ANSI Full Outer Join, Ready or Not?

30 12 2010

December 30, 2010 (Modified January 1, 2011)

When I read pages 101-103 of the book “Pro Oracle SQL” a couple of days ago, I was reminded of a couple of things.  This section of the book describes full outer joins, showing the ANSI syntax and Oracle syntax to perform a full outer join.  If you read my earlier blog article on the topic of ANSI SQL, you probably saw in the article that there are a couple of bug reports listed in Metalink (MOS) that describe problems with ANSI joins, including a couple that are specific to Oracle Database versions below 11.2.0.2.  As far as I can tell (at least with Oracle Database 11.2.0.1), ANSI full outer joins are the only ANSI formatted join syntax that is not converted into Oracle specific join syntax.  The second thing that it reminded me of is a search of the phrase pig outer join that seemed to hit my blog at least once a week.  There is one article on my blog that matches that description, and that article includes the following example of a full outer join using Oracle syntax:

SELECT
  T1.ANIMAL,
  T2.ANIMAL
FROM
  TABLE_1 T1,
  TABLE_2 T2
WHERE
  T1.ANIMAL(+)=T2.ANIMAL
UNION
SELECT
  T1.ANIMAL,
  T2.ANIMAL
FROM
  TABLE_1 T1,
  TABLE_2 T2
WHERE
  T1.ANIMAL=T2.ANIMAL(+);

T1.ANIMAL         T2.ANIMAL
COW               COW
PIG               PIG
(null)            DOG
ZEBRA             (null)
SHARK             (null)
ROOSTER           (null)
LION              (null) 

The above example works well as long as multiple rows do not have the same value in the ANIMAL column.  The example on page 102 of the book looks similar to the one above, just without all of the common farm animals.  :-)

But there was one other item that caught my eye.  I could not reproduce the execution plan found in the book using the ANSI full outer join syntax on Oracle Database 11.2.0.1.  Interesting… was the wrong execution plan copied into the book, or is there another explanation?  Let’s put together a test script to help see what is happening:

ALTER SYSTEM SET PGA_AGGREGATE_TARGET=2000M SCOPE=MEMORY;

CREATE TABLE
  T1
AS
SELECT
  ROWNUM C1,
  LPAD(TO_CHAR(ROWNUM),10,'0') C2,
  LPAD('A',200,'A') PADDING
FROM
  DUAL
CONNECT BY
  LEVEL<=100000;

CREATE TABLE
  T2
AS
SELECT
  ROWNUM C1,
  LPAD(TO_CHAR(ROWNUM),10,'0') C2,
  LPAD('A',400,'A') PADDING
FROM
  DUAL
CONNECT BY
  LEVEL<=100000;

COMMIT;

CREATE INDEX IND_T1_C1 ON T1(C1);
CREATE INDEX IND_T2_C1 ON T2(C1);

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',CASCADE=>TRUE,ESTIMATE_PERCENT=>NULL)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',CASCADE=>TRUE,ESTIMATE_PERCENT=>NULL) 

Wait 60 seconds, just to make certain that the 2,000M PGA_AGGREGATE_TARGET has had a chance to take effect, then continue with the script.  We will write the full outer join SQL statement four different ways, with the third method using the UNION clause as it was used in the book:

SET AUTOTRACE TRACEONLY STATISTICS
SET ARRAYSIZE 1000
ALTER SESSION SET STATISTICS_LEVEL='ALL';

SELECT /* FIND_ME 1 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION ALL
SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1
  AND T1.C1 IS NULL;

SELECT /* FIND_ME 2 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION ALL
SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1
  AND T1.ROWID IS NULL;

SELECT /* FIND_ME 3 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION
SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1;

SELECT /* FIND_ME 4 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1;

SET AUTOTRACE OFF
SET LINESIZE 170
SET PAGESIZE 2000
SET TRIMSPOOL ON
SPOOL TEST_OUTER_PLANS.TXT

SELECT /*+ LEADING(S) */
  T.PLAN_TABLE_OUTPUT
FROM
  (SELECT
    SQL_ID,
    CHILD_NUMBER
  FROM
    V$SQL
  WHERE
    SQL_TEXT LIKE 'SELECT /* FIND_ME%') S,
  TABLE(DBMS_XPLAN.DISPLAY_CURSOR(S.SQL_ID,S.CHILD_NUMBER,'ALLSTATS LAST +COST +BYTES')) T;

SPOOL OFF 

When the above script is executed, the execution plans for the first half of the test script will be written to a file named TEST_OUTER_PLANS.TXT.  Now on to the second half of the script were duplicate rows are introduced into table T1, some rows are deleted, and other rows are modified:

INSERT INTO
  T1
SELECT
  ROWNUM C1,
  LPAD(TO_CHAR(ROWNUM),10,'0') C2,
  LPAD('A',200,'A') PADDING
FROM
  DUAL
CONNECT BY
  LEVEL<=50000;

UPDATE
  T1
SET
  C1=NULL
WHERE
  C1 BETWEEN 90000 AND 100000;

UPDATE
  T1
SET
  C1=C1+200000
WHERE
  C1 BETWEEN 1 AND 1000;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',CASCADE=>TRUE,ESTIMATE_PERCENT=>NULL,NO_INVALIDATE=>FALSE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',CASCADE=>TRUE,ESTIMATE_PERCENT=>NULL,NO_INVALIDATE=>FALSE)

ALTER SYSTEM FLUSH SHARED_POOL;
ALTER SYSTEM FLUSH SHARED_POOL;

SET AUTOTRACE TRACEONLY STATISTICS

SELECT /* FIND_ME 1 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION ALL
SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1
  AND T1.C1 IS NULL;

SELECT /* FIND_ME 2 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION ALL
SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1
  AND T1.ROWID IS NULL;

SELECT /* FIND_ME 3 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION
SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1;

SELECT /* FIND_ME 4 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1;

SET AUTOTRACE OFF
SET LINESIZE 170
SET PAGESIZE 2000
SET TRIMSPOOL ON
SPOOL TEST_OUTER_PLANS2.TXT

SELECT /*+ LEADING(S) */
  T.PLAN_TABLE_OUTPUT
FROM
  (SELECT
    SQL_ID,
    CHILD_NUMBER
  FROM
    V$SQL
  WHERE
    SQL_TEXT LIKE 'SELECT /* FIND_ME%') S,
  TABLE(DBMS_XPLAN.DISPLAY_CURSOR(S.SQL_ID,S.CHILD_NUMBER,'ALLSTATS LAST +COST +BYTES')) T;

SPOOL OFF 

The execution plans for the second half of the script are written to a file named TEST_OUTER_PLANS2.TXT.  So, what does the output of the plans look like on Oracle Database 10.2.0.5 Standard Edition?  The execution plans for the first half of the script:

SQL_ID  cfjjpmdc0ghsx, child number 0
-------------------------------------
SELECT /* FIND_ME 1 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2
FROM   T1,   T2 WHERE   T1.C1(+)=T2.C1   AND T1.C1 IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |   998 (100)|    100K|00:00:00.13 |   12483 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    100K|00:00:00.13 |   12483 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|   273   (2)|    100K|00:00:00.04 |    3460 |  3748K|  1935K| 5608K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.01 |    3231 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |      0 |00:00:00.10 |    9023 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |      1 |    21 |   725   (1)|    100K|00:00:00.04 |    9023 |  3748K|  1935K| 5609K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL  | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1"."C1" IS NULL)
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  1qtvpf3mnb3nx, child number 0
-------------------------------------
SELECT /* FIND_ME 2 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2
FROM   T1,   T2 WHERE   T1.C1(+)=T2.C1   AND T1.ROWID IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |   998 (100)|    100K|00:00:00.13 |   12483 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    100K|00:00:00.13 |   12483 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|   273   (2)|    100K|00:00:00.04 |    3460 |  3748K|  1935K| 5608K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.01 |    3231 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |      0 |00:00:00.10 |    9023 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |    100K|  3222K|   725   (1)|    100K|00:00:00.04 |    9023 |  3748K|  1935K| 5609K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL  | T1        |      1 |    100K|  2734K|   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1".ROWID IS NULL)
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  4v4r3dau0barp, child number 0
-------------------------------------
SELECT /* FIND_ME 3 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1(+) UNION SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2
WHERE   T1.C1(+)=T2.C1

Plan hash value: 2719845061

-------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name      | Starts | E-Rows |E-Bytes|E-Temp | Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |           |      1 |        |       |       |  2078 (100)|    100K|00:00:00.31 |   12383 |       |       |          |
|   1 |  SORT UNIQUE            |           |      1 |    200K|  4101K|  5913K|  2078  (62)|    100K|00:00:00.31 |   12383 |  5510K|  1269K| 4897K (0)|
|   2 |   UNION-ALL             |           |      1 |        |       |       |            |    200K|00:00:00.04 |   12383 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|       |   273   (2)|    100K|00:00:00.04 |    3360 |  3748K|  1935K| 5609K (0)|
|   4 |     INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|       |    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   5 |     TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|       |   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
|*  6 |    HASH JOIN OUTER      |           |      1 |    100K|  2050K|       |   725   (1)|    100K|00:00:00.04 |    9023 |  3748K|  1935K| 5609K (0)|
|   7 |     TABLE ACCESS FULL   | T2        |      1 |    100K|   488K|       |   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|       |   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."C1"="T2"."C1")
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  gs96s7s3ff9sp, child number 0
-------------------------------------
SELECT /* FIND_ME 4 */   T1.C1,   T2.C1,   T1.C2 FROM   T1 FULL OUTER JOIN T2      ON T1.C1=T2.C1

Plan hash value: 2431666783

-----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |           |      1 |        |       |   766 (100)|    100K|00:00:00.11 |    9581 |       |       |          |
|   1 |  VIEW                   |           |      1 |    100K|  3222K|   766   (2)|    100K|00:00:00.11 |    9581 |       |       |          |
|   2 |   UNION-ALL             |           |      1 |        |       |            |    100K|00:00:00.11 |    9581 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|   273   (2)|    100K|00:00:00.04 |    3460 |  3748K|  1935K| 5608K (0)|
|   4 |     INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   5 |     TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.01 |    3231 |       |       |          |
|*  6 |    HASH JOIN ANTI       |           |      1 |      1 |    10 |   493   (2)|      0 |00:00:00.08 |    6121 |  3748K|  1935K| 5546K (0)|
|   7 |     TABLE ACCESS FULL   | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     INDEX FAST FULL SCAN| IND_T1_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."C1"="T2"."C1")
   6 - access("T1"."C1"="T2"."C1") 

Notice in the above that the ANSI full outer join syntax SQL statement completed faster than the other methods, almost 3 times faster than the method using UNION, but only slightly faster than the method using UNION ALL.  Take a close look at the Predicate Information section of the execution plan for the second SQL statement – notice that there is no filter predicate on plan line 8 (keep an eye on the plan for the second SQL statement later).  The execution plan for the ANSI full outer join is very similar to what is shown in the book, assuming that tables T1 and T2 did not have indexes.

The execution plans for the second half of the script on Oracle Database 10.2.0.5 Standard Edition:

SQL_ID  cfjjpmdc0ghsx, child number 0
-------------------------------------
SELECT /* FIND_ME 1 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2
FROM   T1,   T2 WHERE   T1.C1(+)=T2.C1   AND T1.C1 IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |  1261 (100)|    161K|00:00:00.20 |   15757 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    161K|00:00:00.20 |   15757 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|   404   (2)|    150K|00:00:00.04 |    5122 |  3748K|  1935K| 5610K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.01 |    4893 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |  11001 |00:00:00.12 |   10635 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |   9334 |   191K|   856   (1)|    149K|00:00:00.04 |   10635 |  3748K|  1935K| 5611K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL  | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.01 |    4743 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1"."C1" IS NULL)
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  1qtvpf3mnb3nx, child number 0
-------------------------------------
SELECT /* FIND_ME 2 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2
FROM   T1,   T2 WHERE   T1.C1(+)=T2.C1   AND T1.ROWID IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |  1261 (100)|    161K|00:00:00.20 |   15757 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    161K|00:00:00.20 |   15757 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|   404   (2)|    150K|00:00:00.04 |    5122 |  3748K|  1935K| 5610K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.01 |    4893 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |  11001 |00:00:00.12 |   10635 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |    139K|  4511K|   857   (1)|    149K|00:00:00.04 |   10635 |  3748K|  1935K| 5611K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|*  8 |     TABLE ACCESS FULL  | T1        |      1 |    139K|  3828K|   383   (1)|    139K|00:00:00.01 |    4743 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1".ROWID IS NULL)
   6 - access("T1"."C1"="T2"."C1")
   8 - filter("T1"."C1" IS NOT NULL)

-

SQL_ID  4v4r3dau0barp, child number 0
-------------------------------------
SELECT /* FIND_ME 3 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1(+) UNION SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2
WHERE   T1.C1(+)=T2.C1

Plan hash value: 2719845061

-------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name      | Starts | E-Rows |E-Bytes|E-Temp | Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |           |      1 |        |       |       |  2823 (100)|    111K|00:00:00.49 |   15607 |       |       |          |
|   1 |  SORT UNIQUE            |           |      1 |    289K|  5947K|  8544K|  2823  (58)|    111K|00:00:00.49 |   15607 |  6998K|  1589K| 6220K (0)|
|   2 |   UNION-ALL             |           |      1 |        |       |       |            |    299K|00:00:00.04 |   15607 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|       |   404   (2)|    150K|00:00:00.04 |    4972 |  3748K|  1935K| 5611K (0)|
|   4 |     INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|       |    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   5 |     TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|       |   383   (1)|    150K|00:00:00.01 |    4743 |       |       |          |
|*  6 |    HASH JOIN OUTER      |           |      1 |    139K|  2871K|       |   857   (1)|    149K|00:00:00.04 |   10635 |  3748K|  1935K| 5580K (0)|
|   7 |     TABLE ACCESS FULL   | T2        |      1 |    100K|   488K|       |   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|*  8 |     TABLE ACCESS FULL   | T1        |      1 |    139K|  2187K|       |   383   (1)|    139K|00:00:00.01 |    4743 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."C1"="T2"."C1")
   6 - access("T1"."C1"="T2"."C1")
   8 - filter("T1"."C1" IS NOT NULL)

-

SQL_ID  gs96s7s3ff9sp, child number 0
-------------------------------------
SELECT /* FIND_ME 4 */   T1.C1,   T2.C1,   T1.C2 FROM   T1 FULL OUTER JOIN T2      ON T1.C1=T2.C1

Plan hash value: 2431666783

-----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |           |      1 |        |       |   905 (100)|    161K|00:00:00.20 |   11402 |       |       |          |
|   1 |  VIEW                   |           |      1 |    160K|  5156K|   905   (2)|    161K|00:00:00.20 |   11402 |       |       |          |
|   2 |   UNION-ALL             |           |      1 |        |       |            |    161K|00:00:00.20 |   11402 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|   404   (2)|    150K|00:00:00.04 |    5122 |  3748K|  1935K| 5610K (0)|
|   4 |     INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     229 |       |       |          |
|   5 |     TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.01 |    4893 |       |       |          |
|*  6 |    HASH JOIN ANTI       |           |      1 |  10001 |    97K|   501   (2)|  11001 |00:00:00.09 |    6280 |  3748K|  1935K| 5547K (0)|
|   7 |     TABLE ACCESS FULL   | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|*  8 |     INDEX FAST FULL SCAN| IND_T1_C1 |      1 |    139K|   683K|    27   (4)|    139K|00:00:00.01 |     388 |       |       |          |
-----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."C1"="T2"."C1")
   6 - access("T1"."C1"="T2"."C1")
   8 - filter("T1"."C1" IS NOT NULL) 

So, why did I see a different execution plan on Oracle Database 11.2.0.1?  Let’s take a look at a 10053 trace file from 10.2.0.5:

SET AUTOTRACE TRACEONLY STATISTICS
ALTER SESSION SET TRACEFILE_IDENTIFIER='ANSI_TRANSFORM_FULL';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /* FIND_ME 5 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF'; 

Inside the trace file I found this (slightly reformatted to improve readability):

******* UNPARSED QUERY IS *******
SELECT
  "from$_subquery$_003"."C1" "C1",
  "from$_subquery$_003"."C1" "C1",
  "from$_subquery$_003"."C2" "C2"
FROM
  ((SELECT
      "T1"."C1" "QCSJ_C000000000300000",
      "T1"."C2" "QCSJ_C000000000300002",
      "T2"."C1" "C1",
      "T2"."C2" "C2"
    FROM
      "TESTUSER"."T1" "T1",
      "TESTUSER"."T2" "T2"
    WHERE
      "T1"."C1"="T2"."C1"(+))
  UNION ALL
   (SELECT
      NULL,
      NULL,
      "T2"."C1" "C1",
      "T2"."C2" "C2"
    FROM
      "TESTUSER"."T1" "T1",
      "TESTUSER"."T2" "T2"
    WHERE
      "T1"."C1"="T2"."C1"
      AND "T1"."C1" IS NOT NULL)) "from$_subquery$_003"

kkoqbc-subheap (delete addr=000000001602C530, in-use=11064, alloc=21776)
kkoqbc-end
          : call(in-use=83648, alloc=131128), compile(in-use=123584, alloc=166568)
apadrv-end: call(in-use=83648, alloc=131128), compile(in-use=125480, alloc=166568)

sql_id=7jhmvz6nutvpv.
Current SQL statement for this session:
SELECT /* FIND_ME 5 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1

============
Plan Table
============
--------------------------------------------+-----------------------------------+
| Id  | Operation                | Name     | Rows  | Bytes | Cost  | Time      |
--------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT         |          |       |       |   905 |           |
| 1   |  VIEW                    |          |  156K | 5156K |   905 |  00:00:08 |
| 2   |   UNION-ALL              |          |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER |          |  146K | 3076K |   404 |  00:00:04 |
| 4   |     INDEX FAST FULL SCAN | IND_T2_C1|   98K |  488K |    20 |  00:00:01 |
| 5   |     TABLE ACCESS FULL    | T1       |  146K | 2344K |   383 |  00:00:04 |
| 6   |    HASH JOIN ANTI        |          |   10K |   98K |   501 |  00:00:05 |
| 7   |     TABLE ACCESS FULL    | T2       |   98K |  488K |   472 |  00:00:04 |
| 8   |     INDEX FAST FULL SCAN | IND_T1_C1|  137K |  684K |    27 |  00:00:01 |
--------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - access("T1"."C1"="T2"."C1")
6 - access("T1"."C1"="T2"."C1")
8 - filter("T1"."C1" IS NOT NULL) 

I guess that query transformation explains the execution plan – it looks like Oracle Database 10.2.0.5 will transform an ANSI full outer join into Oracle specific syntax.  Let’s repeat the test on Oracle Database 11.2.0.1 to see what happens:

SQL_ID  cfjjpmdc0ghsx, child number 0
-------------------------------------
SELECT /* FIND_ME 1 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE
 T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,
T2 WHERE   T1.C1(+)=T2.C1   AND T1.C1 IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |   998 (100)|    100K|00:00:00.21 |   12484 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    100K|00:00:00.21 |   12484 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|   273   (2)|    100K|00:00:00.09 |    3461 |  3749K|  1936K| 5799K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     230 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.02 |    3231 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |      0 |00:00:00.09 |    9023 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |      1 |    21 |   725   (1)|    100K|00:00:00.09 |    9023 |  3749K|  1936K| 5800K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL  | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1"."C1" IS NULL)
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  1qtvpf3mnb3nx, child number 0
-------------------------------------
SELECT /* FIND_ME 2 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE
 T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,
T2 WHERE   T1.C1(+)=T2.C1   AND T1.ROWID IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |   998 (100)|    100K|00:00:00.21 |   12484 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    100K|00:00:00.21 |   12484 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|   273   (2)|    100K|00:00:00.09 |    3461 |  3749K|  1936K| 5799K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     230 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.02 |    3231 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |      0 |00:00:00.09 |    9023 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |    100K|  3222K|   725   (1)|    100K|00:00:00.09 |    9023 |  3749K|  1936K| 5800K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL  | T1        |      1 |    100K|  2734K|   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1".ROWID IS NULL)
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  4v4r3dau0barp, child number 0
-------------------------------------
SELECT /* FIND_ME 3 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE
 T1.C1=T2.C1(+) UNION SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2
WHERE   T1.C1(+)=T2.C1

Plan hash value: 2719845061

-------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name      | Starts | E-Rows |E-Bytes|E-Temp | Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |           |      1 |        |       |       |  2078 (100)|    100K|00:00:00.30 |   12384 |       |       |          |
|   1 |  SORT UNIQUE            |           |      1 |    200K|  4101K|  5913K|  2078  (62)|    100K|00:00:00.30 |   12384 |  6360K|  1340K| 5653K (0)|
|   2 |   UNION-ALL             |           |      1 |        |       |       |            |    200K|00:00:00.21 |   12384 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER|           |      1 |    100K|  2050K|       |   273   (2)|    100K|00:00:00.08 |    3361 |  3749K|  1936K| 5800K (0)|
|   4 |     INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|       |    20   (5)|    100K|00:00:00.01 |     230 |       |       |          |
|   5 |     TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|       |   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
|*  6 |    HASH JOIN OUTER      |           |      1 |    100K|  2050K|       |   725   (1)|    100K|00:00:00.09 |    9023 |  3749K|  1936K| 5743K (0)|
|   7 |     TABLE ACCESS FULL   | T2        |      1 |    100K|   488K|       |   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL   | T1        |      1 |    100K|  1562K|       |   252   (1)|    100K|00:00:00.01 |    3131 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."C1"="T2"."C1")
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  gs96s7s3ff9sp, child number 0
-------------------------------------
SELECT /* FIND_ME 4 */   T1.C1,   T2.C1,   T1.C2 FROM   T1 FULL OUTER
JOIN T2      ON T1.C1=T2.C1

Plan hash value: 3807180574

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |       |   725 (100)|    100K|00:00:00.11 |    9123 |       |       |          |
|   1 |  VIEW                 | VW_FOJ_0 |      1 |    100K|  3222K|   725   (1)|    100K|00:00:00.11 |    9123 |       |       |          |
|*  2 |   HASH JOIN FULL OUTER|          |      1 |    100K|  2050K|   725   (1)|    100K|00:00:00.10 |    9123 |  3749K|  1936K| 5799K (0)|
|   3 |    TABLE ACCESS FULL  | T2       |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   4 |    TABLE ACCESS FULL  | T1       |      1 |    100K|  1562K|   252   (1)|    100K|00:00:00.02 |    3231 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1") 

Notice the difference in the ANSI full outer join execution plan.  Now the second half of the output:

SQL_ID  cfjjpmdc0ghsx, child number 0
-------------------------------------
SELECT /* FIND_ME 1 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE
 T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,
T2 WHERE   T1.C1(+)=T2.C1   AND T1.C1 IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |  1261 (100)|    161K|00:00:00.28 |   15732 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    161K|00:00:00.28 |   15732 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|   404   (2)|    150K|00:00:00.12 |    5110 |  3749K|  1936K| 5671K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     230 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.03 |    4880 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |  11001 |00:00:00.12 |   10622 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |   9334 |   191K|   856   (1)|    149K|00:00:00.11 |   10622 |  3749K|  1936K| 5672K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   8 |     TABLE ACCESS FULL  | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.02 |    4730 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1"."C1" IS NULL)
   6 - access("T1"."C1"="T2"."C1")

-

SQL_ID  1qtvpf3mnb3nx, child number 0
-------------------------------------
SELECT /* FIND_ME 2 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE
 T1.C1=T2.C1(+) UNION ALL SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,
T2 WHERE   T1.C1(+)=T2.C1   AND T1.ROWID IS NULL

Plan hash value: 2463665226

----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |      1 |        |       |  1261 (100)|    161K|00:00:00.27 |   15732 |       |       |          |
|   1 |  UNION-ALL             |           |      1 |        |       |            |    161K|00:00:00.27 |   15732 |       |       |          |
|*  2 |   HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|   404   (2)|    150K|00:00:00.12 |    5110 |  3749K|  1936K| 5671K (0)|
|   3 |    INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|    20   (5)|    100K|00:00:00.01 |     230 |       |       |          |
|   4 |    TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.02 |    4880 |       |       |          |
|*  5 |   FILTER               |           |      1 |        |       |            |  11001 |00:00:00.12 |   10622 |       |       |          |
|*  6 |    HASH JOIN OUTER     |           |      1 |    139K|  4511K|   857   (1)|    149K|00:00:00.11 |   10622 |  3749K|  1936K| 5735K (0)|
|   7 |     TABLE ACCESS FULL  | T2        |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|*  8 |     TABLE ACCESS FULL  | T1        |      1 |    139K|  3828K|   383   (1)|    139K|00:00:00.02 |    4730 |       |       |          |
----------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1")
   5 - filter("T1".ROWID IS NULL)
   6 - access("T1"."C1"="T2"."C1")
   8 - filter("T1"."C1" IS NOT NULL)

-

SQL_ID  4v4r3dau0barp, child number 0
-------------------------------------
SELECT /* FIND_ME 3 */   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE
 T1.C1=T2.C1(+) UNION SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2
WHERE   T1.C1(+)=T2.C1

Plan hash value: 2719845061

-------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation               | Name      | Starts | E-Rows |E-Bytes|E-Temp | Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |           |      1 |        |       |       |  2823 (100)|    111K|00:00:00.47 |   15582 |       |       |          |
|   1 |  SORT UNIQUE            |           |      1 |    289K|  5947K|  8544K|  2823  (58)|    111K|00:00:00.47 |   15582 |  7990K|  1681K| 7102K (0)|
|   2 |   UNION-ALL             |           |      1 |        |       |       |            |    299K|00:00:00.28 |   15582 |       |       |          |
|*  3 |    HASH JOIN RIGHT OUTER|           |      1 |    150K|  3076K|       |   404   (2)|    150K|00:00:00.11 |    4960 |  3749K|  1936K| 5671K (0)|
|   4 |     INDEX FAST FULL SCAN| IND_T2_C1 |      1 |    100K|   488K|       |    20   (5)|    100K|00:00:00.01 |     230 |       |       |          |
|   5 |     TABLE ACCESS FULL   | T1        |      1 |    150K|  2343K|       |   383   (1)|    150K|00:00:00.02 |    4730 |       |       |          |
|*  6 |    HASH JOIN OUTER      |           |      1 |    139K|  2871K|       |   857   (1)|    149K|00:00:00.11 |   10622 |  3749K|  1936K| 5640K (0)|
|   7 |     TABLE ACCESS FULL   | T2        |      1 |    100K|   488K|       |   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|*  8 |     TABLE ACCESS FULL   | T1        |      1 |    139K|  2187K|       |   383   (1)|    139K|00:00:00.02 |    4730 |       |       |          |
-------------------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - access("T1"."C1"="T2"."C1")
   6 - access("T1"."C1"="T2"."C1")
   8 - filter("T1"."C1" IS NOT NULL)

-

SQL_ID  gs96s7s3ff9sp, child number 0
-------------------------------------
SELECT /* FIND_ME 4 */   T1.C1,   T2.C1,   T1.C2 FROM   T1 FULL OUTER
JOIN T2      ON T1.C1=T2.C1

Plan hash value: 3807180574

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation             | Name     | Starts | E-Rows |E-Bytes| Cost (%CPU)| A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |          |      1 |        |       |   856 (100)|    161K|00:00:00.14 |   10772 |       |       |          |
|   1 |  VIEW                 | VW_FOJ_0 |      1 |    150K|  4833K|   856   (1)|    161K|00:00:00.14 |   10772 |       |       |          |
|*  2 |   HASH JOIN FULL OUTER|          |      1 |    150K|  3076K|   856   (1)|    161K|00:00:00.13 |   10772 |  3749K|  1936K| 5671K (0)|
|   3 |    TABLE ACCESS FULL  | T2       |      1 |    100K|   488K|   472   (1)|    100K|00:00:00.01 |    5892 |       |       |          |
|   4 |    TABLE ACCESS FULL  | T1       |      1 |    150K|  2343K|   383   (1)|    150K|00:00:00.02 |    4880 |       |       |          |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("T1"."C1"="T2"."C1") 

Again, notice that the execution plan for the ANSI full outer join is different.  Let’s take a look at a 10053 trace for the SQL statement:

SET AUTOTRACE TRACEONLY STATISTICS
ALTER SESSION SET TRACEFILE_IDENTIFIER='ANSI_TRANSFORM_FULL';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /* FIND_ME 5 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF'; 

Let’s take a look in the 10053 trace file:

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT
  "VW_FOJ_0"."QCSJ_C000000000300000_0" "C1",
  "VW_FOJ_0"."QCSJ_C000000000300001_2" "C1",
  "VW_FOJ_0"."QCSJ_C000000000300002_1" "C2"
FROM
  (SELECT
     "T1"."C1" "QCSJ_C000000000300000_0",
     "T1"."C2" "QCSJ_C000000000300002_1",
     "T2"."C1" "QCSJ_C000000000300001_2"
   FROM
     "TESTUSER"."T2" "T2" FULL OUTER JOIN "TESTUSER"."T1" "T1"
         ON "T1"."C1"="T2"."C1") "VW_FOJ_0"
...
Starting SQL statement dump

user_id=194 user_name=TESTUSER module=SQL*Plus action=
sql_id=7jhmvz6nutvpv plan_hash_value=-487786722 problem_type=3
----- Current SQL Statement for this session (sql_id=7jhmvz6nutvpv) -----
SELECT /* FIND_ME 5 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1
sql_text_length=98
sql=SELECT /* FIND_ME 5 */
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1 FULL OUTER JOIN T2
     ON T1.C1=T2.C1
----- Explain Plan Dump -----
----- Plan Table -----

============
Plan Table
============
-----------------------------------------+-----------------------------------+
| Id  | Operation              | Name    | Rows  | Bytes | Cost  | Time      |
-----------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT       |         |       |       |   856 |           |
| 1   |  VIEW                  | VW_FOJ_0|  146K | 4834K |   856 |  00:00:07 |
| 2   |   HASH JOIN FULL OUTER |         |  146K | 3076K |   856 |  00:00:07 |
| 3   |    TABLE ACCESS FULL   | T2      |   98K |  488K |   472 |  00:00:04 |
| 4   |    TABLE ACCESS FULL   | T1      |  146K | 2344K |   383 |  00:00:04 |
-----------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - access("T1"."C1"="T2"."C1") 

I guess that explains why the execution plan looks a bit different from the version produced by 10.2.0.5.

Anyone care to try this test case on 9i R1, 9i R2, 10g R1, or 11.2.0.2?  I am curious to know if we will trip over one of those ANSI bugs that are building a fort in my front lawn (bang head on desk until this makes sense… ants, see! :-) ).

——————–

Edit: December 30, 2010 Speaking of bugs, a quick look through Metalink:

  • Doc ID 9395765.8, Bug 9395765 “ORA-907 / wrong plan from query with ANSI FULL OUTER join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 8432019.8, Bug 8432019 “Wrong Results With Full Outer Join, Database Link and Merged Inline View”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 8538448.8, Bug 8538448 “OERI [qcsFixQbcnlo2] from FULL OUTER JOIN with UNION ALL”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 8947490.8, Bug 8947490 “OERI[15160] using SQL tuning advisor for full outer joined UNION”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9337832.8, Bug 9337832 “Wrong results from ANSI outer joins”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9882805.8, Bug 9882805 “Wrong results with NATIVE FULL OUTER JOIN and NVL”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 7144891.8, Bug 7144891 “OERI [qctopn1] from nested FULL OUTER JOIN”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 6471020.8, Bug 6471020 “ORA-1790 or ORA-904 from FULL JOIN”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 8782089.8, Bug 8782089 “OERI [15160] on ANSI join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9050716.8, Bug 9050716 “Dumps on kkqstcrf with ANSI joins and Join Elimination”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9149005.8, Bug 9149005 “ANSI left join query with domain index fails with OERI [qxopq_get_rowid:1]“, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9256994.8, Bug 9256994 “ORA-1792 using ANSI joins”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9360157.8, Bug 9360157 “Wrong results using ORA_ROWSCN pseudocolumn with ANSI join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9371323.8, Bug 9371323 “OERI [rwoirw: check ret val] on INSERT ALL with ANSI join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9387924.8, Bug 9387924 “OERI [qxopq_get_rowid:1] from ANSI join and operator”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9713012.8, Bug 9713012 “Wrong results from push predicate on ANSI SQL”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9189070.8, Bug 9189070 “Dump (kkoiqb) parsing ANSI SQL with disjunctive predicate in “ON” clause”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 4459936.8, Bug 4459936 “FGA does not work correctly with ANSI outer joins”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 4871892.8, Bug 4871892 “Wrong results from “left outer join” with TABLE() expressions”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 5183871.8, Bug 5183871 “ORA-904 using ORA_ROWSCN in ANSI SQL”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7429090.8, Bug 7429090 “Poor plan generated for a OUTER join query involving a LATERAL view”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7442232.8, Bug 7442232 “WRONG RESULTS (missing rows) WITH NATIVE FULL OUTER JOIN”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7001990.8, Bug 7001990 “Wrong result (null column) on ansi outer join query and index access”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 8547175.8, Bug 8547175 “FGA does not work correctly with ANSI joins”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7420504.8, Bug 7420504 “Wrong Results with ANSI queries and fix for bug 7345484″, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7375360.8, Bug 7375360 “Repeat execution of uncorrelated subquery in ANSI join”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7345484.8, Bug 7345484 “Left outer join with filters are slow”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 7318276.8, Bug 7318276 “False ORA-918 with fix for bug 5368296 installed”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 5368296.8, Bug 5368296 “ANSI join SQL may not report ORA-918 for ambiguous column”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 5358967.8, Bug 5358967 “ORA-2019 on CREATE VIEW after CURRENT_SCHEMA is changed”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 5031632.8, Bug 5031632 “Wrong results from NATURAL JOIN”, affects Oracle Database release versions below 10.2.0.5
  • Doc ID 8971835.8, Bug 8971835 “Assorted Dumps / ORA-932 / Wrong results when accessing over 1000 columns”, affects Oracle Database release versions below 10.2.0.5

I will suggest that the hidden parameter _OPTIMIZER_NATIVE_FULL_OUTER_JOIN likely controls whether or not an ANSI full outer join is transformed into Oracle specific syntax.  The script in this blog article shows that the default value of this parameter is FORCE on Oracle Database 11.2.0.1.

—–

Edit: Jan 1, 2011:

One more ANSI bug that affects 11.2.0.1 and below - thanks to Coskan for reporting the bug (and for beta testing the ANSI functionality in the production release of 11.2.0.1 :-) ):

  • Doc ID 9287401.8, Bug 9287401 “Full outer join does not push down predicates”, affects Oracle Database release versions below 11.2.0.2




Hash Joins – What is Wrong with this Statement?

29 12 2010

December 29, 2010

I started reading the book “Pro Oracle SQL” a couple of days ago, and I am having trouble putting it down.  Other than a couple of minor word substitutions and intended, but not specified, qualifying words, the first 100 pages of the book are fantastic (I suspect that many of these cases are intentional since that book is not advertised as a SQL performance tuning guide – too much detail might cause confusion).  The description of how SQL processing works, and how to understand execution plans is on par with (or maybe even slightly better than) the treatment in the “Troubleshooting Oracle Performance” book (that reminds me, I still need to finish the second read through of the “Troubleshooting Oracle Performance” book).

As I have done with the last four books that I reviewed, I selected an interesting couple of sentences from this book.  What, if anything, is wrong with the following quote from page 94:

“Based on the table and index statistics, the table that is determined to return the fewest rows will be hashed in its entirety into memory. This hash table includes all of the row data for that table and is loaded into hash buckets based on a randomizing function that converts the join key to a hash value. As long as there is enough memory available, this hash table will reside in memory. However, if there is not enough memory available, the hash table may be written to temp disk space.”

Not as easy of an assignment as with some of the previously extracted quotes?

How about a hint?  Create two simple tables, and collect the full statistics (do not estimate the statistics) on those tables:

CREATE TABLE
  T1
AS
SELECT
  ROWNUM C1,
  LPAD(TO_CHAR(ROWNUM),10,'0') C2,
  LPAD('A',200,'A') PADDING
FROM
  DUAL
CONNECT BY
  LEVEL<=100000;

CREATE TABLE
  T2
AS
SELECT
  ROWNUM C1,
  LPAD(TO_CHAR(ROWNUM),10,'0') C2,
  LPAD('A',400,'A') PADDING
FROM
  DUAL
CONNECT BY
  LEVEL<=100000;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',ESTIMATE_PERCENT=>NULL)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',ESTIMATE_PERCENT=>NULL) 

Now we should probably create a test script that uses the tables:

SET AUTOTRACE TRACEONLY EXPLAIN

SELECT
  *
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T2.C1
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T2.C1
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SELECT
  T1.C1,
  T2.C1,
  T1.C2,
  T1.PADDING
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SELECT
  T1.C1,
  T2.C1,
  T1.C2,
  T1.PADDING,
  T2.PADDING
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2; 

How did you do?  Did you find anything wrong with the quote from the book, or is it completely correct?

-

-

-

I hear someone shouting, “But the above script did not even execute a SQL statement!”.  OK, try this:

ALTER SYSTEM FLUSH SHARED_POOL;
ALTER SYSTEM FLUSH SHARED_POOL;
SET AUTOTRACE TRACEONLY STATISTICS
ALTER SESSION SET STATISTICS_LEVEL='ALL';
ALTER SYSTEM SET PGA_AGGREGATE_TARGET=2000M SCOPE=MEMORY;

Edit Dec 29, 2010: Wait 60 seconds before continuing, just to make certain that the changed PGA_AGGREGATE_TARGET had a chance to take effect (to avoid this trap).  Continuing:

SELECT
  *
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T2.C1
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T2.C1
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SELECT
  T1.C1,
  T2.C1,
  T1.C2,
  T1.PADDING
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SELECT
  T1.C1,
  T2.C1,
  T1.C2,
  T1.PADDING,
  T2.PADDING
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

SET AUTOTRACE OFF
SET LINESIZE 150
SET PAGESIZE 2000
SET TRIMSPOOL ON
SPOOL TEST_HASH_PLANS.TXT

SELECT /*+ LEADING(S) */
  T.PLAN_TABLE_OUTPUT
FROM
  (SELECT
    SQL_ID,
    CHILD_NUMBER
  FROM
    V$SQL
  WHERE
    SQL_TEXT LIKE 'SELECT%T1.C1=T2.C1%') S,
  TABLE(DBMS_XPLAN.DISPLAY_CURSOR(S.SQL_ID,S.CHILD_NUMBER,'ALLSTATS LAST')) T;

SPOOL OFF 

What, if anything, is wrong with the quote from the book?

-

-

-

-

-

Show you the output that I received?  OK:

SELECT
  *
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

Execution Plan
----------------------------------------------------------
Plan hash value: 1838229974

-----------------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|    60M|       |  1493   (1)| 00:00:12 |
|*  1 |  HASH JOIN         |      |   100K|    60M|    21M|  1493   (1)| 00:00:12 |
|   2 |   TABLE ACCESS FULL| T1   |   100K|    20M|       |   248   (1)| 00:00:02 |
|   3 |   TABLE ACCESS FULL| T2   |   100K|    39M|       |   464   (1)| 00:00:04 |
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1")

-

SELECT
  T1.C1,
  T2.C1
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

Execution Plan
----------------------------------------------------------
Plan hash value: 1838229974

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|   976K|   713   (1)| 00:00:06 |
|*  1 |  HASH JOIN         |      |   100K|   976K|   713   (1)| 00:00:06 |
|   2 |   TABLE ACCESS FULL| T1   |   100K|   488K|   248   (1)| 00:00:02 |
|   3 |   TABLE ACCESS FULL| T2   |   100K|   488K|   464   (1)| 00:00:04 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1")

-

SELECT
  T1.C1,
  T2.C1
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

Execution Plan
----------------------------------------------------------
Plan hash value: 1838229974

-----------------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|  3125K|       |   781   (1)| 00:00:07 |
|*  1 |  HASH JOIN         |      |   100K|  3125K|  2736K|   781   (1)| 00:00:07 |
|   2 |   TABLE ACCESS FULL| T1   |   100K|  1562K|       |   248   (1)| 00:00:02 |
|   3 |   TABLE ACCESS FULL| T2   |   100K|  1562K|       |   464   (1)| 00:00:04 |
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2")

-

SELECT
  T1.C1,
  T2.C1,
  T1.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

Execution Plan
----------------------------------------------------------
Plan hash value: 1838229974

-----------------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|  3125K|       |   781   (1)| 00:00:07 |
|*  1 |  HASH JOIN         |      |   100K|  3125K|  2736K|   781   (1)| 00:00:07 |
|   2 |   TABLE ACCESS FULL| T1   |   100K|  1562K|       |   248   (1)| 00:00:02 |
|   3 |   TABLE ACCESS FULL| T2   |   100K|  1562K|       |   464   (1)| 00:00:04 |
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2")

-

SELECT
  T1.C1,
  T2.C1,
  T1.C2,
  T1.PADDING
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

Execution Plan
----------------------------------------------------------
Plan hash value: 2959412835

-----------------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|    22M|       |  1018   (1)| 00:00:09 |
|*  1 |  HASH JOIN         |      |   100K|    22M|  2736K|  1018   (1)| 00:00:09 |
|   2 |   TABLE ACCESS FULL| T2   |   100K|  1562K|       |   464   (1)| 00:00:04 |
|   3 |   TABLE ACCESS FULL| T1   |   100K|    20M|       |   248   (1)| 00:00:02 |
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2")

-

SELECT
  T1.C1,
  T2.C1,
  T1.C2,
  T1.PADDING,
  T2.PADDING
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2=T2.C2;

Execution Plan
----------------------------------------------------------
Plan hash value: 1838229974

-----------------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|    60M|       |  1493   (1)| 00:00:12 |
|*  1 |  HASH JOIN         |      |   100K|    60M|    21M|  1493   (1)| 00:00:12 |
|   2 |   TABLE ACCESS FULL| T1   |   100K|    20M|       |   248   (1)| 00:00:02 |
|   3 |   TABLE ACCESS FULL| T2   |   100K|    39M|       |   464   (1)| 00:00:04 |
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2") 

The output from the second script:

SQL_ID  c2nzwfydj9nft, child number 0
-------------------------------------
SELECT   * FROM   T1,   T2 WHERE   T1.C1=T2.C1

Plan hash value: 1838229974

----------------------------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |      1 |        |    100K|00:00:00.24 |   15298 |       |       |          |
|*  1 |  HASH JOIN         |      |      1 |    100K|    100K|00:00:00.24 |   15298 |    25M|  3830K|   28M (0)|
|   2 |   TABLE ACCESS FULL| T1   |      1 |    100K|    100K|00:00:00.01 |    3131 |       |       |          |
|   3 |   TABLE ACCESS FULL| T2   |      1 |    100K|    100K|00:00:00.07 |   12167 |       |       |          |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1")

-

SQL_ID  1r4up8dp9fc00, child number 0
-------------------------------------
SELECT   T1.C1,   T2.C1 FROM   T1,   T2 WHERE   T1.C1=T2.C1

Plan hash value: 1838229974

----------------------------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |      1 |        |    100K|00:00:00.16 |   15298 |       |       |          |
|*  1 |  HASH JOIN         |      |      1 |    100K|    100K|00:00:00.16 |   15298 |  3749K|  1936K| 5635K (0)|
|   2 |   TABLE ACCESS FULL| T1   |      1 |    100K|    100K|00:00:00.01 |    3131 |       |       |          |
|   3 |   TABLE ACCESS FULL| T2   |      1 |    100K|    100K|00:00:00.05 |   12167 |       |       |          |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1")

-

SQL_ID  0rnjh74c5m1dc, child number 0
-------------------------------------
SELECT   T1.C1,   T2.C1 FROM   T1,   T2 WHERE   T1.C1=T2.C1   AND
T1.C2=T2.C2

Plan hash value: 1838229974

----------------------------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |      1 |        |    100K|00:00:00.25 |   15298 |       |       |          |
|*  1 |  HASH JOIN         |      |      1 |    100K|    100K|00:00:00.25 |   15298 |  4670K|  1438K| 6600K (0)|
|   2 |   TABLE ACCESS FULL| T1   |      1 |    100K|    100K|00:00:00.01 |    3131 |       |       |          |
|   3 |   TABLE ACCESS FULL| T2   |      1 |    100K|    100K|00:00:00.09 |   12167 |       |       |          |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2")

-

PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------------------------------------------
SQL_ID  c691ypk4k096j, child number 0
-------------------------------------
SELECT   T1.C1,   T2.C1,   T1.C2 FROM   T1,   T2 WHERE   T1.C1=T2.C1
AND T1.C2=T2.C2

Plan hash value: 1838229974

----------------------------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |      1 |        |    100K|00:00:00.23 |   15298 |       |       |          |
|*  1 |  HASH JOIN         |      |      1 |    100K|    100K|00:00:00.23 |   15298 |  4670K|  1438K| 6600K (0)|
|   2 |   TABLE ACCESS FULL| T1   |      1 |    100K|    100K|00:00:00.01 |    3131 |       |       |          |
|   3 |   TABLE ACCESS FULL| T2   |      1 |    100K|    100K|00:00:00.08 |   12167 |       |       |          |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2")

-

SQL_ID  dpq7d224rxc6t, child number 0
-------------------------------------
SELECT   T1.C1,   T2.C1,   T1.C2,   T1.PADDING FROM   T1,   T2 WHERE
T1.C1=T2.C1   AND T1.C2=T2.C2

Plan hash value: 2959412835

----------------------------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |      1 |        |    100K|00:00:00.17 |   15482 |       |       |          |
|*  1 |  HASH JOIN         |      |      1 |    100K|    100K|00:00:00.17 |   15482 |  4670K|  1438K| 6600K (0)|
|   2 |   TABLE ACCESS FULL| T2   |      1 |    100K|    100K|00:00:00.01 |    5892 |       |       |          |
|   3 |   TABLE ACCESS FULL| T1   |      1 |    100K|    100K|00:00:00.05 |    9590 |       |       |          |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2")

-

SQL_ID  0k4q3ahjzu9nd, child number 0
-------------------------------------
SELECT   T1.C1,   T2.C1,   T1.C2,   T1.PADDING,   T2.PADDING FROM   T1,
  T2 WHERE   T1.C1=T2.C1   AND T1.C2=T2.C2

Plan hash value: 1838229974

----------------------------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |      1 |        |    100K|00:00:00.24 |   15298 |       |       |          |
|*  1 |  HASH JOIN         |      |      1 |    100K|    100K|00:00:00.24 |   15298 |    25M|  3830K|   28M (0)|
|   2 |   TABLE ACCESS FULL| T1   |      1 |    100K|    100K|00:00:00.01 |    3131 |       |       |          |
|   3 |   TABLE ACCESS FULL| T2   |      1 |    100K|    100K|00:00:00.06 |   12167 |       |       |          |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C1"="T2"."C1" AND "T1"."C2"="T2"."C2") 

I think that I forgot the question… was it something about the value of test cases?  :-)





Feeling ANSI About Oracle Join Syntax?

26 12 2010

December 26, 2010

(Forward to the Next Post in the Series)

Yesterday I started reading another book on the topic of Oracle SQL (for the moment I will keep the title of the book a mystery).  I am not much of a fan of ANSI style syntax – that syntax style is easy to read when there are just two tables involved, but I tend to become lost when several tables are listed with left outer joins to some tables and equi-joins to other tables.  Take for instance the following example which I encountered in an ERP mailing list:

SELECT CUSTOMER_ORDER.ID, SHIPPER.SHIPPED_DATE, CUST_ORDER_LINE.LINE_NO,
PART.ID, PART.DESCRIPTION, SHIPPER_LINE.SHIPPED_QTY
FROM CUSTOMER_ORDER
LEFT JOIN SHIPPER ON CUSTOMER_ORDER.ID = SHIPPER.CUST_ORDER_ID
INNER JOIN SHIPPER_LINE ON SHIPPER.PACKLIST_ID =
SHIPPER_LINE.PACKLIST_ID AND SHIPPER_LINE.SHIPPED_QTY > 0
LEFT JOIN CUST_ORDER_LINE ON CUSTOMER_ORDER.ID =
CUST_ORDER_LINE.CUST_ORDER_ID INNER JOIN PART ON PART.ID =
CUST_ORDER_LINE.PART_ID AND PART.DESCRIPTION LIKE 'PUMP%'

The above query did not work quite as the person wanted, so he asked for some assistance:

“The only thing with this is that it doesn’t seem to show me Customer
order lines where no shipments have occurred. I.E all returned records
have a Shipped_date and there should be some that don’t have
Shipped_date.”

After looking at the problem for a couple of minutes, I proposed the following SQL statement:

SELECT
  CO.ID,
  S.SHIPPED_DATE,
  COL.LINE_NO,
  P.ID,
  P.DESCRIPTION,
  SL.SHIPPED_QTY
FROM
  CUSTOMER_ORDER CO,
  CUST_ORDER_LINE COL,
  PART P,
  SHIPPER S,
  SHIPPER_LINE SL
WHERE
  CO.ID=COL.CUST_ORDER_ID
  AND COL.PART_ID=P.ID
  AND COL.CUST_ORDER_ID=SL.CUST_ORDER_ID(+)
  AND COL.LINE_NO=SL.CUST_ORDER_LINE_NO(+)
  AND SL.PACKLIST_ID=S.PACKLIST_ID(+)
  AND NVL(SL.SHIPPED_QTY,1) > 0
  AND P.DESCRIPTION LIKE 'PUMP%';

The above is nice and simple Oracle specific join syntax that seemed to meet the OP’s requirements.  But wait, the OP’s company is considering a switch from Oracle Database to SQL Server!  Bang head on the table until this makes sense (little floating dots, kind of looks like ants see).  Here, try this:

SELECT
  CO.ID,
  S.SHIPPED_DATE,
  COL.LINE_NO,
  P.ID,
  P.DESCRIPTION,
  SL.SHIPPED_QTY
FROM
  CUSTOMER_ORDER CO
INNER JOIN
  CUST_ORDER_LINE COL
ON
  CO.ID=COL.CUST_ORDER_ID
INNER JOIN
  PART P
ON
  COL.PART_ID=P.ID
LEFT OUTER JOIN
  SHIPPER_LINE SL
ON
  COL.CUST_ORDER_ID=SL.CUST_ORDER_ID
  AND COL.LINE_NO=SL.CUST_ORDER_LINE_NO
LEFT OUTER JOIN
  SHIPPER S
ON
  SL.PACKLIST_ID=S.PACKLIST_ID
WHERE
  COALESCE(SL.SHIPPED_QTY,1) > 0
  AND P.DESCRIPTION LIKE 'PUMP%';

So, which of the above two SQL statements is easier to read?

Still not convinced?  Let’s look at the FROM clause of another simple SQL statement.

Oracle specific join syntax (edit: Dec 26, 2010 2.5 hours after the initial post: the fifth line in the WHERE clause should show AND T3.VENDOR_ID(+) = ‘SAM’ due to the outer join between tables T1 and T3 – with that fix is the query section still equivalent to the ANSI version?  Something also needs to be done with the last line in the WHERE clause due to the outer join between tables T3 and T4):

FROM
  T1,
  T2,
  T3,
  T4
WHERE
  T1.PRODUCT_CODE='10'
  AND T1.PART_ID=T2.PART_ID(+)
  AND T2.DRAWING_REV_NO='20'
  AND T1.PART_ID=T3.PART_ID(+)
  AND T3.VENDOR_ID='SAM'
  AND T3.PART_ID=T4.PART_ID(+)
  AND T4.DESCRIPTION LIKE 'PAINT%';

ANSI join syntax:

FROM
  T1
LEFT OUTER JOIN
  T2
ON
  T1.PART_ID=T2.PART_ID
LEFT OUTER JOIN
  T3
ON
  T1.PART_ID=T3.PART_ID
LEFT OUTER JOIN
  T4
ON
  T3.PART_ID=T4.PART_ID
WHERE
  T1.PRODUCT_CODE='10'
  AND T2.DRAWING_REV_NO='20'
  AND T2.LOT_ID='0'
  AND T2.SPLIT_ID='0'
  AND T3.VENDOR_ID='SAM'
  AND T4.DESCRIPTION LIKE 'PAINT%';

When written with the Oracle specific join syntax, I can quickly see the list of tables that are accessed, and I can see how the results from each table will be restricted as the rows are retrieved.  Oracle Database will actually try to convert the ANSI style join syntax back into Oracle join syntax (this can be seen by enabling a 10053 trace), and there are several cases where bugs will cause the wrong results to be returned to the client.  In the above portion of a SQL statement, Oracle’s optimizer will not necessarily join table T1 to table T2 and then join the result to T3 and then join that result to T4.  The optimizer could join the tables in just about any order, possibly even joining two tables that have no join condition between them (in the process creating a Cartesian product).

The OP mentioned reading a book titled “SQL in 10 Minutes”, or something like that, which is one that I read back in 2000 when I was working with Oracle Database 8.0.5 – that book only describes the ANSI style join syntax.  The 8.0.5 version did not support the ANSI join syntax, and neither did 8.1.7 (8i), so I used the Oracle specific syntax until jumping to Oracle Database 10.2.0.2 in 2006.  There are some cases where the Oracle specific syntax does not translate directly into the ANSI style syntax, where the two syntaxes appear to be requesting the same information, but actually return different information (and that result is not considered a bug).  A couple of years ago I participated in a Usenet thread that included one such query.  This blog article by a member of the Oracle Optimizer group shows an example of that type of query – I believe it is examples C. and D.).

Considering that the Oracle query optimizer transforms the ANSI join syntax into Oracle specific syntax, it seems that there is always a risk of triggering an Oracle bug during the transformation (these bugs are less common in recent Oracle releases).  Bugs?  Just a very small sampling from Metalink (MOS) followed by a couple of mentions from other blogs:

  • Doc ID 9050716.8, Bug 9050716 “Dumps on kkqstcrf with ANSI joins and Join Elimination”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 5188321.8, Bug 5188321 “Wrong results (no rows) OR ORA-1445 from ANSI outer join”, affects Oracle Database release versions below 11.1.0.6
  • Doc ID 5368296.8, Bug 5368296 “ANSI join SQL may not report ORA-918 for ambiguous column”, affects Oracle Database release versions below 11.1.0.6
  • Doc ID 7420504.8, Bug 7420504 “Wrong Results with ANSI queries and fix for bug 7345484″, affects versions 10.2.0.3 through 11.1.0.7
  • Doc ID 9189070.8, Bug 9189070 “Dump (kkoiqb) parsing ANSI SQL with disjunctive predicate in ‘ON’ clause”, affects versions below 11.2.0.2
  • Doc ID 5864217.8, Bug 5864217 “OERI [kkoljt1] from ANSI query with join elimination”, affects Oracle Database release versions below 11.1.0.6
  • Doc ID 6050882.8, Bug 6050882 “Wrong results from ANSI outer join with fix for bug 4967068 or 5864217″, affects Oracle Database release versions below 11.1.0.6
  • Doc ID 7001990.8, Bug 7001990 “Wrong result (null column) on ansi outer join query and index access”, affects Oracle Database release versions below 11.1.0.7
  • Doc ID 9371323.8, Bug 9371323 “OERI [rwoirw: check ret val] on INSERT ALL with ANSI join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 5702433.8, Bug 5702433 “ORA-918 from ANSI joine with a CONTAINS clause”, affects Oracle Database release versions below 11.2.0.1
  • Doc ID 6033480.8, Bug 6033480 “High parse time of query when using ANSI style joins”, affects Oracle Database release versions below 11.1.0.6
  • Doc ID 7710538.8, Bug 7710538 “ORA-904 from UNION ALL with ANSI join”, affects Oracle Database release versions below 11.2.0.1
  • Doc ID 8547175.8, Bug 8547175 “FGA does not work correctly with ANSI joins”, affects Oracle Database release versions below 11.2.0.1
  • Doc ID 8782089.8, Bug 8782089 “OERI [15160] on ANSI join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9395765.8, Bug 9395765 “ORA-907 / wrong plan from query with ANSI FULL OUTER join”, affects Oracle Database release versions below 11.2.0.2
  • Doc ID 9713012.8, Bug 9713012 “Wrong results from push predicate on ANSI SQL”, affects Oracle Database release versions below 11.2.0.2
  • ANSI – argh
  • ANSI SQL
  • When ANSI SQL Join Syntax Does Not Work in Oracle
  • ANSI Outer Joins And Lateral Views (relates to the above referenced article by the Oracle Optimizer group)

I recently saw an interesting message thread on the Oracle-L listserve that asked whether or not it was a bad idea to mix ANSI style joins with Oracle specific style joins.  Randolf and I discussed the same topic while working on the “Expert Oracle Practices” book – if I recall correctly, we determined that while it might work, it is a bad idea; the same execution plans were created for both of the simple test queries.  But why were the execution plans the same?  We need a simple test case script for help:

First, let’s create three very simple tables, making certain to declare the first column in each table as NOT NULL (this is important for one section of the test script):

CREATE TABLE T1(
  C1 NUMBER NOT NULL,
  C2 DATE);

CREATE TABLE T2(
  C1 NUMBER NOT NULL,
  C2 DATE);

CREATE TABLE T3(
  C1 NUMBER NOT NULL,
  C2 DATE);

INSERT INTO
  T1
SELECT
  ROWNUM*3 C1,
  TRUNC(SYSDATE)+(ROWNUM*3) C2
FROM
  DUAL
CONNECT BY
  LEVEL<=100;

INSERT INTO
  T2
SELECT
  (ROWNUM-30)*4 C1,
  TRUNC(SYSDATE)+(ROWNUM*4) C2
FROM
  DUAL
CONNECT BY
  LEVEL<=100;

INSERT INTO
  T3
SELECT
  (ROWNUM-60)*4 C1,
  TRUNC(SYSDATE)+(ROWNUM*4) C2
FROM
  DUAL
CONNECT BY
  LEVEL<=200;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1')
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2')
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T3')

For the test script we will enable a 10053 trace, execute a SQL statement using Oracle specific join syntax, and then the equivalent SQL statement using ANSI join syntax:

ALTER SESSION SET TRACEFILE_IDENTIFIER='ANSI_TRANSFORM';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
INNER JOIN
  T2
ON
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+);

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
LEFT OUTER JOIN
  T2
ON
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
RIGHT OUTER JOIN
  T2
ON
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION ALL
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1
  AND T1.C1 IS NULL;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
FULL OUTER JOIN
  T2
ON
  T1.C1=T2.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2,
  T3.C2
FROM
  T1,
  T2,
  T3
WHERE
  T1.C1=T2.C1(+)
  AND T2.C1=T3.C1;

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2,
  T3.C2
FROM
  T1
LEFT OUTER JOIN
  T2
ON
  T1.C1=T2.C1,
  T3
WHERE
  T2.C1=T3.C1;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

The second to the last example (line 72) shows a full outer join using Oracle syntax (note that the column C1 must be declared as NOT NULL) and the ANSI full outer join syntax (line 95).  The last example shows what happens when ANSI join syntax is mixed with Oracle join syntax.  The following shows portions of the contents of the 10053 trace file when the script was executed on Oracle Database 11.2.0.1:

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1;

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2" WHERE "T1"."C1"="T2"."C1" 
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
INNER JOIN
  T2
ON
  T1.C1=T2.C1;

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2" WHERE "T1"."C1"="T2"."C1"

The final query after transformation is identical for this set of SQL statements.

—-

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+);

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2" WHERE "T1"."C1"="T2"."C1"(+) 
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
LEFT OUTER JOIN
  T2
ON
  T1.C1=T2.C1;

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2" WHERE "T1"."C1"="T2"."C1"(+)

The final query after transformation is identical for this set of SQL statements.

—-

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2" WHERE "T1"."C1"(+)="T2"."C1" 
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
RIGHT OUTER JOIN
  T2
ON
  T1.C1=T2.C1

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T2" "T2","TESTUSER"."T1" "T1" WHERE "T1"."C1"(+)="T2"."C1"

The final query after transformation is identical for this set of SQL statements.

—-

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1(+)
UNION ALL
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1,
  T2
WHERE
  T1.C1(+)=T2.C1
  AND T1.C1 IS NULL

Final query after transformations:******* UNPARSED QUERY IS *******
 (SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2"
 WHERE "T1"."C1"="T2"."C1"(+))
UNION ALL  (SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2"
 WHERE "T1"."C1"(+)="T2"."C1" AND "T1"."C1" IS NULL) 
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2
FROM
  T1
FULL OUTER JOIN
  T2
ON
  T1.C1=T2.C1

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "VW_FOJ_0"."QCSJ_C000000000300000_0" "C1","VW_FOJ_0"."QCSJ_C000000000300002_1" "C2","VW_FOJ_0"."QCSJ_C000000000300001_2" "C1",
"VW_FOJ_0"."QCSJ_C000000000300003_3" "C2" FROM
 (SELECT "T1"."C1" "QCSJ_C000000000300000_0","T1"."C2" "QCSJ_C000000000300002_1","T2"."C1" "QCSJ_C000000000300001_2",
 "T2"."C2" "QCSJ_C000000000300003_3" FROM "TESTUSER"."T2" "T2" FULL OUTER JOIN "TESTUSER"."T1" "T1" ON "T1"."C1"="T2"."C1") "VW_FOJ_0"

The final query after transformation is definitely not the same for the Oracle specific syntax and the ANSI syntax, even though the rows retrieved were identical.

—-

SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2,
  T3.C2
FROM
  T1,
  T2,
  T3
WHERE
  T1.C1=T2.C1(+)
  AND T2.C1=T3.C1;

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2","T3"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2","TESTUSER"."T3" "T3"
WHERE "T1"."C1"="T2"."C1" AND "T2"."C1"="T3"."C1" 
SELECT
  T1.C1,
  T1.C2,
  T2.C1,
  T2.C2,
  T3.C2
FROM
  T1
LEFT OUTER JOIN
  T2
ON
  T1.C1=T2.C1,
  T3
WHERE
  T2.C1=T3.C1;

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2","T3"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2","TESTUSER"."T3" "T3"
WHERE "T2"."C1"="T3"."C1" AND "T1"."C1"="T2"."C1"

The final query after transformation is identical for this set of SQL statements, but notice that the optimizer apparently “lost” the “outer” portion of the  join between tables T1 and T2.  I do not think that is supposed to happen (or at least it was not intended – probably should have specified AND T2.C1=T3.C1(+) )!  This is the relevant portion of the 10053 trace file, in case anyone wants to investigate:

Join Elimination (JE)   
*************************
SQL:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2","T3"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2","TESTUSER"."T3" "T3" WHERE "T1"."C1"="T2"."C1"(+) AND "T2"."C1"="T3"."C1"
SQL:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2","T3"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2","TESTUSER"."T3" "T3" WHERE "T1"."C1"="T2"."C1"(+) AND "T2"."C1"="T3"."C1"
Query block SEL$1 (#0) unchanged
CVM: Considering view merge in query block SEL$1 (#0)
OJE: Considering outer-join elimination on query block SEL$1 (#0)
OJE: considering predicate"T1"."C1"="T2"."C1"(+)

rejected
OJE: considering predicate"T2"."C1"="T3"."C1"

OJE:      Converting outer join of T2 and T1 to inner-join.
considered
Registered qb: SEL$6E71C6F6 0x1fbfcba0 (OUTER-JOIN REMOVED FROM QUERY BLOCK SEL$1; SEL$1)
---------------------
QUERY BLOCK SIGNATURE
---------------------
  signature (): qb_name=SEL$6E71C6F6 nbfros=3 flg=0
    fro(0): flg=0 objn=82957 hint_alias="T1"@"SEL$1"
    fro(1): flg=0 objn=82958 hint_alias="T2"@"SEL$1"
    fro(2): flg=0 objn=83037 hint_alias="T3"@"SEL$1"

OJE:   outer-join eliminated
JE:   Considering Join Elimination on query block SEL$6E71C6F6 (#0)
*************************
Join Elimination (JE)   
*************************
SQL:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2","T3"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2","TESTUSER"."T3" "T3" WHERE "T1"."C1"="T2"."C1" AND "T2"."C1"="T3"."C1"
SQL:******* UNPARSED QUERY IS *******
SELECT "T1"."C1" "C1","T1"."C2" "C2","T2"."C1" "C1","T2"."C2" "C2","T3"."C2" "C2" FROM "TESTUSER"."T1" "T1","TESTUSER"."T2" "T2","TESTUSER"."T3" "T3" WHERE "T1"."C1"="T2"."C1" AND "T2"."C1"="T3"."C1"

Considering the above transformation, I now feel a little ansy about Oracle join syntax.





Explain Plan Shows a Cartesian Merge Join, How Would You Help?

24 12 2010

December 24, 2010

Imagine that a developer approached you with the following SQL statement, and explained that he (or she) noticed that the execution plan showed a Cartesian merge join.  Even adding an ORDERED hint did not affect the execution plan, and the execution performance was the same with the ORDERED hint.

SELECT X.TIME_PERIOD EXPOSURE_PERIOD,Y.TIME_PERIOD EVALUATION_PERIOD,BUSINESS_UNIT,
TO_NUMBER(LOB_VALUE) BUSINESS_UNIT_LOB_ID_FIN,0 CALC_VALUE

FROM ACTUARIAL_REF_DATA.TIME_PERIOD_HIERARCHY X,ACTUARIAL_REF_DATA.TIME_PERIOD_HIERARCHY Y,ANALYSIS_BUSINESS_UNITS, ANALYSIS_LOBS

WHERE X.TIME_PERIOD BETWEEN TO_NUMBER('200001') AND TO_NUMBER('200212')
AND Y.TIME_PERIOD BETWEEN TO_NUMBER('200001') AND TO_NUMBER('200212')
AND BUSINESS_UNIT = '33011';

Cartesian joins are not automatically a sign of problems.  Previous blog articles have demonstrated that a Cartesian join may be more efficient than other methods for certain situations (see Improving Performance by Using a Cartesian Join and Improving Performance by Using a Cartesian Join 2), the execution plan may simply display a Cartesian join rather than a nested loops join when one of the row sources is expected to return a single row, or the optimizer may introduce a Cartesian join as a transformation due of transitive closure (see this article).

How would you help the developer with the above SQL statement?  Would you first attempt to reformat the SQL statement, or would you do something else as the first step (note that this blog article is not specifically interested in just helping the developer with this one SQL statement, but instead is seeking advice to help the developer know what to do the next time)?  Think about the SQL statement for a moment…

Almost a year ago I put together another blog article (SQL Basics – Working with ERP Data) that was based on a small portion of a presentation that I gave to an ERP user’s group.  I almost created a new blog article that basically stated the same tips shortly after I saw the above SQL statement in this OTN thread (please do not visit the thread until you have had a chance to think about the SQL statement, and how you would help the developer).





SELECT Statement is Fast, INSERT INTO Using the SELECT Statement is Brutally Slow 3

20 12 2010

December 20, 2010

(Back to the Previous Post in the Series)

The previous article in this series included a test case that demonstrated significantly different performance for a SELECT statement and an INSERT INTO statement that used the same SELECT statement as the data source.  This blog article includes the timing results and the execution plans that were generated from the script in the previous blog article.  At the end of this blog article is an unexpected twist – see if you are able to determine what caused the behavior.

———–

SELECT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.23 seconds when selecting 10,478 rows:

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |  1425 |           |
| 1   |  SORT GROUP BY               |            |   486 |   46K |  1425 |  00:00:12 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1423 |  00:00:12 |
| 4   |     VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 5   |      SORT GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   19K | 1126K |  1055 |  00:00:09 |
| 10  |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 11  |       SORT GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       8303  consistent gets                                                   
          0  physical reads                                                    
      62292  redo size                                                         
     141157  bytes sent via SQL*Net to client                                  
        470  bytes received via SQL*Net from client                            
         12  SQL*Net roundtrips to/from client                                 
          3  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed  

INSERT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in… 30 minutes, 18.01 seconds when inserting 10,478 rows:

-------------------------------------------------+-----------------------------------+
| Id  | Operation                      | Name    | Rows  | Bytes | Cost  | Time      |
-------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT               |         |       |       | 4964K |           |
| 1   |  LOAD TABLE CONVENTIONAL       |         |       |       |       |           |
| 2   |   SORT GROUP BY                |         |   842 |   60K | 4964K |  11:18:45 |
| 3   |    FILTER                      |         |       |       |       |           |
| 4   |     HASH JOIN OUTER            |         |   842 |   60K | 4964K |  11:18:45 |
| 5   |      VIEW                      |         |   842 |   28K | 4964K |  11:18:42 |
| 6   |       FILTER                   |         |       |       |       |           |
| 7   |        SORT GROUP BY           |         |   842 |   53K | 4964K |  11:18:42 |
| 8   |         FILTER                 |         |       |       |       |           |
| 9   |          HASH JOIN             |         |  852M |   54G |  7031 |  00:00:57 |
| 10  |           INDEX FAST FULL SCAN | T1_PK   |  106K | 2755K |    60 |  00:00:01 |
| 11  |           TABLE ACCESS FULL    | T1_LINES| 5628K |  214M |  3388 |  00:00:28 |
| 12  |      VIEW                      |         |   700 |   27K |   368 |  00:00:03 |
| 13  |       SORT GROUP BY            |         |   700 |   40K |   368 |  00:00:03 |
| 14  |        HASH JOIN               |         |  146K | 8452K |   362 |  00:00:03 |
| 15  |         TABLE ACCESS FULL      | T2      |   700 |   18K |     3 |  00:00:01 |
| 16  |         TABLE ACCESS FULL      | T2_LINES|  146K | 4663K |   358 |  00:00:03 |
-------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - filter("EL"."RELID"=MAX("RELID"))
8 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
9 - access("E"."CUSTPO"="EL"."CUSTPO")
11 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND "EL"."FCSTQTY">0))
14 - access("CO"."ID"="COL"."CUST_ORDER_ID")
15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
16 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)

Statistics
----------------------------------------------------------                     
       1174  recursive calls                                                   
        454  db block gets                                                     
      84217  consistent gets                                                   
     214160  physical reads                                                    
     401488  redo size                                                         
        569  bytes sent via SQL*Net to client                                  
       1520  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
          6  sorts (memory)                                                    
          2  sorts (disk)                                                      
      10478  rows processed                                                     

SELECT_10.2.0.2 (OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.20 seconds when selecting 10,478 rows:

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |  1425 |           |
| 1   |  SORT GROUP BY               |            |   486 |   46K |  1425 |  00:00:12 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1423 |  00:00:12 |
| 4   |     VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 5   |      HASH GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   19K | 1126K |  1055 |  00:00:09 |
| 10  |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 11  |       HASH GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       7457  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     141157  bytes sent via SQL*Net to client                                  
        470  bytes received via SQL*Net from client                            
         12  SQL*Net roundtrips to/from client                                 
          1  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

INSERT_10.2.0.2 (OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.23 seconds when inserting 10,478 rows:

---------------------------------------------------+-----------------------------------+
| Id  | Operation                     | Name       | Rows  | Bytes | Cost  | Time      |
---------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT              |            |       |       |  1425 |           |
| 1   |  LOAD TABLE CONVENTIONAL      |            |       |       |       |           |
| 2   |   SORT GROUP BY               |            |   486 |   46K |  1425 |  00:00:12 |
| 3   |    FILTER                     |            |       |       |       |           |
| 4   |     HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1423 |  00:00:12 |
| 5   |      VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 6   |       SORT GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 7   |        HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 8   |         TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 9   |         TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 10  |      NESTED LOOPS             |            |   19K | 1126K |  1055 |  00:00:09 |
| 11  |       VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 12  |        SORT GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 13  |         FILTER                |            |       |       |       |           |
| 14  |          INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 15  |       INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
---------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - access("CO"."ID"="COL"."CUST_ORDER_ID")
8 - filter("CUSTOMER_PO_REF" IS NOT NULL)
9 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
13 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
15 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
15 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
        186  recursive calls                                                   
        341  db block gets                                                     
       7561  consistent gets                                                   
          0  physical reads                                                    
     397832  redo size                                                         
        569  bytes sent via SQL*Net to client                                  
       1520  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
          4  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

SELECT_11.1.0.7 (OPTIMIZER_FEATURES_ENABLE=’11.1.0.7′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.23 seconds when selecting 10,478 rows:

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |  1392 |           |
| 1   |  SORT GROUP BY               |            |   829 |   79K |  1392 |  00:00:12 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1390 |  00:00:12 |
| 4   |     VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 5   |      HASH GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   19K | 1126K |  1022 |  00:00:09 |
| 10  |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 11  |       HASH GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       7457  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     141157  bytes sent via SQL*Net to client                                  
        470  bytes received via SQL*Net from client                            
         12  SQL*Net roundtrips to/from client                                 
          1  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

INSERT_11.1.0.7 (OPTIMIZER_FEATURES_ENABLE=’11.1.0.7′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.25 seconds when inserting 10,478 rows:

---------------------------------------------------+-----------------------------------+
| Id  | Operation                     | Name       | Rows  | Bytes | Cost  | Time      |
---------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT              |            |       |       |  1392 |           |
| 1   |  LOAD TABLE CONVENTIONAL      |            |       |       |       |           |
| 2   |   SORT GROUP BY               |            |   829 |   79K |  1392 |  00:00:12 |
| 3   |    FILTER                     |            |       |       |       |           |
| 4   |     HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1390 |  00:00:12 |
| 5   |      VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 6   |       SORT GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 7   |        HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 8   |         TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 9   |         TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 10  |      NESTED LOOPS             |            |   19K | 1126K |  1022 |  00:00:09 |
| 11  |       VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 12  |        SORT GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 13  |         FILTER                |            |       |       |       |           |
| 14  |          INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 15  |       INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
---------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - access("CO"."ID"="COL"."CUST_ORDER_ID")
8 - filter("CUSTOMER_PO_REF" IS NOT NULL)
9 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
13 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
15 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
15 - filter("EL"."FCSTQTY">0) 

Statistics
----------------------------------------------------------                     
        186  recursive calls                                                   
        341  db block gets                                                     
       7564  consistent gets                                                   
          0  physical reads                                                    
     397816  redo size                                                         
        569  bytes sent via SQL*Net to client                                  
       1520  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
          4  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

SELECT_11.2.0.1 (OPTIMIZER_FEATURES_ENABLE=’11.2.0.1′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.21 seconds when selecting 10,478 rows:

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |  1392 |           |
| 1   |  SORT GROUP BY               |            |   829 |   79K |  1392 |  00:00:12 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1390 |  00:00:12 |
| 4   |     VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 5   |      HASH GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   19K | 1126K |  1022 |  00:00:09 |
| 10  |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 11  |       HASH GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       7457  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     141157  bytes sent via SQL*Net to client                                  
        470  bytes received via SQL*Net from client                            
         12  SQL*Net roundtrips to/from client                                 
          1  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

INSERT_11.2.0.1 (OPTIMIZER_FEATURES_ENABLE=’11.2.0.1′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.26 seconds when inserting 10,478 rows:

---------------------------------------------------+-----------------------------------+
| Id  | Operation                     | Name       | Rows  | Bytes | Cost  | Time      |
---------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT              |            |       |       |  1392 |           |
| 1   |  LOAD TABLE CONVENTIONAL      |            |       |       |       |           |
| 2   |   SORT GROUP BY               |            |   829 |   79K |  1392 |  00:00:12 |
| 3   |    FILTER                     |            |       |       |       |           |
| 4   |     HASH JOIN RIGHT OUTER     |            |   19K | 1882K |  1390 |  00:00:12 |
| 5   |      VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 6   |       SORT GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 7   |        HASH JOIN              |            |  146K | 8452K |   362 |  00:00:03 |
| 8   |         TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 9   |         TABLE ACCESS FULL     | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 10  |      NESTED LOOPS             |            |   19K | 1126K |  1022 |  00:00:09 |
| 11  |       VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 12  |        SORT GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 13  |         FILTER                |            |       |       |       |           |
| 14  |          INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 15  |       INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
---------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - access("CO"."ID"="COL"."CUST_ORDER_ID")
8 - filter("CUSTOMER_PO_REF" IS NOT NULL)
9 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
13 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
15 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
15 - filter("EL"."FCSTQTY">0) 

Statistics
----------------------------------------------------------                     
        186  recursive calls                                                   
        341  db block gets                                                     
       7563  consistent gets                                                   
          0  physical reads                                                    
     397876  redo size                                                         
        569  bytes sent via SQL*Net to client                                  
       1520  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
          4  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

——————–

SELECT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=100, OPTIMIZER_INDEX_COST_ADJ=80), completed in 0.21 seconds when selecting 10,478 rows (execution plan is affected by the changes to OPTIMIZER_INDEX_CACHING and OPTIMIZER_INDEX_COST_ADJ):

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |   436 |           |
| 1   |  SORT GROUP BY               |            |   486 |   46K |   436 |  00:00:04 |
| 2   |   NESTED LOOPS               |            |   994 |   94K |   435 |  00:00:04 |
| 3   |    FILTER                    |            |       |       |       |           |
| 4   |     HASH JOIN OUTER          |            |   700 |   41K |   433 |  00:00:04 |
| 5   |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 6   |       SORT GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 7   |        FILTER                |            |       |       |       |           |
| 8   |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 9   |      VIEW                    |            |   700 |   27K |   368 |  00:00:03 |
| 10  |       SORT GROUP BY          |            |   700 |   40K |   368 |  00:00:03 |
| 11  |        HASH JOIN             |            |  146K | 8452K |   362 |  00:00:03 |
| 12  |         TABLE ACCESS FULL    | T2         |   700 |   18K |     3 |  00:00:01 |
| 13  |         TABLE ACCESS FULL    | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 14  |    INDEX RANGE SCAN          | T1_LINES_PK|     1 |    37 |     1 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
11 - access("CO"."ID"="COL"."CUST_ORDER_ID")
12 - filter("CUSTOMER_PO_REF" IS NOT NULL)
13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter(("EL"."FCSTQTY">0 AND "EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))) 

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       7457  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     141157  bytes sent via SQL*Net to client                                  
        470  bytes received via SQL*Net from client                            
         12  SQL*Net roundtrips to/from client                                 
          3  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

INSERT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=100, OPTIMIZER_INDEX_COST_ADJ=80), completed in… 15 minutes, 11.32 seconds when inserting 10,478 rows (execution plan is unaffected by the changes to OPTIMIZER_INDEX_CACHING and OPTIMIZER_INDEX_COST_ADJ, although the execution completed twice as fast):

-------------------------------------------------+-----------------------------------+
| Id  | Operation                      | Name    | Rows  | Bytes | Cost  | Time      |
-------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT               |         |       |       | 4964K |           |
| 1   |  LOAD TABLE CONVENTIONAL       |         |       |       |       |           |
| 2   |   SORT GROUP BY                |         |   842 |   60K | 4964K |  11:18:45 |
| 3   |    FILTER                      |         |       |       |       |           |
| 4   |     HASH JOIN OUTER            |         |   842 |   60K | 4964K |  11:18:45 |
| 5   |      VIEW                      |         |   842 |   28K | 4964K |  11:18:42 |
| 6   |       FILTER                   |         |       |       |       |           |
| 7   |        SORT GROUP BY           |         |   842 |   53K | 4964K |  11:18:42 |
| 8   |         FILTER                 |         |       |       |       |           |
| 9   |          HASH JOIN             |         |  852M |   54G |  7031 |  00:00:57 |
| 10  |           INDEX FAST FULL SCAN | T1_PK   |  106K | 2755K |    60 |  00:00:01 |
| 11  |           TABLE ACCESS FULL    | T1_LINES| 5628K |  214M |  3388 |  00:00:28 |
| 12  |      VIEW                      |         |   700 |   27K |   368 |  00:00:03 |
| 13  |       SORT GROUP BY            |         |   700 |   40K |   368 |  00:00:03 |
| 14  |        HASH JOIN               |         |  146K | 8452K |   362 |  00:00:03 |
| 15  |         TABLE ACCESS FULL      | T2      |   700 |   18K |     3 |  00:00:01 |
| 16  |         TABLE ACCESS FULL      | T2_LINES|  146K | 4663K |   358 |  00:00:03 |
-------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - filter("EL"."RELID"=MAX("RELID"))
8 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
9 - access("E"."CUSTPO"="EL"."CUSTPO")
11 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND "EL"."FCSTQTY">0))
14 - access("CO"."ID"="COL"."CUST_ORDER_ID")
15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
16 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)

Statistics
----------------------------------------------------------                     
        618  recursive calls                                                   
        388  db block gets                                                     
      42148  consistent gets                                                   
     107080  physical reads                                                    
     397876  redo size                                                         
        569  bytes sent via SQL*Net to client                                  
       1523  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
          3  sorts (memory)                                                    
          1  sorts (disk)                                                      
      10478  rows processed

SELECT_10.2.0.2 (OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′, OPTIMIZER_INDEX_CACHING=100, OPTIMIZER_INDEX_COST_ADJ=80), completed in 0.20 seconds when selecting 10,478 rows (excution plans are identical for SELECT and INSERT INTO for the OPTIMIZER_FEATURES_ENABLE values 10.2.0.2, 11.1.0.7, and 11.2.0.1):

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |   436 |           |
| 1   |  SORT GROUP BY               |            |   486 |   46K |   436 |  00:00:04 |
| 2   |   NESTED LOOPS               |            |   994 |   94K |   435 |  00:00:04 |
| 3   |    FILTER                    |            |       |       |       |           |
| 4   |     HASH JOIN OUTER          |            |   700 |   41K |   433 |  00:00:04 |
| 5   |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 6   |       HASH GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 7   |        FILTER                |            |       |       |       |           |
| 8   |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 9   |      VIEW                    |            |   700 |   27K |   368 |  00:00:03 |
| 10  |       HASH GROUP BY          |            |   700 |   40K |   368 |  00:00:03 |
| 11  |        HASH JOIN             |            |  146K | 8452K |   362 |  00:00:03 |
| 12  |         TABLE ACCESS FULL    | T2         |   700 |   18K |     3 |  00:00:01 |
| 13  |         TABLE ACCESS FULL    | T2_LINES   |  146K | 4663K |   358 |  00:00:03 |
| 14  |    INDEX RANGE SCAN          | T1_LINES_PK|     1 |    37 |     1 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
11 - access("CO"."ID"="COL"."CUST_ORDER_ID")
12 - filter("CUSTOMER_PO_REF" IS NOT NULL)
13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter(("EL"."FCSTQTY">0 AND "EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)))

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       7457  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     141157  bytes sent via SQL*Net to client                                  
        470  bytes received via SQL*Net from client                            
         12  SQL*Net roundtrips to/from client                                 
          1  sorts (memory)                                                    
          0  sorts (disk)                                                      
      10478  rows processed

————————-

The odd twist… assume that you used either Oracle Database 11.2.0.1 or 11.2.0.2 for the test.  12 hours after your test completed, you executed the following SQL statements to pull the execution plans and non-default optimizer parameters for the test SQL statements from the server’s memory:

SET AUTOTRACE OFF
SET LINESIZE 150
SET PAGESIZE 1000
SET TRIMSPOOL ON
SPOOL MYSQL_PLANS.TXT

SELECT /*+ LEADING(S) USE_NL(S T) */
  T.PLAN_TABLE_OUTPUT
FROM
  (SELECT
    SQL_ID,
    CHILD_NUMBER,
    COUNT(*) OVER (PARTITION BY SQL_ID) C
  FROM
    V$SQL
  WHERE
    SQL_TEXT LIKE '%T2%'
    AND SQL_TEXT LIKE '%T1%'
    AND SQL_TEXT NOT LIKE '%MGMT_NOTIFY%'
  ORDER BY
    SQL_ID,
    CHILD_NUMBER) S,
  TABLE(DBMS_XPLAN.DISPLAY_CURSOR(S.SQL_ID,S.CHILD_NUMBER,'TYPICAL')) T
WHERE
  S.C>=1;

SPOOL OFF

SET LINESIZE 150
SET PAGESIZE 1000
SET TRIMSPOOL ON
SPOOL MYSQL_OPTIMIZER_ENV.TXT

SELECT /*+ LEADING(S) USE_NL(S T) */
  SOE.SQL_ID,
  SOE.CHILD_NUMBER,
  SOE.NAME,
  SOE.VALUE
FROM
  (SELECT
    SQL_ID,
    CHILD_NUMBER,
    COUNT(*) OVER (PARTITION BY SQL_ID) C
  FROM
    V$SQL
  WHERE
    SQL_TEXT LIKE '%T2%'
    AND SQL_TEXT LIKE '%T1%'
    AND SQL_TEXT NOT LIKE '%MGMT_NOTIFY%'
  ORDER BY
    SQL_ID,
    CHILD_NUMBER) S,
  V$SQL_OPTIMIZER_ENV SOE
WHERE
  S.SQL_ID=SOE.SQL_ID
  AND S.CHILD_NUMBER=SOE.CHILD_NUMBER
  AND SOE.ISDEFAULT='NO'
ORDER BY
  SOE.SQL_ID,
  SOE.CHILD_NUMBER,
  SOE.NAME;

SPOOL OFF 

Assume that you saw included in the output something like this following:

SQL_ID  4kkx042dnfuvf, child number 0
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+ _80 */       E.CUSTPO,       MAX(RELID) RELID     FROM
 T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY

Plan hash value: 1947245329

-------------------------------------------------------------------------------------------
| Id  | Operation                   | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |             |       |       |   436 (100)|          |
|   1 |  SORT GROUP BY              |             |   829 | 80413 |   436   (7)| 00:00:04 |
|   2 |   NESTED LOOPS              |             |   994 | 96418 |   435   (6)| 00:00:04 |
|*  3 |    FILTER                   |             |       |       |            |          |
|*  4 |     HASH JOIN OUTER         |             |   700 | 42000 |   433   (6)| 00:00:04 |
|   5 |      VIEW                   |             |   700 | 14700 |    65  (10)| 00:00:01 |
|   6 |       HASH GROUP BY         |             |   700 | 18200 |    65  (10)| 00:00:01 |
|*  7 |        FILTER               |             |       |       |            |          |
|   8 |         INDEX FAST FULL SCAN| T1_PK       |   108K|  2754K|    60   (2)| 00:00:01 |
|   9 |      VIEW                   |             |   700 | 27300 |   368   (6)| 00:00:03 |
|  10 |       HASH GROUP BY         |             |   700 | 40600 |   368   (6)| 00:00:03 |
|* 11 |        HASH JOIN            |             |   149K|  8456K|   362   (4)| 00:00:03 |
|* 12 |         TABLE ACCESS FULL   | T2          |   700 | 18200 |     3   (0)| 00:00:01 |
|* 13 |         TABLE ACCESS FULL   | T2_LINES    |   149K|  4665K|   358   (4)| 00:00:03 |
|* 14 |    INDEX RANGE SCAN         | T1_LINES_PK |     1 |    37 |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - filter(COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
   4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  11 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  12 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND
              "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND
              "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter(("EL"."FCSTQTY">0 AND "EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DA
              TE",SYSDATE@!-365))) 

 

SQL_ID  4kkx042dnfuvf, child number 1
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+ _80 */       E.CUSTPO,       MAX(RELID) RELID     FROM
 T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY

Plan hash value: 1232865634

---------------------------------------------------------------------------------------------------------
| Id  | Operation                        | Name         | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |              |       |       |       |  5087K(100)|          |
|   1 |  SORT GROUP BY                   |              |   842 | 61466 |       |  5087K  (2)| 11:18:20 |
|*  2 |   FILTER                         |              |       |       |       |            |          |
|*  3 |    HASH JOIN OUTER               |              |   842 | 61466 |       |  5087K  (2)| 11:18:20 |
|   4 |     VIEW                         |              |   842 | 28628 |       |  5083K  (2)| 11:17:48 |
|*  5 |      FILTER                      |              |       |       |       |            |          |
|   6 |       SORT GROUP BY              |              |   842 | 54730 |    77G|  5083K  (2)| 11:17:48 |
|*  7 |        FILTER                    |              |       |       |       |            |          |
|   8 |         NESTED LOOPS             |              |   893M|    54G|       |  7225 (100)| 00:00:58 |
|   9 |          INDEX FAST FULL SCAN    | T1_PK        |   108K|  2754K|       |    59   (2)| 00:00:01 |
|* 10 |          INDEX RANGE SCAN        | T1_LINES_PK  |  8233 |   313K|       |     2  (50)| 00:00:01 |
|  11 |     VIEW                         |              |   700 | 27300 |       |  3939   (1)| 00:00:32 |
|  12 |      SORT GROUP BY               |              |   700 | 40600 |       |  3939   (1)| 00:00:32 |
|* 13 |       TABLE ACCESS BY INDEX ROWID| T2_LINES     |   213 |  6816 |       |     6   (0)| 00:00:01 |
|  14 |        NESTED LOOPS              |              |   149K|  8456K|       |  3933   (1)| 00:00:32 |
|* 15 |         TABLE ACCESS FULL        | T2           |   700 | 18200 |       |     3  (34)| 00:00:01 |
|* 16 |         INDEX RANGE SCAN         | SYS_C0027538 |   321 |       |       |     2  (50)| 00:00:01 |
---------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  10 - access("E"."CUSTPO"="EL"."CUSTPO" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND
              "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND
              "EL"."FCSTQTY">0))
  13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  16 - access("CO"."ID"="COL"."CUST_ORDER_ID") 

 

SQL_ID  4kkx042dnfuvf, child number 2
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+ _80 */       E.CUSTPO,       MAX(RELID) RELID     FROM
 T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY

Plan hash value: 4293267978

----------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name        | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |             |       |       |       |  5083K(100)|          |
|   1 |  SORT GROUP BY               |             |   842 | 61466 |       |  5083K  (2)| 11:17:51 |
|*  2 |   FILTER                     |             |       |       |       |            |          |
|*  3 |    HASH JOIN OUTER           |             |   842 | 61466 |       |  5083K  (2)| 11:17:51 |
|   4 |     VIEW                     |             |   842 | 28628 |       |  5083K  (2)| 11:17:48 |
|*  5 |      FILTER                  |             |       |       |       |            |          |
|   6 |       SORT GROUP BY          |             |   842 | 54730 |    77G|  5083K  (2)| 11:17:48 |
|*  7 |        FILTER                |             |       |       |       |            |          |
|   8 |         NESTED LOOPS         |             |   893M|    54G|       |  7226 (100)| 00:00:58 |
|   9 |          INDEX FAST FULL SCAN| T1_PK       |   108K|  2754K|       |    60   (2)| 00:00:01 |
|* 10 |          INDEX RANGE SCAN    | T1_LINES_PK |  8233 |   313K|       |     2  (50)| 00:00:01 |
|  11 |     VIEW                     |             |   700 | 27300 |       |   369   (6)| 00:00:03 |
|  12 |      SORT GROUP BY           |             |   700 | 40600 |       |   369   (6)| 00:00:03 |
|* 13 |       HASH JOIN              |             |   149K|  8456K|       |   362   (4)| 00:00:03 |
|* 14 |        TABLE ACCESS FULL     | T2          |   700 | 18200 |       |     4  (25)| 00:00:01 |
|* 15 |        TABLE ACCESS FULL     | T2_LINES    |   149K|  4665K|       |   358   (4)| 00:00:03 |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  10 - access("E"."CUSTPO"="EL"."CUSTPO" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND
              "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND
              "EL"."FCSTQTY">0))
  13 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  14 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  15 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

 

SQL_ID  4kkx042dnfuvf, child number 3
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+ _80 */       E.CUSTPO,       MAX(RELID) RELID     FROM
 T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY

Plan hash value: 3038192993

-------------------------------------------------------------------------------------------
| Id  | Operation                   | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |             |       |       |   436 (100)|          |
|   1 |  SORT GROUP BY              |             |   486 | 47142 |   436   (7)| 00:00:04 |
|   2 |   NESTED LOOPS              |             |   994 | 96418 |   435   (6)| 00:00:04 |
|*  3 |    FILTER                   |             |       |       |            |          |
|*  4 |     HASH JOIN OUTER         |             |   700 | 42000 |   433   (6)| 00:00:04 |
|   5 |      VIEW                   |             |   700 | 14700 |    65  (10)| 00:00:01 |
|   6 |       SORT GROUP BY         |             |   700 | 18200 |    65  (10)| 00:00:01 |
|*  7 |        FILTER               |             |       |       |            |          |
|   8 |         INDEX FAST FULL SCAN| T1_PK       |   108K|  2754K|    60   (2)| 00:00:01 |
|   9 |      VIEW                   |             |   700 | 27300 |   368   (6)| 00:00:03 |
|  10 |       SORT GROUP BY         |             |   700 | 40600 |   368   (6)| 00:00:03 |
|* 11 |        HASH JOIN            |             |   149K|  8456K|   362   (4)| 00:00:03 |
|* 12 |         TABLE ACCESS FULL   | T2          |   700 | 18200 |     3   (0)| 00:00:01 |
|* 13 |         TABLE ACCESS FULL   | T2_LINES    |   149K|  4665K|   358   (4)| 00:00:03 |
|* 14 |    INDEX RANGE SCAN         | T1_LINES_PK |     1 |    37 |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - filter(COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
   4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  11 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  12 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND
              "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND
              "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter(("EL"."FCSTQTY">0 AND "EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DA
              TE",SYSDATE@!-365))) 

 

SQL_ID  bqsrv9mngjdfu, child number 0
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+  */       E.CUSTPO,       MAX(RELID) RELID     FROM
T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY   CO

Plan hash value: 1522673873

-------------------------------------------------------------------------------------------
| Id  | Operation                   | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |             |       |       |  1392 (100)|          |
|   1 |  SORT GROUP BY              |             |   829 | 80413 |  1392   (3)| 00:00:12 |
|*  2 |   FILTER                    |             |       |       |            |          |
|*  3 |    HASH JOIN RIGHT OUTER    |             | 19874 |  1882K|  1390   (2)| 00:00:12 |
|   4 |     VIEW                    |             |   700 | 27300 |   368   (6)| 00:00:03 |
|   5 |      HASH GROUP BY          |             |   700 | 40600 |   368   (6)| 00:00:03 |
|*  6 |       HASH JOIN             |             |   149K|  8456K|   362   (4)| 00:00:03 |
|*  7 |        TABLE ACCESS FULL    | T2          |   700 | 18200 |     3   (0)| 00:00:01 |
|*  8 |        TABLE ACCESS FULL    | T2_LINES    |   149K|  4665K|   358   (4)| 00:00:03 |
|   9 |     NESTED LOOPS            |             | 19874 |  1125K|  1022   (1)| 00:00:09 |
|  10 |      VIEW                   |             |   700 | 14700 |    65  (10)| 00:00:01 |
|  11 |       HASH GROUP BY         |             |   700 | 18200 |    65  (10)| 00:00:01 |
|* 12 |        FILTER               |             |       |       |            |          |
|  13 |         INDEX FAST FULL SCAN| T1_PK       |   108K|  2754K|    60   (2)| 00:00:01 |
|* 14 |      INDEX RANGE SCAN       | T1_LINES_PK |    28 |  1036 |     3   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)
              AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
   7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
   8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND
              "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND
              "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter("EL"."FCSTQTY">0) 

 

SQL_ID  bqsrv9mngjdfu, child number 1
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+  */       E.CUSTPO,       MAX(RELID) RELID     FROM
T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY   CO

Plan hash value: 1232865634

---------------------------------------------------------------------------------------------------------
| Id  | Operation                        | Name         | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |              |       |       |       |    16M(100)|          |
|   1 |  SORT GROUP BY                   |              |   842 | 61466 |       |    16M  (1)| 35:51:03 |
|*  2 |   FILTER                         |              |       |       |       |            |          |
|*  3 |    HASH JOIN OUTER               |              |   842 | 61466 |       |    16M  (1)| 35:51:03 |
|   4 |     VIEW                         |              |   842 | 28628 |       |    16M  (1)| 35:50:07 |
|*  5 |      FILTER                      |              |       |       |       |            |          |
|   6 |       SORT GROUP BY              |              |   842 | 54730 |    77G|    16M  (1)| 35:50:07 |
|*  7 |        FILTER                    |              |       |       |       |            |          |
|   8 |         NESTED LOOPS             |              |   893M|    54G|       |    11M  (1)| 24:33:17 |
|   9 |          INDEX FAST FULL SCAN    | T1_PK        |   108K|  2754K|       |    59   (2)| 00:00:01 |
|* 10 |          INDEX RANGE SCAN        | T1_LINES_PK  |  8233 |   313K|       |   104   (1)| 00:00:01 |
|  11 |     VIEW                         |              |   700 | 27300 |       |  7023   (1)| 00:00:57 |
|  12 |      SORT GROUP BY               |              |   700 | 40600 |       |  7023   (1)| 00:00:57 |
|* 13 |       TABLE ACCESS BY INDEX ROWID| T2_LINES     |   213 |  6816 |       |    11  (10)| 00:00:01 |
|  14 |        NESTED LOOPS              |              |   149K|  8456K|       |  7016   (1)| 00:00:57 |
|* 15 |         TABLE ACCESS FULL        | T2           |   700 | 18200 |       |     3  (34)| 00:00:01 |
|* 16 |         INDEX RANGE SCAN         | SYS_C0027538 |   321 |       |       |     4  (25)| 00:00:01 |
---------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  10 - access("E"."CUSTPO"="EL"."CUSTPO" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND
              "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND
              "EL"."FCSTQTY">0))
  13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  16 - access("CO"."ID"="COL"."CUST_ORDER_ID") 

 

SQL_ID  bqsrv9mngjdfu, child number 2
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+  */       E.CUSTPO,       MAX(RELID) RELID     FROM
T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY   CO

Plan hash value: 3881822961

-------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |       |       |       |  5083K(100)|          |
|   1 |  SORT GROUP BY               |          |   842 | 61466 |       |  5083K  (2)| 11:17:50 |
|*  2 |   FILTER                     |          |       |       |       |            |          |
|*  3 |    HASH JOIN OUTER           |          |   842 | 61466 |       |  5083K  (2)| 11:17:50 |
|   4 |     VIEW                     |          |   842 | 28628 |       |  5083K  (2)| 11:17:47 |
|*  5 |      FILTER                  |          |       |       |       |            |          |
|   6 |       SORT GROUP BY          |          |   842 | 54730 |    77G|  5083K  (2)| 11:17:47 |
|*  7 |        FILTER                |          |       |       |       |            |          |
|*  8 |         HASH JOIN            |          |   893M|    54G|  4032K|  7033   (9)| 00:00:57 |
|   9 |          INDEX FAST FULL SCAN| T1_PK    |   108K|  2754K|       |    60   (2)| 00:00:01 |
|* 10 |          TABLE ACCESS FULL   | T1_LINES |  5763K|   214M|       |  3389  (16)| 00:00:28 |
|  11 |     VIEW                     |          |   700 | 27300 |       |   369   (6)| 00:00:03 |
|  12 |      SORT GROUP BY           |          |   700 | 40600 |       |   369   (6)| 00:00:03 |
|* 13 |       HASH JOIN              |          |   149K|  8456K|       |   362   (4)| 00:00:03 |
|* 14 |        TABLE ACCESS FULL     | T2       |   700 | 18200 |       |     4  (25)| 00:00:01 |
|* 15 |        TABLE ACCESS FULL     | T2_LINES |   149K|  4665K|       |   358   (4)| 00:00:03 |
-------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
   8 - access("E"."CUSTPO"="EL"."CUSTPO")
  10 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND
              "EL"."FCSTQTY">0))
  13 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  14 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  15 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

 

SQL_ID  bqsrv9mngjdfu, child number 3
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+  */       E.CUSTPO,       MAX(RELID) RELID     FROM
T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY   CO

Plan hash value: 4176222027

-------------------------------------------------------------------------------------------
| Id  | Operation                   | Name        | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |             |       |       |  1425 (100)|          |
|   1 |  SORT GROUP BY              |             |   486 | 47142 |  1425   (2)| 00:00:12 |
|*  2 |   FILTER                    |             |       |       |            |          |
|*  3 |    HASH JOIN RIGHT OUTER    |             | 19874 |  1882K|  1423   (2)| 00:00:12 |
|   4 |     VIEW                    |             |   700 | 27300 |   368   (6)| 00:00:03 |
|   5 |      SORT GROUP BY          |             |   700 | 40600 |   368   (6)| 00:00:03 |
|*  6 |       HASH JOIN             |             |   149K|  8456K|   362   (4)| 00:00:03 |
|*  7 |        TABLE ACCESS FULL    | T2          |   700 | 18200 |     3   (0)| 00:00:01 |
|*  8 |        TABLE ACCESS FULL    | T2_LINES    |   149K|  4665K|   358   (4)| 00:00:03 |
|   9 |     NESTED LOOPS            |             | 19874 |  1125K|  1055   (1)| 00:00:09 |
|  10 |      VIEW                   |             |   700 | 14700 |    65  (10)| 00:00:01 |
|  11 |       SORT GROUP BY         |             |   700 | 18200 |    65  (10)| 00:00:01 |
|* 12 |        FILTER               |             |       |       |            |          |
|  13 |         INDEX FAST FULL SCAN| T1_PK       |   108K|  2754K|    60   (2)| 00:00:01 |
|* 14 |      INDEX RANGE SCAN       | T1_LINES_PK |    28 |  1036 |     3   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)
              AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
   7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
   8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND
              "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND
              "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter("EL"."FCSTQTY">0) 

 

SQL_ID  bqsrv9mngjdfu, child number 4
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+  */       E.CUSTPO,       MAX(RELID) RELID     FROM
T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY   CO

Plan hash value: 1232865634

---------------------------------------------------------------------------------------------------------
| Id  | Operation                        | Name         | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |              |       |       |       |    16M(100)|          |
|   1 |  SORT GROUP BY                   |              |   842 | 61466 |       |    16M  (1)| 35:51:03 |
|*  2 |   FILTER                         |              |       |       |       |            |          |
|*  3 |    HASH JOIN OUTER               |              |   842 | 61466 |       |    16M  (1)| 35:51:03 |
|   4 |     VIEW                         |              |   842 | 28628 |       |    16M  (1)| 35:50:07 |
|*  5 |      FILTER                      |              |       |       |       |            |          |
|   6 |       SORT GROUP BY              |              |   842 | 54730 |    77G|    16M  (1)| 35:50:07 |
|*  7 |        FILTER                    |              |       |       |       |            |          |
|   8 |         NESTED LOOPS             |              |   893M|    54G|       |    11M  (1)| 24:33:17 |
|   9 |          INDEX FAST FULL SCAN    | T1_PK        |   108K|  2754K|       |    59   (2)| 00:00:01 |
|* 10 |          INDEX RANGE SCAN        | T1_LINES_PK  |  8233 |   313K|       |   104   (1)| 00:00:01 |
|  11 |     VIEW                         |              |   700 | 27300 |       |  7023   (1)| 00:00:57 |
|  12 |      SORT GROUP BY               |              |   700 | 40600 |       |  7023   (1)| 00:00:57 |
|* 13 |       TABLE ACCESS BY INDEX ROWID| T2_LINES     |   213 |  6816 |       |    11  (10)| 00:00:01 |
|  14 |        NESTED LOOPS              |              |   149K|  8456K|       |  7016   (1)| 00:00:57 |
|* 15 |         TABLE ACCESS FULL        | T2           |   700 | 18200 |       |     3  (34)| 00:00:01 |
|* 16 |         INDEX RANGE SCAN         | SYS_C0027538 |   321 |       |       |     4  (25)| 00:00:01 |
---------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
  10 - access("E"."CUSTPO"="EL"."CUSTPO" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND
              "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND
              "EL"."FCSTQTY">0))
  13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
  15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  16 - access("CO"."ID"="COL"."CUST_ORDER_ID") 

 SQL_ID  bqsrv9mngjdfu, child number 5
-------------------------------------
/* SQL Analyze(7,1) */ SELECT /*+ LEADING(E) */
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,   E.FCDUEDATE
REQUIRED_DATE,   SUM(E.FCSTQTY) QTY,   1 PLAN_LEVEL FROM   (SELECT /*+
LEADING(E) */     E.CUSTPO,     EL.FCSTQTY,     EL.FCDUEDATE   FROM
(SELECT /*+  */       E.CUSTPO,       MAX(RELID) RELID     FROM
T1 E     GROUP BY       E.CUSTPO) E,     T1_LINES EL   WHERE
E.CUSTPO=EL.CUSTPO     AND E.RELID=EL.RELID     AND EL.FCDUEDATE
BETWEEN SYSDATE-365 AND SYSDATE+1200     AND EL.FCSTQTY>0) E,   (SELECT
/*+  */     CO.CUSTOMER_PO_REF,     MAX(COL.DESIRED_SHIP_DATE)
DESIRED_SHIP_DATE,     MAX(COL.PART_ID) PART_ID   FROM     T2 CO,
T2_LINES COL   WHERE     CO.ID=COL.CUST_ORDER_ID     AND
CUSTOMER_PO_REF IS NOT NULL     AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
 GROUP BY     CO.CUSTOMER_PO_REF) CO WHERE
E.CUSTPO=CO.CUSTOMER_PO_REF(+)   AND
E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365) GROUP BY
COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),   E.FCDUEDATE ORDER BY   CO

Plan hash value: 3881822961

-------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |       |       |       |  5083K(100)|          |
|   1 |  SORT GROUP BY               |          |   842 | 61466 |       |  5083K  (2)| 11:17:50 |
|*  2 |   FILTER                     |          |       |       |       |            |          |
|*  3 |    HASH JOIN OUTER           |          |   842 | 61466 |       |  5083K  (2)| 11:17:50 |
|   4 |     VIEW                     |          |   842 | 28628 |       |  5083K  (2)| 11:17:47 |
|*  5 |      FILTER                  |          |       |       |       |            |          |
|   6 |       SORT GROUP BY          |          |   842 | 54730 |    77G|  5083K  (2)| 11:17:47 |
|*  7 |        FILTER                |          |       |       |       |            |          |
|*  8 |         HASH JOIN            |          |   893M|    54G|  4032K|  7033   (9)| 00:00:57 |
|   9 |          INDEX FAST FULL SCAN| T1_PK    |   108K|  2754K|       |    60   (2)| 00:00:01 |
|* 10 |          TABLE ACCESS FULL   | T1_LINES |  5763K|   214M|       |  3389  (16)| 00:00:28 |
|  11 |     VIEW                     |          |   700 | 27300 |       |   369   (6)| 00:00:03 |
|  12 |      SORT GROUP BY           |          |   700 | 40600 |       |   369   (6)| 00:00:03 |
|* 13 |       HASH JOIN              |          |   149K|  8456K|       |   362   (4)| 00:00:03 |
|* 14 |        TABLE ACCESS FULL     | T2       |   700 | 18200 |       |     4  (25)| 00:00:01 |
|* 15 |        TABLE ACCESS FULL     | T2_LINES |   149K|  4665K|       |   358   (4)| 00:00:03 |
-------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
   8 - access("E"."CUSTPO"="EL"."CUSTPO")
  10 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND
              "EL"."FCSTQTY">0))
  13 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  14 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  15 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

Assume that the second script produced the following (the blue text is directly related to the SQL statements that were executed by the script):

SQL_ID        CHILD_NUMBER NAME                                     VALUE
------------- ------------ ---------------------------------------- -------------------------
33n2n2z5a330f            0 _pga_max_size                            409600 KB
33n2n2z5a330f            0 optimizer_features_enable                10.1.0.4
-
33n2n2z5a330f            1 _pga_max_size                            409600 KB
33n2n2z5a330f            1 optimizer_features_enable                10.2.0.2
-
33n2n2z5a330f            2 _pga_max_size                            409600 KB
33n2n2z5a330f            2 optimizer_features_enable                11.1.0.7
-
33n2n2z5a330f            3 _pga_max_size                            409600 KB
------------------------------------------------------------------------------
4kkx042dnfuvf            0 _pga_max_size                            409600 KB
4kkx042dnfuvf            0 is_recur_flags                           72
4kkx042dnfuvf            0 optimizer_features_hinted                11.2.0.1
4kkx042dnfuvf            0 optimizer_index_caching                  100
4kkx042dnfuvf            0 optimizer_index_cost_adj                 80
4kkx042dnfuvf            0 optimizer_mode_hinted                    true
-
4kkx042dnfuvf            1 _pga_max_size                            409600 KB
4kkx042dnfuvf            1 is_recur_flags                           72
4kkx042dnfuvf            1 optimizer_dynamic_sampling               0
4kkx042dnfuvf            1 optimizer_features_hinted                9.0.0
4kkx042dnfuvf            1 optimizer_index_caching                  100
4kkx042dnfuvf            1 optimizer_index_cost_adj                 80
4kkx042dnfuvf            1 optimizer_mode_hinted                    true
4kkx042dnfuvf            1 query_rewrite_enabled                    false
4kkx042dnfuvf            1 skip_unusable_indexes                    false
-
4kkx042dnfuvf            2 _pga_max_size                            409600 KB
4kkx042dnfuvf            2 is_recur_flags                           72
4kkx042dnfuvf            2 optimizer_dynamic_sampling               1
4kkx042dnfuvf            2 optimizer_features_hinted                9.2.0.8
4kkx042dnfuvf            2 optimizer_index_caching                  100
4kkx042dnfuvf            2 optimizer_index_cost_adj                 80
4kkx042dnfuvf            2 optimizer_mode_hinted                    true
4kkx042dnfuvf            2 query_rewrite_enabled                    false
4kkx042dnfuvf            2 skip_unusable_indexes                    false
-
4kkx042dnfuvf            3 _pga_max_size                            409600 KB
4kkx042dnfuvf            3 is_recur_flags                           72
4kkx042dnfuvf            3 optimizer_features_hinted                10.1.0.5
4kkx042dnfuvf            3 optimizer_index_caching                  100
4kkx042dnfuvf            3 optimizer_index_cost_adj                 80
4kkx042dnfuvf            3 optimizer_mode_hinted                    true
------------------------------------------------------------------------------
bqsrv9mngjdfu            0 _pga_max_size                            409600 KB
bqsrv9mngjdfu            0 is_recur_flags                           72
bqsrv9mngjdfu            0 optimizer_features_hinted                11.2.0.1
bqsrv9mngjdfu            0 optimizer_mode_hinted                    true
-
bqsrv9mngjdfu            1 _pga_max_size                            409600 KB
bqsrv9mngjdfu            1 is_recur_flags                           72
bqsrv9mngjdfu            1 optimizer_dynamic_sampling               0
bqsrv9mngjdfu            1 optimizer_features_hinted                9.0.0
bqsrv9mngjdfu            1 optimizer_mode_hinted                    true
bqsrv9mngjdfu            1 query_rewrite_enabled                    false
bqsrv9mngjdfu            1 skip_unusable_indexes                    false
-
bqsrv9mngjdfu            2 _pga_max_size                            409600 KB
bqsrv9mngjdfu            2 is_recur_flags                           72
bqsrv9mngjdfu            2 optimizer_dynamic_sampling               1
bqsrv9mngjdfu            2 optimizer_features_hinted                9.2.0.8
bqsrv9mngjdfu            2 optimizer_mode_hinted                    true
bqsrv9mngjdfu            2 query_rewrite_enabled                    false
bqsrv9mngjdfu            2 skip_unusable_indexes                    false
-
bqsrv9mngjdfu            3 _pga_max_size                            409600 KB
bqsrv9mngjdfu            3 is_recur_flags                           72
bqsrv9mngjdfu            3 optimizer_features_hinted                10.1.0.5
bqsrv9mngjdfu            3 optimizer_mode_hinted                    true
-
bqsrv9mngjdfu            4 _pga_max_size                            409600 KB
bqsrv9mngjdfu            4 is_recur_flags                           72
bqsrv9mngjdfu            4 optimizer_dynamic_sampling               0
bqsrv9mngjdfu            4 optimizer_features_hinted                9.0.0
bqsrv9mngjdfu            4 optimizer_mode_hinted                    true
bqsrv9mngjdfu            4 query_rewrite_enabled                    false
bqsrv9mngjdfu            4 skip_unusable_indexes                    false
-
bqsrv9mngjdfu            5 _pga_max_size                            409600 KB
bqsrv9mngjdfu            5 is_recur_flags                           72
bqsrv9mngjdfu            5 optimizer_dynamic_sampling               1
bqsrv9mngjdfu            5 optimizer_features_hinted                9.2.0.8
bqsrv9mngjdfu            5 optimizer_mode_hinted                    true
bqsrv9mngjdfu            5 query_rewrite_enabled                    false
bqsrv9mngjdfu            5 skip_unusable_indexes                    false
------------------------------------------------------------------------------
gfb3g0axbj17z            0 _pga_max_size                            409600 KB
gfb3g0axbj17z            0 optimizer_features_enable                10.1.0.4
gfb3g0axbj17z            0 optimizer_index_caching                  100
gfb3g0axbj17z            0 optimizer_index_cost_adj                 80
-
gfb3g0axbj17z            1 _pga_max_size                            409600 KB
gfb3g0axbj17z            1 optimizer_features_enable                10.2.0.2
gfb3g0axbj17z            1 optimizer_index_caching                  100
gfb3g0axbj17z            1 optimizer_index_cost_adj                 80
-
gfb3g0axbj17z            2 _pga_max_size                            409600 KB
gfb3g0axbj17z            2 optimizer_features_enable                11.1.0.7
gfb3g0axbj17z            2 optimizer_index_caching                  100
gfb3g0axbj17z            2 optimizer_index_cost_adj                 80
-
gfb3g0axbj17z            3 _pga_max_size                            409600 KB
gfb3g0axbj17z            3 optimizer_index_caching                  100
gfb3g0axbj17z            3 optimizer_index_cost_adj                 80  

—————————————————————————————————————————–
—————————————————————————————————————————–

Just to put a slightly different spin on the test results, I repeated the test case on Oracle Database 10.2.0.5 Standard Edition (also Enterprise Edition) with an 8,000M SGA_TARGET and 1,800M PGA_AGGREGATE_TARGET.  The results?

SELECT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.34 seconds when selecting 10,478 rows (same execution plan for OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′):

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |  1368 |           |
| 1   |  SORT GROUP BY               |            |   489 |   46K |  1368 |  00:00:11 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   20K | 1906K |  1367 |  00:00:11 |
| 4   |     VIEW                     |            |   700 |   27K |   375 |  00:00:03 |
| 5   |      SORT GROUP BY           |            |   700 |   40K |   375 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8454K |   368 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4664K |   364 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   20K | 1140K |   992 |  00:00:08 |
| 10  |      VIEW                    |            |   671 |   14K |    65 |  00:00:01 |
| 11  |       SORT GROUP BY          |            |   671 |   17K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  107K | 2773K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    30 |  1110 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
       1434  recursive calls                                                   
          0  db block gets                                                     
       7818  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     104015  bytes sent via SQL*Net to client                                  
        549  bytes received via SQL*Net from client                            
          9  SQL*Net roundtrips to/from client                                 
         36  sorts (memory)                                                    
          0  sorts (disk)                                                      
       7604  rows processed

INSERT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in… 0.34 seconds when inserting 10,478 rows (same execution plan for OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′):

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT             |            |       |       |  1368 |           |
| 1   |  SORT GROUP BY               |            |   489 |   46K |  1368 |  00:00:11 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   20K | 1906K |  1367 |  00:00:11 |
| 4   |     VIEW                     |            |   700 |   27K |   375 |  00:00:03 |
| 5   |      SORT GROUP BY           |            |   700 |   40K |   375 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8454K |   368 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4664K |   364 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   20K | 1140K |   992 |  00:00:08 |
| 10  |      VIEW                    |            |   671 |   14K |    65 |  00:00:01 |
| 11  |       SORT GROUP BY          |            |   671 |   17K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  107K | 2773K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    30 |  1110 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0)

Statistics
----------------------------------------------------------                     
       1350  recursive calls                                                   
        468  db block gets                                                     
       7981  consistent gets                                                   
          0  physical reads                                                    
     293716  redo size                                                         
        817  bytes sent via SQL*Net to client                                  
       1709  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
         21  sorts (memory)                                                    
          0  sorts (disk)                                                      
       7604  rows processed

Notice in the above that the execution plan is the same for both the SELECT and INSERT INTO SQL statements, unlike what happened in Oracle Database 11.2.0.1 with the same OPTIMIZER_FEATURES_ENABLE setting.

————

SELECT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=100, OPTIMIZER_INDEX_COST_ADJ=80), completed in 0.34 seconds when selecting 10,478 rows (same execution plan for OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′):

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |   442 |           |
| 1   |  SORT GROUP BY               |            |   489 |   46K |   442 |  00:00:04 |
| 2   |   NESTED LOOPS               |            |  1006 |   95K |   441 |  00:00:04 |
| 3   |    FILTER                    |            |       |       |       |           |
| 4   |     HASH JOIN OUTER          |            |   671 |   39K |   440 |  00:00:04 |
| 5   |      VIEW                    |            |   671 |   14K |    65 |  00:00:01 |
| 6   |       SORT GROUP BY          |            |   671 |   17K |    65 |  00:00:01 |
| 7   |        FILTER                |            |       |       |       |           |
| 8   |         INDEX FAST FULL SCAN | T1_PK      |  107K | 2773K |    60 |  00:00:01 |
| 9   |      VIEW                    |            |   700 |   27K |   375 |  00:00:03 |
| 10  |       SORT GROUP BY          |            |   700 |   40K |   375 |  00:00:03 |
| 11  |        HASH JOIN             |            |  146K | 8454K |   368 |  00:00:03 |
| 12  |         TABLE ACCESS FULL    | T2         |   700 |   18K |     3 |  00:00:01 |
| 13  |         TABLE ACCESS FULL    | T2_LINES   |  146K | 4664K |   364 |  00:00:03 |
| 14  |    INDEX RANGE SCAN          | T1_LINES_PK|     1 |    37 |     1 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
11 - access("CO"."ID"="COL"."CUST_ORDER_ID")
12 - filter("CUSTOMER_PO_REF" IS NOT NULL)
13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0))

Statistics
----------------------------------------------------------                     
          1  recursive calls                                                   
          0  db block gets                                                     
       7508  consistent gets                                                   
          0  physical reads                                                    
          0  redo size                                                         
     104015  bytes sent via SQL*Net to client                                  
        549  bytes received via SQL*Net from client                            
          9  SQL*Net roundtrips to/from client                                 
          3  sorts (memory)                                                    
          0  sorts (disk)                                                      
       7604  rows processed

INSERT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in… 0.35 seconds when inserting 10,478 rows (same execution plan for OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′):

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT             |            |       |       |   442 |           |
| 1   |  SORT GROUP BY               |            |   489 |   46K |   442 |  00:00:04 |
| 2   |   NESTED LOOPS               |            |  1006 |   95K |   441 |  00:00:04 |
| 3   |    FILTER                    |            |       |       |       |           |
| 4   |     HASH JOIN OUTER          |            |   671 |   39K |   440 |  00:00:04 |
| 5   |      VIEW                    |            |   671 |   14K |    65 |  00:00:01 |
| 6   |       SORT GROUP BY          |            |   671 |   17K |    65 |  00:00:01 |
| 7   |        FILTER                |            |       |       |       |           |
| 8   |         INDEX FAST FULL SCAN | T1_PK      |  107K | 2773K |    60 |  00:00:01 |
| 9   |      VIEW                    |            |   700 |   27K |   375 |  00:00:03 |
| 10  |       SORT GROUP BY          |            |   700 |   40K |   375 |  00:00:03 |
| 11  |        HASH JOIN             |            |  146K | 8454K |   368 |  00:00:03 |
| 12  |         TABLE ACCESS FULL    | T2         |   700 |   18K |     3 |  00:00:01 |
| 13  |         TABLE ACCESS FULL    | T2_LINES   |  146K | 4664K |   364 |  00:00:03 |
| 14  |    INDEX RANGE SCAN          | T1_LINES_PK|     1 |    37 |     1 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter(COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
11 - access("CO"."ID"="COL"."CUST_ORDER_ID")
12 - filter("CUSTOMER_PO_REF" IS NOT NULL)
13 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0))

Statistics
----------------------------------------------------------                     
        183  recursive calls                                                   
        495  db block gets                                                     
       7702  consistent gets                                                   
          2  physical reads                                                    
     294848  redo size                                                         
        830  bytes sent via SQL*Net to client                                  
       1712  bytes received via SQL*Net from client                            
          3  SQL*Net roundtrips to/from client                                 
          4  sorts (memory)                                                    
          0  sorts (disk)                                                      
       7604  rows processed

Again, notice that the execution plan remained the same for the SELECT and INSERT INTO SQL statements.  Is this a bug in 11.2.0.1 that does not exist in 10.2.0.5, or was a bug introduced in 10.2.0.5?  Let’s take a look at a portion of the 10053 trace file from Oracle Database 11.2.0.1, comparing the output for the two settings of OPTIMIZER_FEATURES_ENABLE where a change in the execution plan was identified in 11.2.0.1.  With the setting at 10.2.0.2 we see that the complex view merge was prevented due to a CBQT (cost-based query transformation) directive, while that did not happen with the setting at 10.1.0.4:


11.2.0.1 

OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′

OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′

 

JE:   Considering Join Elimination on query block SEL$4 (#0)

JE:   Considering Join Elimination on query block SEL$4 (#0)

 

*************************

*************************

 

Join Elimination (JE)   

Join Elimination (JE)   

 

*************************

*************************

 

SQL:******* UNPARSED QUERY IS *******

SQL:******* UNPARSED QUERY IS *******

 

SELECT “CO”.”CUSTOMER_PO_REF” “CUSTOMER_PO_REF”,MAX(“COL”.”DESIRED_SHIP_DATE”) “DESIRED_SHIP_DATE”,MAX(“COL”.”PART_ID”) “PART_ID” FROM “TESTUSER”.”T2″ “CO”,”TESTUSER”.”T2_LINES” “COL” WHERE “CO”.”ID”=”COL”.”CUST_ORDER_ID” AND “CO”.”CUSTOMER_PO_REF” IS NOT NULL AND “COL”.”DESIRED_SHIP_DATE”>=SYSDATE@!-365 GROUP BY “CO”.”CUSTOMER_PO_REF”

SELECT “CO”.”CUSTOMER_PO_REF” “CUSTOMER_PO_REF”,MAX(“COL”.”DESIRED_SHIP_DATE”) “DESIRED_SHIP_DATE”,MAX(“COL”.”PART_ID”) “PART_ID” FROM “TESTUSER”.”T2″ “CO”,”TESTUSER”.”T2_LINES” “COL” WHERE “CO”.”ID”=”COL”.”CUST_ORDER_ID” AND “CO”.”CUSTOMER_PO_REF” IS NOT NULL AND “COL”.”DESIRED_SHIP_DATE”>=SYSDATE@!-365 GROUP BY “CO”.”CUSTOMER_PO_REF”

 

SQL:******* UNPARSED QUERY IS *******

SQL:******* UNPARSED QUERY IS *******

 

SELECT “CO”.”CUSTOMER_PO_REF” “CUSTOMER_PO_REF”,MAX(“COL”.”DESIRED_SHIP_DATE”) “DESIRED_SHIP_DATE”,MAX(“COL”.”PART_ID”) “PART_ID” FROM “TESTUSER”.”T2″ “CO”,”TESTUSER”.”T2_LINES” “COL” WHERE “CO”.”ID”=”COL”.”CUST_ORDER_ID” AND “CO”.”CUSTOMER_PO_REF” IS NOT NULL AND “COL”.”DESIRED_SHIP_DATE”>=SYSDATE@!-365 GROUP BY “CO”.”CUSTOMER_PO_REF”

SELECT “CO”.”CUSTOMER_PO_REF” “CUSTOMER_PO_REF”,MAX(“COL”.”DESIRED_SHIP_DATE”) “DESIRED_SHIP_DATE”,MAX(“COL”.”PART_ID”) “PART_ID” FROM “TESTUSER”.”T2″ “CO”,”TESTUSER”.”T2_LINES” “COL” WHERE “CO”.”ID”=”COL”.”CUST_ORDER_ID” AND “CO”.”CUSTOMER_PO_REF” IS NOT NULL AND “COL”.”DESIRED_SHIP_DATE”>=SYSDATE@!-365 GROUP BY “CO”.”CUSTOMER_PO_REF”

 

Query block SEL$4 (#0) unchanged

Query block SEL$4 (#0) unchanged

Different

CVM:   Checking validity of merging in query block SEL$2 (#0)

CVM:     CVM bypassed: view on right side of Outer Join + MuLTiple TABle.

Different

CVM: Considering view merge in query block SEL$2 (#0)

 

Different

CVM:   Checking validity of merging in query block SEL$3 (#0)

 

Different

CVM: Considering view merge in query block SEL$3 (#0)

 

 

CNT:   Considering count(col) to count(*) on query block SEL$3 (#0)

CNT:   Considering count(col) to count(*) on query block SEL$3 (#0)

 

*************************

*************************

 

Count(col) to Count(*) (CNT)

Count(col) to Count(*) (CNT)

 

*************************

*************************

 

CNT:     COUNT() to COUNT(*) not done.

CNT:     COUNT() to COUNT(*) not done.

Different

 

CVM: CBQT Marking query block SEL$3 (#0) as valid for CVM.

Different

CVM:   Merging complex view SEL$3 (#0) into SEL$2 (#0).

CVM:   Not Merging SEL$3 (#0) into SEL$2 (#0) due to CBQT directive.

Different

qbcp:******* UNPARSED QUERY IS *******

 

Different

SELECT /*+ LEADING (“E”) */ “E”.”CUSTPO” “CUSTPO”,”EL”.”FCSTQTY” “FCSTQTY”,”EL”.”FCDUEDATE” “FCDUEDATE” FROM  (SELECT “E”.”CUSTPO” “CUSTPO”,MAX(“E”.”RELID”) “RELID” FROM “TESTUSER”.”T1″ “E” GROUP BY “E”.”CUSTPO”) “E”,”TESTUSER”.”T1_LINES” “EL” WHERE “E”.”CUSTPO”=”EL”.”CUSTPO” AND “E”.”RELID”=”EL”.”RELID” AND “EL”.”FCDUEDATE”>=SYSDATE@!-365 AND “EL”.”FCDUEDATE”<=SYSDATE@!+1200 AND “EL”.”FCSTQTY”>0

 

Different

vqbcp:******* UNPARSED QUERY IS *******

 

Different

SELECT “E”.”CUSTPO” “CUSTPO”,MAX(“E”.”RELID”) “RELID” FROM “TESTUSER”.”T1″ “E” GROUP BY “E”.”CUSTPO”

 

Different

CVM: result SEL$2 (#0)

 

Different

******* UNPARSED QUERY IS *******

 

Different

SELECT /*+ LEADING (“E”) */ “E”.”CUSTPO” “CUSTPO”,”EL”.”FCSTQTY” “FCSTQTY”,”EL”.”FCDUEDATE” “FCDUEDATE” FROM “TESTUSER”.”T1″ “E”,”TESTUSER”.”T1_LINES” “EL” WHERE “E”.”CUSTPO”=”EL”.”CUSTPO” AND “EL”.”FCDUEDATE”>=SYSDATE@!-365 AND “EL”.”FCDUEDATE”<=SYSDATE@!+1200 AND “EL”.”FCSTQTY”>0 GROUP BY “E”.”CUSTPO”,”EL”.ROWID,”EL”.”RELID”,”EL”.”FCDUEDATE”,”EL”.”FCSTQTY” HAVING MAX(“E”.”RELID”)=”EL”.”RELID”

 

 

JE:   Considering Join Elimination on query block SEL$2 (#0)

JE:   Considering Join Elimination on query block SEL$2 (#0)

 

*************************

*************************

 

Join Elimination (JE)   

Join Elimination (JE)   

 

*************************

*************************

 

SQL:******* UNPARSED QUERY IS *******

SQL:******* UNPARSED QUERY IS *******

Different

SELECT /*+ LEADING (“E”) */ “E”.”CUSTPO” “CUSTPO”,”EL”.”FCSTQTY” “FCSTQTY”,”EL”.”FCDUEDATE” “FCDUEDATE” FROM “TESTUSER”.”T1″ “E”,”TESTUSER”.”T1_LINES” “EL” WHERE “E”.”CUSTPO”=”EL”.”CUSTPO” AND “EL”.”FCDUEDATE”>=SYSDATE@!-365 AND “EL”.”FCDUEDATE”<=SYSDATE@!+1200 AND “EL”.”FCSTQTY”>0 GROUP BY “E”.”CUSTPO”,”EL”.ROWID,”EL”.”RELID”,”EL”.”FCDUEDATE”,”EL”.”FCSTQTY” HAVING MAX(“E”.”RELID”)=”EL”.”RELID”

SELECT /*+ LEADING (“E”) */ “E”.”CUSTPO” “CUSTPO”,”EL”.”FCSTQTY” “FCSTQTY”,”EL”.”FCDUEDATE” “FCDUEDATE” FROM  (SELECT “E”.”CUSTPO” “CUSTPO”,MAX(“E”.”RELID”) “RELID” FROM “TESTUSER”.”T1″ “E” GROUP BY “E”.”CUSTPO”) “E”,”TESTUSER”.”T1_LINES” “EL” WHERE “E”.”CUSTPO”=”EL”.”CUSTPO” AND “E”.”RELID”=”EL”.”RELID” AND “EL”.”FCDUEDATE”>=SYSDATE@!-365 AND “EL”.”FCDUEDATE”<=SYSDATE@!+1200 AND “EL”.”FCSTQTY”>0

 ——————-

Let’s take a look at a portion of the 10053 trace file on Oracle Database 10.2.0.5, comparing the output for the two settings of OPTIMIZER_FEATURES_ENABLE where a change in the execution plan was identified.  With the setting at 10.2.0.2 we see that the complex view merge was prevented due to a CBQT (cost-based query transformation) directive, and that also happened with the setting at 10.1.0.4:

10.2.0.5

OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′

OPTIMIZER_FEATURES_ENABLE=’10.2.0.2′

 

**************************

**************************

 

Predicate Move-Around (PM)

Predicate Move-Around (PM)

 

**************************

**************************

 

PM: Considering predicate move-around in INS$1 (#0).

PM: Considering predicate move-around in INS$1 (#0).

 

PM:   Checking validity of predicate move-around in INS$1 (#0).

PM:   Checking validity of predicate move-around in INS$1 (#0).

 

CBQT: Validity checks passed for 2bxr3x54dk7nq.

CBQT: Validity checks passed for 2bxr3x54dk7nq.

 

voptcojrj: logp:0000000012312FF8

voptcojrj: logp:0000000012312FF8

 

voptcojrj:”E”.”CUSTPO”=”CO”.”CUSTOMER_PO_REF”(+)

voptcojrj:”E”.”CUSTPO”=”CO”.”CUSTOMER_PO_REF”(+)

 

rejected

rejected

 

voptcojrj:”E”.”FCDUEDATE”>COALESCE(“CO”.”DESIRED_SHIP_DATE”,SYSDATE@!-365)

voptcojrj:”E”.”FCDUEDATE”>COALESCE(“CO”.”DESIRED_SHIP_DATE”,SYSDATE@!-365)

 

rejected

rejected

Different

 

Query block (0000000012314D80) before join elimination:

Different

 

SQL:******* UNPARSED QUERY IS *******

Different

 

SELECT “CO”.”CUSTOMER_PO_REF” “CUSTOMER_PO_REF”,MAX(“COL”.”DESIRED_SHIP_DATE”) “DESIRED_SHIP_DATE”,MAX(“COL”.”PART_ID”) “PART_ID” FROM “TESTUSER”.”T2″ “CO”,”TESTUSER”.”T2_LINES” “COL” WHERE “CO”.”ID”=”COL”.”CUST_ORDER_ID” AND “CO”.”CUSTOMER_PO_REF” IS NOT NULL AND “COL”.”DESIRED_SHIP_DATE”>=SYSDATE@!-365 GROUP BY “CO”.”CUSTOMER_PO_REF”

Different

 

Query block (0000000012314D80) unchanged

 

CVM: CBQT Marking query block SEL$3 (#0)as valid for CVM.

CVM: CBQT Marking query block SEL$3 (#0)as valid for CVM.

 

CVM:  Not merging SEL$3 (#0) into SEL$2 (#0) due to CBQT directive.

CVM:  Not merging SEL$3 (#0) into SEL$2 (#0) due to CBQT directive.

Different

CVM:   Merging SPJ view SEL$2 (#0) into SEL$1 (#0)

Query block (000000001231DE28) before join elimination:

Different

 

SQL:******* UNPARSED QUERY IS *******

Different

 

SELECT /*+ LEADING (“E”) */ “E”.”CUSTPO” “CUSTPO”,”EL”.”FCSTQTY” “FCSTQTY”,”EL”.”FCDUEDATE” “FCDUEDATE” FROM  (SELECT “E”.”CUSTPO” “CUSTPO”,MAX(“E”.”RELID”) “RELID” FROM “TESTUSER”.”T1″ “E” GROUP BY “E”.”CUSTPO”) “E”,”TESTUSER”.”T1_LINES” “EL” WHERE “E”.”CUSTPO”=”EL”.”CUSTPO” AND “E”.”RELID”=”EL”.”RELID” AND “EL”.”FCDUEDATE”>=SYSDATE@!-365 AND “EL”.”FCDUEDATE”<=SYSDATE@!+1200 AND “EL”.”FCSTQTY”>0

Different

 

Query block (000000001231DE28) unchanged

Different

 

CVM:   Merging SPJ view SEL$2 (#0) into SEL$1 (#0)

 

voptcojrj: logp:0000000012312FF8

voptcojrj: logp:0000000012312FF8

 

voptcojrj:”E”.”CUSTPO”=”CO”.”CUSTOMER_PO_REF”(+)

voptcojrj:”E”.”CUSTPO”=”CO”.”CUSTOMER_PO_REF”(+)

 

rejected

rejected

 

voptcojrj:”EL”.”FCDUEDATE”>COALESCE(“CO”.”DESIRED_SHIP_DATE”,SYSDATE@!-365)

voptcojrj:”EL”.”FCDUEDATE”>COALESCE(“CO”.”DESIRED_SHIP_DATE”,SYSDATE@!-365)

 

rejected

rejected

 

voptcojrj:”E”.”CUSTPO”=”EL”.”CUSTPO”

voptcojrj:”E”.”CUSTPO”=”EL”.”CUSTPO”

 

rejected

rejected

 

voptcojrj:”E”.”RELID”=”EL”.”RELID”

voptcojrj:”E”.”RELID”=”EL”.”RELID”

 

rejected

rejected

 

voptcojrj:”EL”.”FCDUEDATE”>=SYSDATE@!-365

voptcojrj:”EL”.”FCDUEDATE”>=SYSDATE@!-365

 

rejected

rejected

 

voptcojrj:”EL”.”FCDUEDATE”<=SYSDATE@!+1200

voptcojrj:”EL”.”FCDUEDATE”<=SYSDATE@!+1200

 

rejected

rejected

 

voptcojrj:”EL”.”FCSTQTY”>0

voptcojrj:”EL”.”FCSTQTY”>0

 

rejected

rejected

Different

 

Query block (000000001231ED68) before join elimination:

Different

 

SQL:******* UNPARSED QUERY IS *******

Different

 

SELECT /*+ LEADING (“E”) LEADING (“E”) */ COALESCE(“CO”.”PART_ID”,’NOT-IN-SYSTEM’) “PART_ID”,”EL”.”FCDUEDATE” “REQUIRED_DATE”,SUM(“EL”.”FCSTQTY”) “QTY”,1 “PLAN_LEVEL” FROM  (SELECT “E”.”CUSTPO” “CUSTPO”,MAX(“E”.”RELID”) “RELID” FROM “TESTUSER”.”T1″ “E” GROUP BY “E”.”CUSTPO”) “E”,”TESTUSER”.”T1_LINES” “EL”, (SELECT “CO”.”CUSTOMER_PO_REF” “CUSTOMER_PO_REF”,MAX(“COL”.”DESIRED_SHIP_DATE”) “DESIRED_SHIP_DATE”,MAX(“COL”.”PART_ID”) “PART_ID” FROM “TESTUSER”.”T2″ “CO”,”TESTUSER”.”T2_LINES” “COL” WHERE “CO”.”ID”=”COL”.”CUST_ORDER_ID” AND “CO”.”CUSTOMER_PO_REF” IS NOT NULL AND “COL”.”DESIRED_SHIP_DATE”>=SYSDATE@!-365 GROUP BY “CO”.”CUSTOMER_PO_REF”) “CO” WHERE “E”.”CUSTPO”=”CO”.”CUSTOMER_PO_REF”(+) AND “EL”.”FCDUEDATE”>COALESCE(“CO”.”DESIRED_SHIP_DATE”,SYSDATE@!-365) AND “E”.”CUSTPO”=”EL”.”CUSTPO” AND “E”.”RELID”=”EL”.”RELID” AND “EL”.”FCDUEDATE”>=SYSDATE@!-365 AND “EL”.”FCDUEDATE”<=SYSDATE@!+1200 AND “EL”.”FCSTQTY”>0 GROUP BY COALESCE(“CO”.”PART_ID”,’NOT-IN-SYSTEM’),”EL”.”FCDUEDATE” ORDER BY COALESCE(“CO”.”PART_ID”,’NOT-IN-SYSTEM’),”EL”.”FCDUEDATE”

Different

 

Query block (000000001231ED68) unchanged

 

Registered qb: SEL$F5BB74E1 0x1231ed68 (VIEW MERGE SEL$1; SEL$2)

Registered qb: SEL$F5BB74E1 0x1231ed68 (VIEW MERGE SEL$1; SEL$2)

 

  signature (): qb_name=SEL$F5BB74E1 nbfros=3 flg=0

  signature (): qb_name=SEL$F5BB74E1 nbfros=3 flg=0

 

    fro(0): flg=1 objn=0 hint_alias=”CO”@”SEL$1″

    fro(0): flg=1 objn=0 hint_alias=”CO”@”SEL$1″

 

    fro(1): flg=1 objn=0 hint_alias=”E”@”SEL$2″

    fro(1): flg=1 objn=0 hint_alias=”E”@”SEL$2″

 

    fro(2): flg=0 objn=47930 hint_alias=”EL”@”SEL$2″

    fro(2): flg=0 objn=47930 hint_alias=”EL”@”SEL$2″

 

Now what?  Is it considered a bug if Oracle Database 11.2.0.1 behaves similar to 10.2.0.2, but not similar to 10.2.0.5, when the OPTIMIZER_FEATURES_ENABLE parameter is set to 10.1.0.4?





SELECT Statement is Fast, INSERT INTO Using the SELECT Statement is Brutally Slow 2

18 12 2010

December 18, 2010 (Modified December 19, 2010)

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

The previous blog article in this series resulted in several interesting comments with very useful advice.  But was the performance issue just an isolated case, one that only happens in one database, with one Oracle Database release version?  We need a test case to determine how frequently this problem may occur.  First, we will create two tables, table T1 will emulate table EDI830 from the previous blog article, and table T1_LINES will emulate the EDI830_LINES table.  A PADDING column will be used to make the average row length roughly equivalent to that of the original tables:

CREATE TABLE T1(
  CUSTPO VARCHAR2(12) NOT NULL,
  RELID VARCHAR2(12) NOT NULL,
  PADDING VARCHAR2(40),
  CONSTRAINT T1_PK PRIMARY KEY (CUSTPO,RELID));

CREATE TABLE T1_LINES(
  CUSTPO VARCHAR2(12) NOT NULL,
  RELID VARCHAR2(12) NOT NULL,
  FCSTQTY NUMBER NOT NULL,
  FC VARCHAR2(1),
  FCDUEDATE DATE NOT NULL,
  CONSTRAINT T1_LINES_PK PRIMARY KEY (CUSTPO,RELID,FCDUEDATE,FCSTQTY)); 

Next, the table T1 is populated in a repeatable way that as best as possible simulates how the original table was actually populated in production:

INSERT INTO T1
SELECT
  RPAD(CHR(MOD(ROWNUM-1,26)+65)||TO_CHAR(ROWNUM),12,'A') CUSTPO,
  LPAD('1',12,'0') RELID,
  LPAD('A',40,'A') PADDING
FROM
  DUAL
CONNECT BY
  LEVEL<=700;

INSERT INTO
  T1
SELECT
  CUSTPO,
  LPAD(TO_CHAR(V2.RN+1),12,'0') RELID,
  LPAD('A',40,'A') PADDING
FROM
  (SELECT /*+ NO_MERGE */
    CUSTPO,
    PADDING,
    MOD(ROWNUM,10)*30+19 RN
  FROM
    (SELECT /*+ NO_MERGE */
      CUSTPO,
      PADDING
    FROM
      T1
    ORDER BY
      CUSTPO)) V1,
  (SELECT /*+ NO_MERGE */
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=319) V2
WHERE
  V2.RN<=V1.RN; 

If we select from table T1, we are able to see how the row counts are distributed in an unequal, yet repeatable way, with 700 distinct customer purchase order numbers: 

SELECT
  CUSTPO,
  MIN(RELID),
  MAX(RELID)
FROM
  T1
GROUP BY
  CUSTPO
ORDER BY
  CUSTPO;

CUSTPO       MIN(RELID)   MAX(RELID)
------------ ------------ ------------
A105AAAAAAAA 000000000001 000000000050
A131AAAAAAAA 000000000001 000000000080
A157AAAAAAAA 000000000001 000000000110
A183AAAAAAAA 000000000001 000000000140
A1AAAAAAAAAA 000000000001 000000000170
A209AAAAAAAA 000000000001 000000000200
A235AAAAAAAA 000000000001 000000000230
A261AAAAAAAA 000000000001 000000000260
...

Z624AAAAAAAA 000000000001 000000000230
Z650AAAAAAAA 000000000001 000000000260
Z676AAAAAAAA 000000000001 000000000290
Z78AAAAAAAAA 000000000001 000000000020

700 rows selected. 

Just as a quick experiment, let’s take a look at the output of the SQL statement that will be used to populate the line detail table (T1_LINES) for the customer POs:

SELECT
  CUSTPO,
  RELID,
  10 FCSTQTY,
  'A' FC,
  TO_DATE('01-JAN-2011','DD-MON-YYYY') + (V2.RN*3 - V1.REL*2) FCDUEDATE
FROM
  (SELECT /*+ NO_MERGE */
    CUSTPO,
    RELID,
    ROW_NUMBER() OVER (PARTITION BY RELID ORDER BY CUSTPO) RN,
    ROW_NUMBER() OVER (PARTITION BY CUSTPO ORDER BY RELID DESC) REL
  FROM
    T1
  WHERE
    CUSTPO IN ('Z78AAAAAAAAA','Y155AAAAAAAA')) V1,
  (SELECT /*+ NO_MERGE */
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=100) V2
WHERE
  V2.RN < (MOD(V1.RN,100)+10)
ORDER BY
  CUSTPO,
  RELID,
  5;

CUSTPO       RELID           FCSTQTY F FCDUEDATE
------------ ------------ ---------- - ---------
Y155AAAAAAAA 000000000001         10 A 26-SEP-10
Y155AAAAAAAA 000000000001         10 A 29-SEP-10
Y155AAAAAAAA 000000000001         10 A 02-OCT-10
Y155AAAAAAAA 000000000001         10 A 05-OCT-10
Y155AAAAAAAA 000000000001         10 A 08-OCT-10
Y155AAAAAAAA 000000000001         10 A 11-OCT-10
Y155AAAAAAAA 000000000001         10 A 14-OCT-10
Y155AAAAAAAA 000000000001         10 A 17-OCT-10
Y155AAAAAAAA 000000000001         10 A 20-OCT-10
Y155AAAAAAAA 000000000001         10 A 23-OCT-10
Y155AAAAAAAA 000000000002         10 A 28-SEP-10
Y155AAAAAAAA 000000000002         10 A 01-OCT-10
...

Z78AAAAAAAAA 000000000020         10 A 17-JAN-11
Z78AAAAAAAAA 000000000020         10 A 20-JAN-11
Z78AAAAAAAAA 000000000020         10 A 23-JAN-11
Z78AAAAAAAAA 000000000020         10 A 26-JAN-11
Z78AAAAAAAAA 000000000020         10 A 29-JAN-11
Z78AAAAAAAAA 000000000020         10 A 01-FEB-11

720 rows selected.

In the above, you can see how the dates will automatically shift from one release of a customer PO to the next, as well as the order in which the rows will be inserted.  The actual dates and number of rows for these two customer POs will actually be a bit different when the rows are inserted into the table, so use the above as just an illustration.

Next, let’s insert 6,079,050 rows into the line detail table in a repeatable way:

INSERT INTO
  T1_LINES
SELECT
  CUSTPO,
  RELID,
  10 FCSTQTY,
  'A' FC,
  TO_DATE('01-JAN-2011','DD-MON-YYYY') + (V2.RN*3 - V1.REL*2) FCDUEDATE
FROM
  (SELECT /*+ NO_MERGE */
    CUSTPO,
    RELID,
    ROW_NUMBER() OVER (PARTITION BY RELID ORDER BY CUSTPO) RN,
    ROW_NUMBER() OVER (PARTITION BY CUSTPO ORDER BY RELID DESC) REL
  FROM
    T1) V1,
  (SELECT /*+ NO_MERGE */
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=100) V2
WHERE
  V2.RN < (MOD(V1.RN,100)+10)
ORDER BY
  RELID,
  CUSTPO,
  5; 

COMMIT;

Now let’s create table T2 (simulates table CUSTOMER_ORDER) and table T2_LINES (simulates table CUST_ORDER_LINE).  Table T2_LINES will be populated with 224,700 rows:

CREATE TABLE T2(
  ID VARCHAR2(15),
  CUSTOMER_ID VARCHAR2(15),
  CUSTOMER_PO_REF VARCHAR2(40),
  PADDING VARCHAR2(150),
  PRIMARY KEY(ID));

CREATE TABLE T2_LINES(
  CUST_ORDER_ID VARCHAR2(15),
  LINE_NO NUMBER,
  PART_ID VARCHAR2(30),
  DESIRED_SHIP_DATE DATE,
  PADDING VARCHAR2(100),
  PRIMARY KEY(CUST_ORDER_ID,LINE_NO)); 

INSERT INTO
  T2
SELECT DISTINCT
  CUSTPO ID,
  'AAAAAAAAAA' CUSTOMER_ID,
  CUSTPO CUSTOMER_PO_REF,
  RPAD('A',150,'A') PADDING
FROM
  T1
ORDER BY
  DBMS_RANDOM.VALUE;

INSERT INTO
  T2_LINES
SELECT
  CUST_ORDER_ID,
  ROW_NUMBER() OVER (PARTITION BY CUST_ORDER_ID ORDER BY DESIRED_SHIP_DATE) LINE_NO,
  RPAD(TO_CHAR((MOD(ROWNUM,3000)+1) * 33)||'PART',10,'A') PART_ID,
  DESIRED_SHIP_DATE,
  RPAD('A',100,'A') PADDING
FROM 
  (SELECT DISTINCT
    CUSTPO CUST_ORDER_ID,
    FCDUEDATE DESIRED_SHIP_DATE   
  FROM
    T1_LINES
  WHERE
    FCDUEDATE<= TO_DATE('15-JAN-2011','DD-MON-YYYY')) V1;

COMMIT;

Finally, we will gather statistics for the tables and the primary key indexes:

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',CASCADE=>TRUE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1_LINES',CASCADE=>TRUE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',CASCADE=>TRUE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2_LINES',CASCADE=>TRUE) 

We are now able to start transforming the original query sections, these sections will be listed one at a time, as they were in the earlier article:

    (SELECT
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E 

 The inline view that uses the above inline view: 

  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN TO_DATE('01-JAN-2011','DD-MON-YYYY')-365 AND TO_DATE('01-JAN-2011','DD-MON-YYYY')+1200
    AND EL.FCSTQTY>0) E 

The inline view for the customer orders:

  (SELECT
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO 

Finally, the full SQL statement with all of the inline views joined:

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE; 

Next, we need a simple table to hold the contents of the INSERT INTO… SELECT statement:

CREATE TABLE T1_DEST (
  PART_ID VARCHAR2(30),
  REQUIRED_DATE DATE,
  QTY NUMBER,
  PLAN_LEVEL NUMBER); 

Now the script that will actually perform the test with different values for OPTIMIZER_FEATURES_ENABLE, OPTIMIZER_INDEX_COST_ADJ, and OPTIMIZER_INDEX_CACHING (Edit Dec 19, 2010: the original version of the script set the TRACEFILE_IDENTIFIER value identically for the SELECT and the INSERT INTO versions of the SQL statement when the OPTIMIZER_FEATURES_ENABLED parameter was greater than 10.1.0.4, and that error resulted in the SELECT and the INSERT INTO execution plans appearing in the same trace file, rather than in separate trace files – the script below has been corrected):


SET TIMING ON
SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS

SPOOL Capture_Results.txt

ALTER SESSION SET OPTIMIZER_INDEX_CACHING=0;
ALTER SESSION SET OPTIMIZER_INDEX_COST_ADJ=100;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='10.1.0.4';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_10.1.0.4';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_10.1.0.4';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='10.2.0.2';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_10.2.0.2';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_10.2.0.2';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='11.1.0.7';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_11.1.0.7';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_11.1.0.7';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';
INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='11.2.0.1';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_11.2.0.1';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_11.2.0.1';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+  */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

SPOOL Capture_Results80.txt

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_INDEX_CACHING=100;
ALTER SESSION SET OPTIMIZER_INDEX_COST_ADJ=80;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='10.1.0.4';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_10.1.0.4_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_10.1.0.4_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='10.2.0.2';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_10.2.0.2_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_10.2.0.2_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='11.1.0.7';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_11.1.0.7_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_11.1.0.7_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

TRUNCATE TABLE T1_DEST;

ALTER SESSION SET OPTIMIZER_FEATURES_ENABLE='11.2.0.1';
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_11.2.0.1_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'INSERT_11.2.0.1_80';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';

INSERT INTO T1_DEST
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT /*+ _80 */
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      T1 E
    GROUP BY
      E.CUSTPO) E,
    T1_LINES EL
  WHERE
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT /*+  */
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    T2 CO,
    T2_LINES COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;

ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

SPOOL OFF

For this blog article, I decided to use the Enterprise Edition of Oracle Database 11.2.0.1, with the following manually set system (CPU) statistics (as printed in the 10053 trace files):

SYSTEM STATISTICS INFORMATION
-----------------------------
  Using WORKLOAD Stats
  CPUSPEED: 2664 millions instructions/sec
  SREADTIM: 8.000000 milliseconds
  MREADTIM: 10.000000 millisecons
  MBRC: 16 blocks
  MAXTHR: 19181568 bytes/sec
  SLAVETHR: -1 bytes/sec 

The tablespace used for the test case uses ASSM with auto-allocated extent sizes, and the following instance-wide parameters specified: 

SGA_TARGET =          12000M
PGA_AGGREGATE_TARGET = 2000M
OPTIMIZER_MODE =    ALL_ROWS

Just for fun, for now I will show you only the first two execution plans from the 10053 trace files:

SELECT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in 0.23 seconds when selecting 10,478 rows:

--------------------------------------------------+-----------------------------------+
| Id  | Operation                    | Name       | Rows  | Bytes | Cost  | Time      |
--------------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT             |            |       |       |  1425 |           |
| 1   |  SORT GROUP BY               |            |   487 |   46K |  1425 |  00:00:12 |
| 2   |   FILTER                     |            |       |       |       |           |
| 3   |    HASH JOIN RIGHT OUTER     |            |   19K | 1884K |  1423 |  00:00:12 |
| 4   |     VIEW                     |            |   700 |   27K |   368 |  00:00:03 |
| 5   |      SORT GROUP BY           |            |   700 |   40K |   368 |  00:00:03 |
| 6   |       HASH JOIN              |            |  146K | 8475K |   362 |  00:00:03 |
| 7   |        TABLE ACCESS FULL     | T2         |   700 |   18K |     3 |  00:00:01 |
| 8   |        TABLE ACCESS FULL     | T2_LINES   |  146K | 4676K |   358 |  00:00:03 |
| 9   |     NESTED LOOPS             |            |   19K | 1126K |  1055 |  00:00:09 |
| 10  |      VIEW                    |            |   700 |   14K |    65 |  00:00:01 |
| 11  |       SORT GROUP BY          |            |   700 |   18K |    65 |  00:00:01 |
| 12  |        FILTER                |            |       |       |       |           |
| 13  |         INDEX FAST FULL SCAN | T1_PK      |  106K | 2755K |    60 |  00:00:01 |
| 14  |      INDEX RANGE SCAN        | T1_LINES_PK|    28 |  1036 |     3 |  00:00:01 |
--------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter(("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - access("CO"."ID"="COL"."CUST_ORDER_ID")
7 - filter("CUSTOMER_PO_REF" IS NOT NULL)
8 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365)
12 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
14 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
14 - filter("EL"."FCSTQTY">0) 

INSERT_10.1.0.4 (OPTIMIZER_FEATURES_ENABLE=’10.1.0.4′, OPTIMIZER_INDEX_CACHING=0, OPTIMIZER_INDEX_COST_ADJ=100), completed in… 30 minutes, 18.01 seconds when inserting 10,478 rows:

-------------------------------------------------+-----------------------------------+
| Id  | Operation                      | Name    | Rows  | Bytes | Cost  | Time      |
-------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT               |         |       |       | 4967K |           |
| 1   |  LOAD TABLE CONVENTIONAL       |         |       |       |       |           |
| 2   |   SORT GROUP BY                |         |   842 |   60K | 4967K |  11:18:11 |
| 3   |    FILTER                      |         |       |       |       |           |
| 4   |     HASH JOIN OUTER            |         |   842 |   60K | 4967K |  11:18:11 |
| 5   |      VIEW                      |         |   842 |   28K | 4967K |  11:18:08 |
| 6   |       FILTER                   |         |       |       |       |           |
| 7   |        SORT GROUP BY           |         |   842 |   53K | 4967K |  11:18:08 |
| 8   |         FILTER                 |         |       |       |       |           |
| 9   |          HASH JOIN             |         |  852M |   54G |  7035 |  00:00:57 |
| 10  |           INDEX FAST FULL SCAN | T1_PK   |  106K | 2755K |    60 |  00:00:01 |
| 11  |           TABLE ACCESS FULL    | T1_LINES| 5631K |  214M |  3388 |  00:00:28 |
| 12  |      VIEW                      |         |   700 |   27K |   368 |  00:00:03 |
| 13  |       SORT GROUP BY            |         |   700 |   40K |   368 |  00:00:03 |
| 14  |        HASH JOIN               |         |  146K | 8475K |   362 |  00:00:03 |
| 15  |         TABLE ACCESS FULL      | T2      |   700 |   18K |     3 |  00:00:01 |
| 16  |         TABLE ACCESS FULL      | T2_LINES|  146K | 4676K |   358 |  00:00:03 |
-------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
3 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
4 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
6 - filter("EL"."RELID"=MAX("RELID"))
8 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
9 - access("E"."CUSTPO"="EL"."CUSTPO")
11 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200 AND "EL"."FCSTQTY">0))
14 - access("CO"."ID"="COL"."CUST_ORDER_ID")
15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
16 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

——————-

Just one more example of the value of test cases.  By the way, make certain that the air conditioning is working well in the room where your test server is located – your test server could be swamped for a couple of hours while the table creation scripts run and the actual test script is executed.  So, what is ahead in part three of this blog article series?

(P.S. Did anyone’s test result for the first INSERT INTO statement complete in less than 30 minutes?)





SELECT Statement is Fast, INSERT INTO Using the SELECT Statement is Brutally Slow 1

15 12 2010

December 15, 2010 

(Forward to the Next Post in the Series)

I am impressed with the responses that were received from the most recent set of blog articles.  I recently encountered an interesting problem with an Oracle database that had the OPTIMIZER_FEATURES_ENABLE parameter set to 10.1.0.4 and the OPTIMIZER_MODE set to ALL_ROWS.  A somewhat complex SQL statement was written like the following, using LEADING hints to help control the join order (to work around a potential problem related to join order when inline views are used):

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      EDI830 E
    GROUP BY
      E.CUSTPO) E,
    EDI830_LINES EL
  WHERE 
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E,
  (SELECT
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    CUSTOMER_ORDER CO,
    CUST_ORDER_LINE COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE; 

The above query executes very quickly (a second or less), and the execution plan for the above query looks like this:

Execution Plan
----------------------------------------------------------
Plan hash value: 3426513411

-----------------------------------------------------------------------------------------------
| Id  | Operation                   | Name            | Rows  | Bytes | Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                 |   205 | 17425 |   157  (21)| 00:00:01 |
|   1 |  SORT GROUP BY              |                 |   205 | 17425 |   157  (21)| 00:00:01 |
|*  2 |   FILTER                    |                 |       |       |            |          |
|*  3 |    HASH JOIN OUTER          |                 |   384 | 32640 |   156  (20)| 00:00:01 |
|   4 |     NESTED LOOPS            |                 |   194 |  9506 |    47  (35)| 00:00:01 |
|   5 |      VIEW                   |                 |  1993 | 35874 |    46  (35)| 00:00:01 |
|   6 |       SORT GROUP BY         |                 |  1993 | 39860 |    46  (35)| 00:00:01 |
|*  7 |        FILTER               |                 |       |       |            |          |
|   8 |         INDEX FAST FULL SCAN| EDI830_PK       |   107K|  2092K|    33  (10)| 00:00:01 |
|*  9 |      INDEX RANGE SCAN       | EDI830_LINES_PK |     1 |    31 |     1   (0)| 00:00:01 |
|  10 |     VIEW                    |                 |  6254 |   219K|   108  (13)| 00:00:01 |
|  11 |      SORT GROUP BY          |                 |  6254 |   250K|   108  (13)| 00:00:01 |
|* 12 |       HASH JOIN             |                 |  8213 |   328K|   106  (12)| 00:00:01 |
|* 13 |        TABLE ACCESS FULL    | CUSTOMER_ORDER  |  7554 |   125K|    14   (8)| 00:00:01 |
|* 14 |        TABLE ACCESS FULL    | CUST_ORDER_LINE |  8582 |   201K|    92  (12)| 00:00:01 |
-----------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - filter("EL"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365) AND
              COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365)<SYSDATE@!+1200)
   3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF"(+))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
   9 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND
              "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND
              "EL"."FCDUEDATE"<=SYSDATE@!+1200)
       filter("EL"."FCSTQTY">0)
  12 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  13 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  14 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

Now, assume that we have a very simple table that currently contains no rows (the table was TRUNCATEd) and no indexes, and we would like to insert the rows returned by the above SQL statement into the table:

INSERT INTO
  T1
SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
...
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE; 

The INSERT INTO SQL statement required 20 to 30 minutes to complete.  Using SELECT * FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(NULL,NULL,’TYPICAL’)); the following execution plan is displayed:

--------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name            | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------------------------
|   0 | INSERT STATEMENT             |                 |       |       |       |   279K(100)|          |
|   1 |  SORT GROUP BY               |                 |   205 | 13735 |       |   279K  (9)| 00:22:11 |
|*  2 |   FILTER                     |                 |       |       |       |            |          |
|   3 |    MERGE JOIN OUTER          |                 | 81363 |  5323K|       |   279K  (9)| 00:22:11 |
|   4 |     VIEW                     |                 | 70658 |  2139K|       |   279K  (9)| 00:22:10 |
|*  5 |      FILTER                  |                 |       |       |       |            |          |
|   6 |       SORT GROUP BY          |                 | 70658 |  3519K|  7169M|   279K  (9)| 00:22:10 |
|*  7 |        FILTER                |                 |       |       |       |            |          |
|*  8 |         HASH JOIN            |                 |   109M|  5343M|  3352K|   1154 (30)| 00:00:06 |
|   9 |          INDEX FAST FULL SCAN| EDI830_PK       |   107K|  2092K|       |     33 (10)| 00:00:01 |
|* 10 |          TABLE ACCESS FULL   | EDI830_LINES    |   242K|  7334K|       |    941 (35)| 00:00:05 |
|* 11 |     SORT JOIN                |                 |  6254 |   219K|       |    110 (15)| 00:00:01 |
|  12 |      VIEW                    |                 |  6254 |   219K|       |    108 (13)| 00:00:01 |
|  13 |       SORT GROUP BY          |                 |  6254 |   250K|       |    108 (13)| 00:00:01 |
|* 14 |        HASH JOIN             |                 |  8213 |   328K|       |    106 (12)| 00:00:01 |
|* 15 |         TABLE ACCESS FULL    | CUSTOMER_ORDER  |  7554 |   125K|       |     14  (8)| 00:00:01 |
|* 16 |         TABLE ACCESS FULL    | CUST_ORDER_LINE |  8582 |   201K|       |     92 (12)| 00:00:01 |
--------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
   2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
   5 - filter("EL"."RELID"=MAX("RELID"))
   7 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
   8 - access("E"."CUSTPO"="EL"."CUSTPO")
  10 - filter(("EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND
       "EL"."FCDUEDATE"<=SYSDATE@!+1200))
  11 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
       filter("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
  14 - access("CO"."ID"="COL"."CUST_ORDER_ID")
  15 - filter("CUSTOMER_PO_REF" IS NOT NULL)
  16 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

What happened, how would you investigate the problem, and how would you correct the problem?  Think about that for a couple of minutes before scrolling down.

Assume that I was able to obtain an execution plan for the INSERT INTO SQL statement that looked like this:

-------------------------------------------------------+-----------------------------------+
| Id  | Operation                     | Name           | Rows  | Bytes | Cost  | Time      |
-------------------------------------------------------+-----------------------------------+
| 0   | INSERT STATEMENT              |                |       |       |   157 |           |
| 1   |  SORT GROUP BY                |                |   194 |   13K |   157 |  00:00:01 |
| 2   |   FILTER                      |                |       |       |       |           |
| 3   |    HASH JOIN OUTER            |                |   223 |   15K |   156 |  00:00:01 |
| 4   |     VIEW                      |                |   194 |  6014 |    47 |  00:00:01 |
| 5   |      NESTED LOOPS             |                |   194 |  9118 |    47 |  00:00:01 |
| 6   |       VIEW                    |                |  1993 |   31K |    46 |  00:00:01 |
| 7   |        SORT GROUP BY          |                |  1993 |   39K |    46 |  00:00:01 |
| 8   |         FILTER                |                |       |       |       |           |
| 9   |          INDEX FAST FULL SCAN | EDI830_PK      |  105K | 2092K |    33 |  00:00:01 |
| 10  |       INDEX RANGE SCAN        | EDI830_LINES_PK|     1 |    31 |     1 |  00:00:01 |
| 11  |     VIEW                      |                |  6254 |  220K |   108 |  00:00:01 |
| 12  |      SORT GROUP BY            |                |  6254 |  250K |   108 |  00:00:01 |
| 13  |       HASH JOIN               |                |  8213 |  329K |   106 |  00:00:01 |
| 14  |        TABLE ACCESS FULL      | CUSTOMER_ORDER |  7554 |  125K |    14 |  00:00:01 |
| 15  |        TABLE ACCESS FULL      | CUST_ORDER_LINE|  8582 |  201K |    92 |  00:00:01 |
-------------------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
2 - filter("E"."FCDUEDATE">COALESCE("CO"."DESIRED_SHIP_DATE",SYSDATE@!-365))
3 - access("E"."CUSTPO"="CO"."CUSTOMER_PO_REF")
8 - filter(SYSDATE@!-365<=SYSDATE@!+1200)
10 - access("E"."CUSTPO"="EL"."CUSTPO" AND "E"."RELID"="EL"."RELID" AND "EL"."FCDUEDATE">=SYSDATE@!-365 AND "EL"."FCSTQTY">0 AND "EL"."FCDUEDATE"<=SYSDATE@!+1200)
10 - filter("EL"."FCSTQTY">0)
13 - access("CO"."ID"="COL"."CUST_ORDER_ID")
14 - filter("CUSTOMER_PO_REF" IS NOT NULL)
15 - filter("COL"."DESIRED_SHIP_DATE">=SYSDATE@!-365) 

Using the above execution plan, the INSERT INTO SQL statement completed in about a second (or less).  What did I do to fix the problem?

———

Here is what the sections of the query are intended to accomplish:

On a daily basis the header rows for custom order forecasts are inserted into the EDI830 table, and each order may be revised multiple times (possibly once a day or once a week), each time bumping the RELID value up by 1 or 2 (RELID is a zero padded number stored in a VARCHAR2 column).  This part of the query retrieves the most recent release number for each of the customer POs so that we are able to return the line item detail for the most recent customer order forecast release:

    (SELECT
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      EDI830 E
    GROUP BY
      E.CUSTPO) E 

Join the above inline view to the line item detail, with restrictions so that we do not look at releases from more than a year ago.  The LEADING hint is used to make certain that the optimizer first returns the rows from the EDI830 table before accessing the EDI830_LINES table (there is a chance that the optimizer will access the EDI830_LINES table first before returning the rows from the inline view):

  (SELECT /*+ LEADING(E) */
    E.CUSTPO,
    EL.FCSTQTY,
    EL.FCDUEDATE
  FROM
    (SELECT
      E.CUSTPO,
      MAX(RELID) RELID
    FROM
      EDI830 E
    GROUP BY
      E.CUSTPO) E,
    EDI830_LINES EL
  WHERE 
    E.CUSTPO=EL.CUSTPO
    AND E.RELID=EL.RELID
    AND EL.FCDUEDATE BETWEEN SYSDATE-365 AND SYSDATE+1200
    AND EL.FCSTQTY>0) E 

The goal of the following subquery is to return the ship date of the last order line that made it into the order entry system for each of the customer POs.  This subquery will allow us to determine which of the rows in the most recent EDI release are beyond the last firmed customer order line in the system (typically, only the firmed EDI release lines are brought into the CUST_ORDER_LINE table):

  (SELECT
    CO.CUSTOMER_PO_REF,
    MAX(COL.DESIRED_SHIP_DATE) DESIRED_SHIP_DATE,
    MAX(COL.PART_ID) PART_ID
  FROM
    CUSTOMER_ORDER CO,
    CUST_ORDER_LINE COL
  WHERE
    CO.ID=COL.CUST_ORDER_ID
    AND CUSTOMER_PO_REF IS NOT NULL
    AND COL.DESIRED_SHIP_DATE>=SYSDATE-365
  GROUP BY
    CO.CUSTOMER_PO_REF) CO

The outer-most portion of the SQL statement joins the two inline views together, using a LEADING hint to make certain that the EDI release rows are retrieved before accessing the CUSTOMER_ORDER and CUST_ORDER_LINE tables (even with the outer join, it is possible that those tables might be accessed first):

SELECT /*+ LEADING(E) */
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM') PART_ID,
  E.FCDUEDATE REQUIRED_DATE,
  SUM(E.FCSTQTY) QTY,
  1 PLAN_LEVEL
FROM
...
  GROUP BY
    CO.CUSTOMER_PO_REF) CO
WHERE
  E.CUSTPO=CO.CUSTOMER_PO_REF(+)
  AND E.FCDUEDATE>COALESCE(CO.DESIRED_SHIP_DATE,SYSDATE-365)
GROUP BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE
ORDER BY
  COALESCE(CO.PART_ID,'NOT-IN-SYSTEM'),
  E.FCDUEDATE;  

What happened?  What process would you use to investigate the performance problem?  How would you resolve this performance problem.

If you tell me to buy a bigger server, I will simply tell you to read a different book.  :-)





I Didn’t Know That 6 – What is Wrong with this Quote?

14 12 2010

December 14, 2010

(Back to the Previous Post in the Series)

In the interest of interesting quotes, a quote that I found in the “Oracle Tuning the Definitive Reference Second Edition” book on page 541:

“Oracle speeds are very high with SSD, and SSD is also cheap at only $1k/gig USD…  Companies are now offering solid-state disk replacement for the Oracle data buffer cache to speed up I/O at the physical level…”

“Physical disk I/O is measured in milliseconds, an eternity when compared to faster operations within other server components such as network RAM and CPU speeds.  For many years, Oracle shops have been embracing solid-state disks, RAM disks that operate hundreds of time faster than old-fashioned platter technology from the 1960s.  SSD also has no channel contention, and as prices fall, SSD will eventually displace the ancient magnetic spinning platters of the last century.”

What, if anything, is wrong with the above quote? 

—————–

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review. 

This blog article marks the last of the blog articles that were scheduled as a component part of the “Oracle Tuning the Definitive Reference Second Edition” book review.  Regular readers will probably recognize that I attempt to encourage people to learn from mistakes, whether your own, or those that you encounter in your day to day duties working with Oracle Database.  If the mistakes are yours, it is your choice whether you continue to make the same mistakes year after year, or if you will seek to learn from the assistance provided by others.  The last four book reviews that I posted have all had a “public opinion” portion (in separate blog articles), and I think that approach adds a new dimension to book reviews – I certainly appreciate the feedback that readers have provided.  If you are a senior DBA, or a person who enjoys digging to find the root meaning of what is stated, take a serious look at buying this book and writing a review. 

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:

  • rampant-books.com/t_oracle_ssd_disk_i_o.htm
  • praetoriate.com/t_%20oraclerac_ssd_with_rac.htm
  • dba-oracle.com/t_sun_solaris_solid_state_disk_ssd.htm
  • dba-oracle.com/t_flash_disk_drives_ssd_ram_san.htm
  • dba-oracle.com/art_dbazine_2020_p2.htm




I Didn’t Know That 5 – What is Wrong with this Quote?

13 12 2010

December 13, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

In the interest of interesting quotes, a quote that I found in the “Oracle Tuning the Definitive Reference Second Edition” book on page 539:

“But what is Oracle’s official position on multiple blocksizes?  For Oracle metal-level customers, there is the Oracle Metalink system which provides the official position of Oracle’s own experts.

Metalink Note: 46757.1, titled Notes on Choosing an Optimal Db Blocksize, says that there are some benefits from having larger blocksizes, but only under specific criteria (paraphrased from Metalink):

  • Large blocks give more data transfer per I/O call.
  • Larger blocksizes provide less fragmentation, i.e. row chaining and row migration, of large objects (LOB, BLOB, CLOB).
  • Indexes like big blocks because index height can be lower and more space exists within the index branch nodes.


Metalink goes on to say that multiple blocksizes may benefit shops that have ‘mixed’ blocksize requirements…”

What, if anything, is wrong with the above quote? 

—————–

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:





I Didn’t Know That 4 – What is Wrong with this Quote?

12 12 2010

December 12, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

In the interest of interesting quotes, a quote that I found in the “Oracle Tuning the Definitive Reference Second Edition” book on page 987:

Row ordering matters!
In some systems where a table is always accessed by the same key sequence, re-ordering the table into the same order as the queries can dramatically reduce I/O and improve SQL performance.

When reorganizing tables to improve SQL performance, keep this in-mind:

  • Only tables that experience multi-block reads (full-table scans) may see an appreciable SQL performance benefit.
  • Some shops will use sorted hash cluster tables to maintain row sequence order (in the same order as the most common indexed retrieval), and you can reorganize a table with an ‘order by’ clause to make the rows in the same sequence as the index.

But it’s not just tables that require periodic maintenance, it’s also indexes.”

What, if anything, is wrong with the above quote? 

—————–

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:

  • remote-dba.net/t_oracle_net_reorganize_tables.htm
  • dba-oracle.com/art_disk_io.htm
  • dba-oracle.com/t_table_row_resequencing.htm
  • dba-oracle.com/t_create_table_select_ctas.htm




I Didn’t Know That 3 – What is Wrong with this Quote?

11 12 2010

December 11, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

In the interest of interesting quotes, a quote that I found in the “Oracle Tuning the Definitive Reference Second Edition” book on page 828:

“When the index can no longer split because the owner block is full, Oracle will spawn a whole new index level, keeping the index tree in perfect logical and phyical balance.  Deletes are a different story.  Physically, Oracle indexes are always balanced because empty blocks stay inside the tree structure after a massive delete. Logically, Oracle indexes are not self-balancing because Oracle does not remove the dead blocks as they become empty.  Figure 16.9 shows an Oracle index before a massive delete…”

What, if anything, is wrong with the above quote?  Please keep in mind that the focus of this blog is on the technical content, and learning from that technical content.  Please stay positive in your responses (before answering, first take a look at page 727 to see if these two sections of the book are related – note that Richard Foote’s PDF file listed below seems to address page 727 of this book).

—————–

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:





I Didn’t Know That 2 – What is Wrong with this Quote?

10 12 2010

December 10, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

In the interest of interesting quotes, a quote that I found in the “Oracle Tuning the Definitive Reference Second Edition” book on page 988:

“Production DBA’s spend weekends reorganizing their data structures, returning them back into their original, pristine state, in preparation for the return of the end-users on Monday morning.

Rebuilding high-DML indexes in a schedule can be a DBA best practice under certain conditions:

  • You can schedule a job to rebuild and index (and address errors) in just a few minutes.  Because most DBA’s are salaried professionals, the DBA cost is negligible.
  • During a weekly maintenance window when the server sits idle.  Because hardware depreciates rapidly, regardless of use, the cost of rebuilding indexes is essentially zero.”

What, if anything, is wrong with the above quote?  Please keep in mind that the focus of this blog is on the technical content, and learning from that technical content.  Please stay positive in your responses (before answering, first take a look at page 727 to see if we really need to first determine the candidate indexes for a rebuild).

—————–

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:





I Didn’t Know That 1 – What is Wrong with this Quote?

9 12 2010

December 9, 2010

(Forward to the Next Post in the Series)

In the interest of interesting quotes, a quote that I found in the “Oracle Tuning the Definitive Reference Second Edition” book on page 995:

“In the 1970s, Moore’s law was introduced, stating that processor costs were always falling while speed continued to improve.  However, as Oracle professionals, we must understand that Moore’s law does not apply to RAM.  While RAM costs continue to fall every year, the speed of RAM access is constrained by silicon technology and did not improve over at least three decades as shown in Figure 17.1.”

What, if anything, is wrong with the above quote?  While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:

  • dba-oracle.com/art_dbazine_oracle_10g_data_warehouse.htm
  • dba-oracle.com/oracle_tips_hardware_oracle_performance.htm
  • dba-oracle.com/t_history_ram.htm

Helpful References:





Wait Events 3 – What is Wrong with this Quote?

9 12 2010

December 9, 2010

(Back to the Previous Post in the Series)

While reading the “Oracle Tuning the Definitive Reference Second Edition” book I found a handful of interesting suggestions regarding Oracle wait events.  Previous articles on this blog have described the contents of 10046 trace files, and leveraged the contents of those files to explain various types of problems and/or unexpected behavior (for example: three part series reading 10046 trace files, EXPLAIN PLAN/AUTOTRACE/TKPROF liesORDERED hint not followedfour part series: Enterprise Edition and Standard Edition perform differently11.2.0.1 ODBC bug, etc.)  Take three minutes to analyze the following quote from page 451 of the book that describes Oracle Database wait events found in 10046 trace files:

“Those Evil Wait Events in the 10046 Trace File

The trace file contains lots of details and it is important to seek out the wait event notes as the wait events are interspersed throughout the 10046 trace file.

WAIT #2: nam='SQL*Net message to client' ela= 10 p1=1111838976 p2=1 p3=0

This wait event record shows that the wait event (nam) is a SQL*Net message to client.  These wait events are the same wait events that can be found in the database in the v$ views like v$session_wait or v$event_name.

The elapsed time (ela) is in microseconds since this database is Oracle 10g, so this wait was a whole 10 microseconds.  This is nothing to worry about because 1 second = 1,000,000 microseconds.  Please note the P1, P2 and P3 variables are specific to each event.”

Keeping in mind that the book is printed after the release of Oracle Database 11.2.0.1 (and possibly 11.2.0.2 for some operating system platforms), what, if anything, is wrong with the above quote?

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:

  • dba-oracle.com/t_10046_trace_file_parse_execute.htm




Wait Events 2 – What is Wrong with this Quote?

8 12 2010

December 8, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

While reading the “Oracle Tuning the Definitive Reference Second Edition” book I found a handful of interesting suggestions regarding Oracle wait events.  Take 60 seconds to analyze the following quote from page 656:

“There are three columns of the v$session_wait view that are of particular interest for a buffer busy wait event: …  The following is an Oracle data dictionary query for these values:

select
  p1 "File #".
  p2 "Block #",
  p3 "Reason Code"
from
  v$session_wait
where
  event = 'buffer busy waits'; 

Keeping in mind that the book is printed after the release of Oracle Database 11.2.0.1 (and possibly 11.2.0.2 for some operating system platforms), what, if anything, is wrong with the above quote?

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

Other pages found during a Google search of the phrase:

  • Previous edition of the book
  • dba-oracle.com/art_builder_bbw.htm
  • praetoriate.com/t_oracle_wait_events_v$system_event.htm
  • dba-oracle.com/t_open_file_waits_event_tuning.htm
  • remote-dba.net/oracle_10g_tuning/t_buffer_busy_waits.htm




Wait Events 1 – What is Wrong with this Quote?

8 12 2010

December 8, 2010

(Forward to the Next Post in the Series)

While reading the “Oracle Tuning the Definitive Reference Second Edition” book I found a handful of interesting suggestions regarding Oracle wait events.  For instance, page 406 of the book states that:

“Excessive db file sequential read waits on an OLTP database might indicate a suboptimal disk subsystem or configuration issues with the disk array.  High I/O waits on the db file scatter read waits associated with large-table full-table scans may not always indicate a problem, but they are most commonly found on these kinds of databases:

  • Data warehouse and Decision Support applications
  • 32-bit Oracle systems with SGAs of less than 1.5 gigabytes
  • Databases that do not have enough buffer cache space to cache their working set of frequently referenced objects”

Keeping in mind that the book is printed after the release of Oracle Database 11.2.0.1 (and possibly 11.2.0.2 for some operating system platforms), what, if anything, is wrong with the above quote?  See example 1 on this blog article for a “Top 5 Timed Events” report section that is similar to what is found on page 406 of the book.

While my review of the book only provides an in-depth technical review of the first 200 pages of the book, this blog article series will dig into some of the pages that were not specifically included in the review.

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

As I stated in a comment in the earlier blog article, I would like to clarify that my review on the Amazon site is not intended to suggest that people should not buy the book. As the publisher’s website states that the book is written for senior Oracle DBAs, I suggest that senior DBAs, Oracle Certified Masters, and other people who are able to research the book’s contents *should* buy the book and post reviews of the book that highlight specific content of the book indicating whether or not that content is correctly stated. Such feedback will be a benefit to the Oracle community, and could help to improve Oracle Database books that are published in the future. I think that we need to keep a positive outlook in order to see things improve.

Other pages found during a Google search of the phrase:





Waiting for a Long Time – What is Going On?

7 12 2010

December 7, 2010

I recently reviewed the book “Oracle Tuning the Definitive Reference Second Edition”, and did not provide an in-depth technical review of the entire book.  This blog article series will dig into some of the pages that were not specifically included in the review.

Over the years I have seen several “Top 5 Timed Events” sections from Statspack and AWR reports.  I recall after reading the “Oracle Performance Tuning 101” book several years ago, the feeling of being quite confused.  Why?  No, it was not a problem with the book – the book made a lot of sense.  After reading the book I searched the Internet looking for more information, for example, for clear indicators that the LOG_BUFFER parameter was undersized.  Is 512KB enough, is 1MB enough, or maybe I have an extreme case that needs a 2MB value for the LOG_BUFFER parameter?  I found a number of web pages in a Google search, and some of those pages included “Top 5″ wait event output.  On one of those web pages the author indicated that the “Top 5″ wait event output indicated an undersized value for the LOG_BUFFER parameter, so I cross-referenced the wait event names with my notes from the “Oracle Performance Tuning 101″ book, and then became very confused.  No wonder Oracle Database performance tuning is so hard – the “Oracle Performance Tuning 101″ book notes caused me to arrive at a completely different problem point than what the author of the web page stated.  After examining more “Top 5″ wait event output sections, and digesting the “Optimizing Oracle Performance” book, I decided that my original opinion about the “Top 5″ sections were more than likely correct.

Let’s try an experiment (or a quiz, if you prefer).  I will show you a slightly modified version of a “Top 5″ wait event section from the “Oracle Tuning the Definitive Reference Second Edition” book, and you tell me your thoughts about that “Top 5″ section.  For example: are there any consistency problems, what does the “Top 5″ section indicate, how does your interpretation of the “Top 5″ section compare with that of the book author?  For an example of what I am trying to uncover, take a look at this blog article.  The last four “Top 5″ sections are from the AskTom website – any opinions on those “Top 5″ sections?

————————–

1 (pages 27 and 406):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                % Total
Event                          Waits   Time (s)  Ela Time
-------------------------- --------- ---------- --------
db file sequential read        5,196    14,292     48.53
db file scattered read        51,038     6,492     22.05
library cache load lock        1,346     2,726      9.25
CPU time                                 2,308      7.84
log file parallel write       38,314     1,674      5.67 

————————–

2 (pages 28, 323, and 405):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                            % Total
Event                      Waits    Time (s) Ela Time
-------------------------------- ----------- --------
CPU time                   9,702       8,084    55.75
db file sequential read    3,936       3,994    27.56
log file sync            598,194         738     5.07
db file scattered read   106,062         660     4.56
log file parallel write  605,360         380     2.61 

————————–

3 (pages 28 and 405):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                               % Total
Event                        Waits     Time (cs) Wt Time
--------------------------   --------  -------   --------
SQL*Net more data to client  1,957,467 4,737,686   99.77
db file sequential read        683,830     3,065     .07
db file parallel write           3,791     2,500     .05
rdbms ipc reply                     13     2,306     .04
db file scattered read           8,443     1,223     .02 

————————–

4 (page 105):

Top 5 Wait Events
~~~~~~~~~~~~~~~~~~                                  % Total
Event                          Waits     Time (cs)  Wt Time
--------------------------     --------  ---------  -------
enqueue                          51,802    959,308    46.70
db file scattered read       21,114,884    394,410    29.21
db file sequential read       1,448,650    393,166     9.13
latch free                    2,301,958    102,168     4.98
log file parallel write         297,864     79,644     3.87 

————————–

5 (page 107):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                        % Total
Event                         Waits        Time (s)     Ela Time
--------------------------- ------------ ---------- ------------
db file scattered read           651,038      6,492        82.03
library cache load lock            9,346      2,726         9.27
db file sequential read        1,069,196     14,292         4.53
CPU time                           2,308      1,290         3.84
log file parallel write           38,314      1,674         1.67 

————————–

6 (page 158):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                       % Total
Event                         Waits        Time (s)     Ela Time
--------------------------- ------------ ----------- -----------
CPU time                                     326,364       88.22
db file sequential read        3,085,708      17,102        4.63
log file sync                  3,648,938      16,804        4.53
log file parallel write        3,621,256       7,239        1.31
SQL*Net more data to client   30,842,404       1,314         .36 

————————–

7 (page 158):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                       % Total
Event                         Waits        Time (s)      DB Time
--------------------------- ------------ ----------- -----------
log file parallel write           19,340         582       55.66
log file sync                     18,586         556       53.13
CPU time                                         450       43.11
db file parallel write             9,844         402       38.54
control file parallel write        2,564         130       12.41 

————————–

8 (page 324):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                              % Total
Event                        Waits    Time (s) Ela Time
------------------------ --------- ----------- --------
db file sequential read  1,137,896       8,750    66.14
CPU time                                 3,966    30.00
db file scattered read     212,574         130      .98
log file sync               14,106         100      .76
log buffer space             3,434          94      .70 

————————–

9 (page 511):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                      % Total
Event                          Waits   Ela Time
-------------------------- ---------   --------
db file sequential read        5,196      48.53
db file scattered read        51,038      22.05
library cache load lock        1,346       9.25
CPU time                          88       7.84
log file parallel write       38,314       5.67 

————————–

10 (page 512):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                      % Total
Event                          Waits   Ela Time
-------------------------- ---------   --------
db file sequential read        5,196      48.53
db file scattered read        51,038      22.05
library cache load lock        1,346       9.25
CPU time                       4,308       7.84
log file parallel write       38,314       5.67 

————————–

11 (page 1002):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                            % Total
Event                      Waits    Time (s) Ela Time
-------------------------------- ----------- --------
db file scattered read     5,196      14,292    58.53   
db file sequential read   51,038       6,492    12.05
library cache load lock    1,346       2,726     9.25
CPU time                               2,308     7.84
log file parallel write   38,314       1,674     5.67 

————————–

12 (AskTom):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                                     % Total
Event                                               Waits    Time (s) Ela Time
-------------------------------------------- ------------ ----------- --------
CPU time                                                       19,612    35.04
latch free                                        899,688      14,371    25.68
db file scattered read                         16,333,411      13,105    23.42
SQL*Net message from dblink                       439,535       4,440     7.93
direct path write                                 405,226       1,509     2.70 

————————–

13 (AskTom):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                                     % Total
Event                                               Waits    Time (s) Ela Time
-------------------------------------------- ------------ ----------- --------
CPU time                                                        2,446    75.27
log file sync                                      12,883         212     6.52
latch free                                         17,869         182     5.60
log file parallel write                            35,538         174     5.34
SQL*Net break/reset to client                       5,544          80     2.46 

————————–

14 (AskTom):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                                     % Total
Event                                               Waits    Time (s) Ela Time
-------------------------------------------- ------------ ----------- --------
CPU time                                                        3,747    66.52
enqueue                                             2,129       1,350    23.97
db file sequential read                            37,842         286     5.07
log file sync                                       9,743          65     1.15
LGWR wait for redo copy                            58,067          61     1.08 

————————–

15 (AskTom):

Top 5 Timed Events
~~~~~~~~~~~~~~~~~~                                                     % Total
Event                                               Waits    Time (s) Ela Time
-------------------------------------------- ------------ ----------- --------
CPU time                                                       19,612    35.04
latch free                                        899,688      14,371    25.68
db file scattered read                         16,333,411      13,105    23.42
SQL*Net message from dblink                       439,535       4,440     7.93
direct path write                                 405,226       1,509     2.70 

————————–

Confused?  Or did you do well in this quiz?





Optimizer Costing 4 – What is Wrong with this Quote?

7 12 2010

December 7, 2010

(Back to the Previous Post in the Series)

I recently reviewed the book “Oracle Tuning the Definitive Reference Second Edition”, and did not provide an in-depth technical review of the entire book.  This blog article series will dig into some of the pages that were not specifically included in the review.  What is wrong with the following quote from page 744 of the book?

“Oracle 10g enhancements

Oracle 10g greatly aided the optimization of large SQL workloads with the introduction of dynamic sampling and root-cause optimization with dbms_stats.  Oracle acknowledged that the root cause of sub-optimal SQL execution plans related to the quality of CBO statistics, and they introduced enhancements to dbms_stats to allow for automatic histogram creation and the gather_system_stats procedure to collecting all-important external information, most notably the average disk access times for index access (sequential reads) and full-scan access (scattered reads).”

What, if anything, is wrong with the above quote from the book?

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

As I stated in a comment in the earlier blog article, I would like to clarify that my review on the Amazon site is not intended to suggest that people should not buy the book. As the publisher’s website states that the book is written for senior Oracle DBAs, I suggest that senior DBAs, Oracle Certified Masters, and other people who are able to research the book’s contents *should* buy the book and post reviews of the book that highlight specific content of the book indicating whether or not that content is correctly stated. Such feedback will be a benefit to the Oracle community, and could help to improve Oracle Database books that are published in the future. I think that we need to keep a positive outlook in order to see things improve.

Other pages found during a Google search of the phrase:

  • dba-oracle.com/t_global_sql_optimization.htm
  • oraclezine.blogspot.com/2009/03/important-notes-for-global-sql.html

Related Oracle Database documentation:





Optimizer Costing 3 – What is Wrong with this Quote?

6 12 2010

December 6, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

I recently reviewed the book “Oracle Tuning the Definitive Reference Second Edition”, and did not provide an in-depth technical review of the entire book.  This blog article series will dig into some of the pages that were not specifically included in the review.  What is wrong with the following quote from page 922 of the book?

Try a rule hint!

For testing unnecessary large table full table scans, try a rule hint (select /*+ RULE */ col1).  If the query uses the index with a rule hint, you have an issue with the CBO.”

What, if anything, is wrong with the above quote from the book?

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

As I stated in a comment in the earlier blog article, I would like to clarify that my review on the Amazon site is not intended to suggest that people should not buy the book. As the publisher’s website states that the book is written for senior Oracle DBAs, I suggest that senior DBAs, Oracle Certified Masters, and other people who are able to research the book’s contents *should* buy the book and post reviews of the book that highlight specific content of the book indicating whether or not that content is correctly stated. Such feedback will be a benefit to the Oracle community, and could help to improve Oracle Database books that are published in the future. I think that we need to keep a positive outlook in order to see things improve.

Other pages found during a Google search of the phrase:

Related Oracle Database documentation:





Optimizer Costing 2 – What is Wrong with this Quote?

6 12 2010

December 6, 2010

(Back to the Previous Post in the Series) (Forward to the Next Post in the Series)

I recently reviewed the book “Oracle Tuning the Definitive Reference Second Edition”, and did not provide an in-depth technical review of the entire book.  This blog article series will dig into some of the pages that were not specifically included in the review.  What is wrong with the following quote from page 527 of the book (this is an atypically long quote – the context would be lost if either of the two paragraphs were removed):

“In general, the Oracle CBO is unaware of buffer details, except when the optimizer_index_caching parameter is set where using multiple data buffers will not impact SQL execution plans.  When data using the new cpu_cost reported metric, the Oracle SQL optimizer builds the SQL plan decision tree based on the execution plan that will have the lowest estimated CPU cost.  For example, if a 32k data buffer is implemented for the index tablespace, the DBA can ensure that the indexes are cached for optimal performance and minimal logical I/O in range scans.

For example, if a database has 50 gigabytes of index space, a 60-gigabyte db_32k_cache_size can be defined and then the optimizer_index_caching parameter can be set to 100, telling the SQL optimizer that all of the Oracle indexes reside in RAM.  When Oracle makes the index versus table scan decision, knowing that the index nodes are in RAM will greatly influence the optimizer because the CBO knows that a logical I/O is often 100 times faster than a physical read.”

What, if anything, is wrong with the above quote from the book?

The point of blog articles like this one is not to insult authors who have spent thousands of hours carefully constructing an accurate and helpful book, but instead to suggest that readers investigate when something stated does not exactly match what one believes to be true.  It could be that the author “took a long walk down a short pier”, or that the author is revealing accurate information which simply cannot be found through other resources (and may in the process be directly contradicting information sources you have used in the past).  If you do not investigate in such cases, you may lose an important opportunity to learn something that could prove to be extremely valuable.

As I stated in a comment in the earlier blog article, I would like to clarify that my review on the Amazon site is not intended to suggest that people should not buy the book. As the publisher’s website states that the book is written for senior Oracle DBAs, I suggest that senior DBAs, Oracle Certified Masters, and other people who are able to research the book’s contents *should* buy the book and post reviews of the book that highlight specific content of the book indicating whether or not that content is correctly stated. Such feedback will be a benefit to the Oracle community, and could help to improve Oracle Database books that are published in the future. I think that we need to keep a positive outlook in order to see things improve.

A Google book search indicates that a slightly modified version of the statement appeared in a couple of  other books:

Other pages found during a Google search of the phrase:

  • dba-oracle.com/oracle_tips_multiple_blocksizes.htm
  • rampant-books.com/t_oracle_improve_sql_execution_speed.htm

Related Oracle Database documentation:








Follow

Get every new post delivered to your Inbox.

Join 139 other followers