A Year Older, Any Wiser?

30 11 2010

November 30, 2010 (Updated December 1, 2010)

(Forward to the Next Post in the Series)

It feels a bit strange, but this blog went live a year ago today.  What was the motivation for creating the blog?  At the time I was comtemplating creating a publically accessible Oracle Database related blog, I already had a restricted-access Oracle blog, and if I was lucky I had maybe four regular visitors (I might have five regular visitors now, or two that hit the refresh button 2.5 times a day).  Before setting up this blog I made the following comment in the above linked OTN thread:

“Yes, a lot of time is spent putting together the test cases. Even more time would be required to put together blog articles that better describe what appears in the test. I do not know if I am able to justify the time involvement, but I will consider starting a blog. However, there are already a large number of very good Oracle blogs. Maybe if it were used just to preserve some of the test cases?”

I had commented something like this, in a previous OTN thread when someone suggested that I set up a blog:

There are already a large number of fantastic Oracle related blogs on the Internet, and every subtopic seemed to have been previously covered in great detail.  I could not image developing unique material that anyone would care to read.

I guess that I proved myself wrong, yet again.  I can think of five good articles in the last year that I published, although I might be imagining things.  So, for the five regular readers (or the 2 that hit the refresh button 2.5 times daily), what are the five good articles?

Wow, I spent (maybe wasted, had I not learned a lot in the process) a lot of time in the last year creating material for this blog.

——————-

Edit: December 1, 2010:

Some of the 400 to 800 non-regular (thus, those who want to know why something is as it is) visitors to this blog who visit daily may be wondering what the symbol means at the top right of my blog, and where I obtained the symbol.  I will leave the meaning of the symbol to your imagination.  So, where did I obtain the symbol?  It was created using a painting/imaging editing program that I created in the late 1990s.  Take a look:

The splash screen, created entirely in the program:

The starting point, not much unusual here:

Let’s use some of those mathematics abilities that the teachers said were so critical to know in life, let’s build a brush using a cosine wave:

Better yet, let’s use sine wave for the brush and change the colors a bit:

Finger painting with the new brush – looking good, except that I keep scratching the canvas, leaving behind black marks:

Let’s play with some more mathematics to transform the picture:

We will use a spiral wave which progressively twists the image the further out from the center you go – using the angular coordinate system and sine and cosine to translate back into X, Y coordinates:

Let’s crank up the twist a bit more and see what it looks like – that certainly looks better than the previous pictures (I fixed the scratches in the canvas first):

But the earlier picture is still too plain, let’s add some lighting effects using, you guessed it, more mathematics:

That lower right corner looks a little boring, let’s roll it up using more mathematics:

Let’s do the same for the top left corner – that’s what mathematics are good for, rolling up the rug:

The last four pictures – pretty neat what can be done with all the mathematics we have worked so hard to forget over the years, too bad I never did anything useful with the painting/image editing program other than to use it as a teaching tool:
 
 





I ORDERED a Hint – Why Won’t You Listen to Me?

29 11 2010

November 29, 2010 (Updated November 30, 2010)

I recently read a blog article that forced me to Stop, Think, … Understand (which happens to be the subtitle of this blog, so it is worth mentioning).  The blog article discussed an error found in the Oracle Database documentation regarding how to read an execution plan – more specifically, how to find the first operation in the execution plan.  A couple of months ago I had the opportunity to attend one of Tanel Poder’s presentations, which I believe was titled “Back to Basics – Choosing the Starting Point of Performance Tuning and Troubleshooting Wisely.”  In the presentation Tanel remarked that there is an error in the documentation (quoted on the referenced blog article), which essentially states that the first operation executed in an execution plan is the operation that is indented the most to the right.  Tanel made the claim that (paraphrasing, of course) the first operation that is executed is actually the first operation (reading from the top of the execution plan) which has no child operations.  An interesting claim, with which I felt no doubt that is correct, but I never verified the claim.  I had that chance when reviewing the referenced blog article, where one of the comments smartly suggested to test with the ORDERED clause hint, and to examine the execution plan.  It seemed to me that this was a very good idea, and I was initially shocked to find that Tanel’s claim was incorrect.  But wait, we can’t stop yet.  What else can we test to see if Tanel is right (he is, of course – see the referenced blog article for the reason)?  How about a 10046 trace with the ORDERED clause hint?  But then I started seeing something strange, a quick script that uses the test tables that were created in an earlier blog article:

SET AUTOTRACE TRACEONLY STATISTICS
SET ARRAYSIZE 1000

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'ORDERED_POL_PO_P';
ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 8';

SELECT /*+ ORDERED */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PO_LINE POL,
  PO_HEADER PO,
  PARTS P
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'ORDERED_POL_P_PO';
ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 8';

SELECT /*+ ORDERED */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PO_LINE POL,
  PARTS P,
  PO_HEADER PO
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM;

SELECT SYSDATE FROM DUAL;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'ORDERED_P_POL_PO';
ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 8';

SELECT /*+ ORDERED */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PARTS P,
  PO_LINE POL,
  PO_HEADER PO
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM;

SELECT SYSDATE FROM DUAL;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'ORDERED_P_PO_POL';
ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 8';

SELECT /*+ ORDERED */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PARTS P,
  PO_HEADER PO,
  PO_LINE POL
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM;

SELECT SYSDATE FROM DUAL;

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

So, what is strange about the 10046 trace file.  Let’s take a look at the TKPROF output that was generated by Oracle Database 11.2.0.1 for the first SQL statement (color coded to help see the tables in the execution plan):  

SELECT /*+ ORDERED */
FROM
  PO_LINE POL,
  PO_HEADER PO,
  PARTS P

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      1855       1855       1855  HASH GROUP BY (cr=267225 pr=267202 pw=0 time=397 us cost=21234 size=105735 card=1855)
      5935       5935       5935   HASH JOIN  (cr=267225 pr=267202 pw=0 time=757 us cost=21233 size=338295 card=5935)
      5935       5935       5935    VIEW  VW_GBC_9 (cr=262229 pr=262213 pw=0 time=1641 us cost=20837 size=213660 card=5935)
      5935       5935       5935     HASH GROUP BY (cr=262229 pr=262213 pw=0 time=757 us cost=20837 size=308620 card=5935)
    329789     329789     329789      FILTER  (cr=262229 pr=262213 pw=0 time=4290315 us)
    329789     329789     329789       HASH JOIN  (cr=262229 pr=262213 pw=0 time=4248980 us cost=20823 size=17880824 card=343862)
     13890      13890      13890        TABLE ACCESS FULL PO_HEADER (cr=13173 pr=13163 pw=0 time=552501 us cost=1068 size=388920 card=13890)
  12205347   12205347   12205347        TABLE ACCESS FULL PO_LINE (cr=249056 pr=249050 pw=0 time=2448109 us cost=19697 size=292928328 card=12205347)
     99694      99694      99694    TABLE ACCESS FULL PARTS (cr=4996 pr=4989 pw=0 time=43511 us cost=394 size=2093574 card=99694) 

In the above, Oracle builds a hash table (this probably is not the right term, which escapes me at the moment) of the PO_HEADER table which is then used to probe into the 1.2 million rows in the PO_LINE table, eventually the 5935 rows from the join of PO_HEADER to PO_LINE is joined to the PARTS table.  So, other than the order of PO_HEADER and PO_LINE being swapped, the ORDERED hint seems to have controlled the order in which the tables were accessed.  Let’s take a look at the next query:

SELECT /*+ ORDERED */
FROM
  PO_LINE POL,
  PARTS P,
  PO_HEADER PO

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      1855       1855       1855  HASH GROUP BY (cr=267225 pr=317918 pw=50685 time=529 us cost=26617 size=135415 card=1855)
    329789     329789     329789   FILTER  (cr=267225 pr=317918 pw=50685 time=3703300 us)
    329789     329789     329789    HASH JOIN  (cr=267225 pr=317918 pw=50685 time=3669899 us cost=26602 size=25101926 card=343862)
     13890      13890      13890     TABLE ACCESS FULL PO_HEADER (cr=13173 pr=13163 pw=0 time=546640 us cost=1068 size=388920 card=13890)
  12205347   12205347   12205347     HASH JOIN  (cr=254052 pr=304755 pw=50685 time=3243495 us cost=25476 size=549240615 card=12205347)
  12205347   12205347   12205347      TABLE ACCESS FULL PO_LINE (cr=249056 pr=249050 pw=0 time=1831025 us cost=19697 size=292928328 card=12205347)
     99694      99694      99694      TABLE ACCESS FULL PARTS (cr=4996 pr=4989 pw=0 time=50678 us cost=394 size=2093574 card=99694) 

The above might give us a little trouble.  It looks like Oracle builds a hash table (this probably is not the right term, which escapes me at the moment) of the 1.2 million rows in the PO_LINE table which is then used to probe into the nearly 100,000 rows in the PARTS table, and then that result is hash joined to the PO_HEADER table.  So, the ORDERED hint seems to have exactly controlled the order in which the tables were accessed (but wait, something is wrong, if only I knew how to read the raw 10046 trace file).  Let’s check the next query’s TKPROF output: 

SELECT /*+ ORDERED */
FROM
  PARTS P,
  PO_LINE POL,
  PO_HEADER PO

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      1855       1855       1855  HASH GROUP BY (cr=267225 pr=267202 pw=0 time=397 us cost=26588 size=135415 card=1855)
    329789     329789     329789   FILTER  (cr=267225 pr=267202 pw=0 time=6561463 us)
    329789     329789     329789    HASH JOIN  (cr=267225 pr=267202 pw=0 time=6525886 us cost=26574 size=25101926 card=343862)
     13890      13890      13890     TABLE ACCESS FULL PO_HEADER (cr=13173 pr=13163 pw=0 time=532624 us cost=1068 size=388920 card=13890)
  12205347   12205347   12205347     HASH JOIN  (cr=254052 pr=254039 pw=0 time=6233040 us cost=25447 size=549240615 card=12205347)
     99694      99694      99694      TABLE ACCESS FULL PARTS (cr=4996 pr=4989 pw=0 time=42487 us cost=394 size=2093574 card=99694)
  12205347   12205347   12205347      TABLE ACCESS FULL PO_LINE (cr=249056 pr=249050 pw=0 time=1623411 us cost=19697 size=292928328 card=12205347)

The join order is PARTS -> PO_LINE -> PO_HEADER, just like what we ORDERED (but wait, what does that 10046 trace file show again?).  Let’s take a look at the final query’s TKPROF output:

SELECT /*+ ORDERED */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PARTS P,
  PO_HEADER PO,
  PO_LINE POL

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      1855       1855       1855  HASH GROUP BY (cr=267225 pr=284314 pw=17112 time=794 us cost=78881 size=109445 card=1855)
    103059     103059     103059   MERGE JOIN  (cr=267225 pr=284314 pw=17112 time=2531825 us cost=78877 size=6031275 card=102225)
   3628420    3628420    3628420    SORT JOIN (cr=254052 pr=271151 pw=17112 time=930143 us cost=77807 size=112482384 card=3628464)
   3628464    3628464    3628464     VIEW  VW_GBC_9 (cr=254052 pr=257294 pw=3255 time=1181413 us cost=77807 size=112482384 card=3628464)
   3628464    3628464    3628464      HASH GROUP BY (cr=254052 pr=257294 pw=3255 time=702832 us cost=77807 size=163280880 card=3628464)
  12205347   12205347   12205347       FILTER  (cr=254052 pr=254039 pw=0 time=7536710 us)
  12205347   12205347   12205347        HASH JOIN  (cr=254052 pr=254039 pw=0 time=6162000 us cost=25447 size=549240615 card=12205347)
     99694      99694      99694         TABLE ACCESS FULL PARTS (cr=4996 pr=4989 pw=0 time=45175 us cost=394 size=2093574 card=99694)
  12205347   12205347   12205347         TABLE ACCESS FULL PO_LINE (cr=249056 pr=249050 pw=0 time=1711986 us cost=19697 size=292928328 card=12205347)
    103059     103059     103059    SORT JOIN (cr=13173 pr=13163 pw=0 time=0 us cost=1070 size=388920 card=13890)
     13890      13890      13890     TABLE ACCESS FULL PO_HEADER (cr=13173 pr=13163 pw=0 time=550208 us cost=1068 size=388920 card=13890) 

The join order is PARTS -> PO_LINE -> PO_HEADER.  What?  I thought that I requested, no DEMANDED (hints are directives after all) that we join in this order:
PARTS -> PO_HEADER -> PO_LINE

I guess that I need to check the documentation for the ORDERED hint: 

“The ORDERED hint instructs Oracle to join tables in the order in which they appear in the FROM clause. Oracle recommends that you use the LEADING hint, which is more versatile than the ORDERED hint.

When you omit the ORDERED hint from a SQL statement requiring a join, the optimizer chooses the order in which to join the tables. You might want to use the ORDERED hint to specify a join order if you know something that the optimizer does not know about the number of rows selected from each table. Such information lets you choose an inner and outer table better than the optimizer could.”

OK, so the documentation confirms that the ORDERED hint controls the join order, not the order in which the tables are accessed.  So, how can we explain why the optimizer did not do as we instructed, with a specific join order?  We could create a 10053 trace file for the query:

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

SELECT /*+ ORDERED */ /* FIND_ME */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PARTS P,
  PO_HEADER PO,
  PO_LINE POL
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM;
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT OFF';

Taking a look inside the 10053 trace file, we find the execution plan with the Predicate Information section:

============
Plan Table
============
---------------------------------------------+-----------------------------------+
| Id  | Operation                 | Name     | Rows  | Bytes | Cost  | Time      |
---------------------------------------------+-----------------------------------+
| 0   | SELECT STATEMENT          |          |       |       |  125K |           |
| 1   |  HASH GROUP BY            |          |  168K | 9936K |  125K |  00:17:04 |
| 2   |   MERGE JOIN              |          |  548K |   32M |  122K |  00:17:39 |
| 3   |    SORT JOIN              |          | 9629K |  292M |  121K |  00:16:29 |
| 4   |     VIEW                  | VW_GBC_9 | 9629K |  292M |  121K |  00:16:29 |
| 5   |      HASH GROUP BY        |          | 9629K |  423M |  121K |  00:16:29 |
| 6   |       FILTER              |          |       |       |       |           |
| 7   |        HASH JOIN          |          |   12M |  524M |   25K |  00:03:24 |
| 8   |         TABLE ACCESS FULL | PARTS    |   97K | 2045K |   394 |  00:00:04 |
| 9   |         TABLE ACCESS FULL | PO_LINE  |   12M |  279M |   19K |  00:03:38 |
| 10  |    SORT JOIN              |          |   27K |  767K |  1251 |  00:00:11 |
| 11  |     TABLE ACCESS FULL     | PO_HEADER|   27K |  767K |  1068 |  00:00:09 |
---------------------------------------------+-----------------------------------+
Predicate Information:
----------------------
6 - filter(TRUNC(SYSDATE@!-90)<=TRUNC(SYSDATE@!))
7 - access("POL"."PART_ID"="P"."PART_ID")
10 - access("PO"."PURC_ORDER_ID"="ITEM_1")
10 - filter("PO"."PURC_ORDER_ID"="ITEM_1")
11 - filter(("PO"."ORDER_DATE"<=TRUNC(SYSDATE@!) AND "PO"."ORDER_DATE">=TRUNC(SYSDATE@!-90))) 

ITEM_1?  Someone’s been rewriting my SQL statement?  Let’s look a little further up the trace file (the query text printed in the 10053 trace file has been reformatted with extra line breaks and spaces):

Final query after transformations:******* UNPARSED QUERY IS *******
SELECT /*+ ORDERED */
  "PO"."VENDOR_ID" "VENDOR_ID",
  "VW_GBC_9"."ITEM_3" "PRODUCT_CODE",
  "VW_GBC_9"."ITEM_4" "STOCK_UM",
  SUM("VW_GBC_9"."ITEM_2") "ORDER_QTY"
FROM
  (SELECT
     "POL"."PURC_ORDER_ID" "ITEM_1",
     SUM("POL"."ORDER_QTY") "ITEM_2",
     "P"."PRODUCT_CODE" "ITEM_3",
     "P"."STOCK_UM" "ITEM_4"
   FROM
     "TESTUSER"."PO_LINE" "POL",
     "TESTUSER"."PARTS" "P"
   WHERE
     "POL"."PART_ID"="P"."PART_ID"
      AND TRUNC(SYSDATE@!-90)<=TRUNC(SYSDATE@!)
   GROUP BY
    "POL"."PURC_ORDER_ID","P"."PRODUCT_CODE","P"."STOCK_UM") "VW_GBC_9",
  "TESTUSER"."PO_HEADER" "PO"
WHERE
  "PO"."ORDER_DATE">=TRUNC(SYSDATE@!-90)
  AND "PO"."ORDER_DATE"<=TRUNC(SYSDATE@!)
  AND "PO"."PURC_ORDER_ID"="VW_GBC_9"."ITEM_1"
GROUP BY
  "PO"."VENDOR_ID",
  "VW_GBC_9"."ITEM_3",
  "VW_GBC_9"."ITEM_4"
kkoqbc: optimizing query block SEL$6E4193EC (#2) 

Well, I guess that explains why my ORDERED hint did not behave as expected.  Darn optimizer completely rewrote the SQL statement before the ORDERED hint was applied.  Now I am starting to wonder how this query might perform in Oracle Database 10.2.0.5, since the hinted query was affected by an automatic transformation performed by the optimizer.

————-

Now, back to demonstrate that Tanel’s claim is correct.  First, let’s find the OBJECT_IDs for the tables involved in the query:

SQL> SELECT OBJECT_NAME FROM DBA_OBJECTS WHERE OBJECT_ID=82052;

OBJECT_NAME
---------------------------------------------------------------
PARTS

SQL> SELECT OBJECT_NAME FROM DBA_OBJECTS WHERE OBJECT_ID=82062;

OBJECT_NAME
---------------------------------------------------------------
PO_HEADER

SQL> SELECT OBJECT_NAME FROM DBA_OBJECTS WHERE OBJECT_ID=82069;

OBJECT_NAME
---------------------------------------------------------------
PO_LINE 

From the above, we see that PARTS=82052, PO_HEADER=82062, and PO_LINE=82069.  Now what?  Let’s check the raw 10046 trace file for the second of our test queries that generated the following TKPROF output:

SELECT /*+ ORDERED */
FROM
  PO_LINE POL,
  PARTS P,
  PO_HEADER PO

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      1855       1855       1855  HASH GROUP BY (cr=267225 pr=317918 pw=50685 time=529 us cost=26617 size=135415 card=1855)
    329789     329789     329789   FILTER  (cr=267225 pr=317918 pw=50685 time=3703300 us)
    329789     329789     329789    HASH JOIN  (cr=267225 pr=317918 pw=50685 time=3669899 us cost=26602 size=25101926 card=343862)
     13890      13890      13890     TABLE ACCESS FULL PO_HEADER (cr=13173 pr=13163 pw=0 time=546640 us cost=1068 size=388920 card=13890)
  12205347   12205347   12205347     HASH JOIN  (cr=254052 pr=304755 pw=50685 time=3243495 us cost=25476 size=549240615 card=12205347)
  12205347   12205347   12205347      TABLE ACCESS FULL PO_LINE (cr=249056 pr=249050 pw=0 time=1831025 us cost=19697 size=292928328 card=12205347)
     99694      99694      99694      TABLE ACCESS FULL PARTS (cr=4996 pr=4989 pw=0 time=50678 us cost=394 size=2093574 card=99694)  

------

PARSING IN CURSOR #3 len=338 dep=0 uid=286 oct=3 lid=286 tim=4471668209 hv=2860598711 ad='469666838' sqlid='2fhf2v2p82jdr'
SELECT /*+ ORDERED */
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PO_LINE POL,
  PARTS P,
  PO_HEADER PO
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM
END OF STMT
PARSE #3:c=0,e=43,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=4284856579,tim=4471668208
EXEC #3:c=0,e=47,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=4284856579,tim=4471668337
WAIT #3: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=0 tim=4471668363
WAIT #3: nam='db file sequential read' ela= 359 file#=1 block#=536704 blocks=1 obj#=82062 tim=4471668787
WAIT #3: nam='db file scattered read' ela= 596 file#=1 block#=536705 blocks=7 obj#=82062 tim=4471669513
WAIT #3: nam='db file scattered read' ela= 564 file#=1 block#=536752 blocks=8 obj#=82062 tim=4471670343
WAIT #3: nam='db file scattered read' ela= 470 file#=1 block#=536760 blocks=8 obj#=82062 tim=4471671092
WAIT #3: nam='db file scattered read' ela= 639 file#=1 block#=536768 blocks=8 obj#=82062 tim=4471671970
...
WAIT #3: nam='db file scattered read' ela= 408 file#=1 block#=558336 blocks=128 obj#=82062 tim=4472034957
WAIT #3: nam='db file scattered read' ela= 334 file#=1 block#=558464 blocks=107 obj#=82062 tim=4472036641
WAIT #3: nam='db file sequential read' ela= 357 file#=1 block#=96384 blocks=1 obj#=82069 tim=4472040086
WAIT #3: nam='direct path read' ela= 385 file number=1 first dba=96385 block cnt=7 obj#=82069 tim=4472040755
WAIT #3: nam='direct path read' ela= 186 file number=1 first dba=96456 block cnt=8 obj#=82069 tim=4472045786
WAIT #3: nam='direct path read' ela= 611 file number=1 first dba=96496 block cnt=24 obj#=82069 tim=4472046904
...
WAIT #3: nam='direct path read' ela= 1104 file number=1 first dba=1342848 block cnt=128 obj#=82069 tim=4478002620
WAIT #3: nam='direct path write temp' ela= 1601 file number=201 first dba=245981 block cnt=31 obj#=82069 tim=4478004794
WAIT #3: nam='direct path write temp' ela= 1985 file number=201 first dba=246016 block cnt=31 obj#=82069 tim=4478017466
WAIT #3: nam='direct path write temp' ela= 2423 file number=201 first dba=245725 block cnt=31 obj#=82069 tim=4478023049
WAIT #3: nam='direct path write temp' ela= 441 file number=201 first dba=245791 block cnt=31 obj#=82069 tim=4478027519
WAIT #3: nam='direct path write temp' ela= 2985 file number=201 first dba=245950 block cnt=31 obj#=82069 tim=4478030913
WAIT #3: nam='asynch descriptor resize' ela= 4 outstanding #aio=1 current aio limit=4294967295 new aio limit=511 obj#=82069 tim=4478044778
WAIT #3: nam='db file sequential read' ela= 28370 file#=1 block#=515584 blocks=1 obj#=82052 tim=4478077091
WAIT #3: nam='db file scattered read' ela= 503 file#=1 block#=515585 blocks=7 obj#=82052 tim=4478077765
WAIT #3: nam='direct path read temp' ela= 806 file number=201 first dba=288671 block cnt=31 obj#=82052 tim=4478097288
WAIT #3: nam='direct path read temp' ela= 467 file number=201 first dba=288702 block cnt=31 obj#=82052 tim=4478098147
WAIT #3: nam='direct path read temp' ela= 435 file number=201 first dba=288733 block cnt=31 obj#=82052 tim=4478099041
... 

Repeating what we found earlier: PARTS=82052, PO_HEADER=82062, and PO_LINE=82069.  We see that Oracle Database's runtime engine accessed the PO_HEADER table first, and then the PO_LINE table, and then finally the PARTS table, just as Tanel had claimed would happen.

But what is that 'asynch descriptor resize' wait event?  Could Tanel Poder have already answered that question?

--------------

Edit November 30, 2010:

Summarizing the comments so far:

  • When unnesting a subquery, optimizer performs the unnest operation *before* appying the ORDERED hint. (Tanel Poder)
  • Outline directives use the LEADING hint and not the ORDERED hint. (Greg Rahn)
  • The LEADING hint should be used when possible rather than the ORDERED hint - the differences with the ORDERED hint may not be exposed until an upgrade is performed.
  • On Oracle Database 10.2.0.5 the execution plans are identical for the ORDERED and LEADING hint versions of the four SQL statements, including the one with the intentional Cartesian join (the GBP entries that appear to be associated with Cost-Based Group-By/Distinct Placement do not appear in 10053 trace files on 10.2.0.5).
  • On Oracle Database 11.1.0.7 the execution plans are identical for the ORDERED and LEADING hint versions of the first three SQL statements (and identical to 10.2.0.5), while the ORDERED version of the last SQL statement (with the intentional Cartesian join) was transformed into a different SQL statement in a section of the 10053 trace file called "Cost-Based Group By Placement"
  • On Oracle Database 11.2.0.1 the execution plans are identical for the ORDERED and LEADING hint versions of the first three SQL statements (and identical to 10.2.0.5), while the ORDERED version of the last SQL statement (with the intentional Cartesian join) was transformed into a different SQL statement (identical to 11.1.0.7) in a section of the 10053 trace file called "Cost-Based Group-By/Distinct Placement"
  • On Oracle Database 11.2.0.1 the execution plans for the SQL statements could potentially change on future executions due to the effects of Cardinality Feedback
  • On Oracle Database 11.2.0.1 when the execution plans for the SQL statements change due to Cardinality Feedback, SET AUTOTRACE TRACEONLY EXPLAIN continues to show the original execution plan even after 10046 trace files show that the runtime engine is using the execution plan developed as a result of Cardinality Feedback.
  • For execution plans affected by Cardinality Feedback, the "Content of other_xml column" portion of a 10053 trace (just below the printed execution plan) will show "cardinality_feedback: yes".

Just wondering if anyone noticed that on my laptop (used for this blog article) I apparently created the objects in the SYSTEM tablespace while connected as the TESTUSER (I did not set the default tablespace for the TESTUSER, and apparently did not set a system-wide default).  How would I know that from the above blog article alone?





Different Performance from Standard Edition and Enterprise Edition? 4

24 11 2010

November 24, 2010

(Back to the Previous Post in the Series)

The previous articles in this series showed potential differences in performance between the Enterprise Edition of Oracle Database and the Standard Edition, as well as changes from release 10.2.0.5 to 11.2.0.1 for the same edition, even when the execution plans appeared to be the same.  The queries in the earlier articles were quite simple, yet demonstrated some of the types of problems that could be encountered if the servers used for the development or test do not use the same release version or edition as the production database, or even if the workload system (CPU) statistics differ.

Today’s blog article builds a more complicated test case – if you decide to try the test case, be prepared to spend between one and three hours building the test tables.  The tables that are constructed by the script are intended to model a portion of the data model employed by an ERP package, complete with foreign key constraints and regular check constraints.  The test script includes queries that are intended to answer questions that might be posed by a user of the ERP package, although the generated, reproducible test data likely does not match what would be found in a typical ERP application.  It might also be interesting to see how the different release versions and editions behave when pummeled by database agnostic code that might be found in certain applications – I wondr if that might be a topic for a future blog article.

Before we start, the commands to drop the generated tables and indexes are listed below - if you have any tables with these names in your database (schema), you probably do not want to execute the scripts in this blog article:

DROP TABLE PO_LINE PURGE;
DROP TABLE PO_HEADER PURGE;
DROP TABLE PO_LINE_TEMP PURGE;
DROP TABLE PO_HEADER_TEMP PURGE;
DROP TABLE PARTS PURGE;
DROP TABLE PARTS_TEMP PURGE;
DROP TABLE VENDORS PURGE;
DROP TABLE VENDORS_TEMP PURGE;
DROP TABLE LOCATIONS PURGE;
DROP TABLE UMS PURGE;

DROP INDEX IND_LOCATIONS_1;
DROP INDEX IND_PARTS_1;
DROP INDEX IND_PARTS_2;
DROP INDEX IND_PARTS_3;
DROP INDEX IND_PARTS_4;
DROP INDEX IND_PARTS_5;
DROP INDEX IND_PARTS_6;
DROP INDEX IND_PARTS_7;
DROP INDEX IND_PO_HEADER_1;
DROP INDEX IND_PO_HEADER_2;
DROP INDEX IND_PO_HEADER_3;
DROP INDEX IND_PO_HEADER_4;
DROP INDEX IND_PO_LINE_1;
DROP INDEX IND_PO_LINE_2;
DROP INDEX IND_PO_LINE_3;
DROP INDEX IND_PO_LINE_4;

As in the earlier blog articles, the following system (CPU) statistics will be used in all of the databases:

EXEC DBMS_STATS.SET_SYSTEM_STATS('MBRC',16)
EXEC DBMS_STATS.SET_SYSTEM_STATS('CPUSPEED',2664)
EXEC DBMS_STATS.SET_SYSTEM_STATS('SREADTIM',8)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MREADTIM',10)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MAXTHR',19181568) 

The initial table setup script follows, expect this script to take one to three hours to complete.  A 10053 and 10046 trace will be enabled, just to see if we receive different performance behavior from the four databases.  The defaults for table and index statistics collection will be used in the script, the SGA_TARGET will be set to 8000M, and the PGA_AGGREGATE_TARGET will be set to 1800M for the test runs.  (The redo logs were left at the default of 50MB in the 10.2.0.5 Standard Edition Database, while the other databases had five 512MB redo logs – this will affect the results of this script that are displayed later in this article.  Archiving of redo logs was disabled in all databases.)

SET ARRAYSIZE 1000

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

CREATE TABLE LOCATIONS(
  LOCATION_ID VARCHAR2(15) NOT NULL ENABLE,
  WAREHOUSE_ID VARCHAR2(15) NOT NULL ENABLE,
  DESCRIPTION VARCHAR2(80),
  LOCATION_TYPE CHAR(1) NOT NULL ENABLE,
  CONSTRAINT "CHK_LOCATIONS" CHECK (
    (LOCATION_TYPE = 'T' Or LOCATION_TYPE = 'R' Or LOCATION_TYPE = 'F')) ENABLE,
  PRIMARY KEY (WAREHOUSE_ID, LOCATION_ID));

CREATE INDEX IND_LOCATIONS_1 ON LOCATIONS (LOCATION_ID);

CREATE TABLE UMS (
  UNIT_OF_MEASURE VARCHAR2(15) NOT NULL ENABLE,
  DESCRIPTION VARCHAR2(40),
  UOM_SCALE NUMBER NOT NULL ENABLE,
  CONSTRAINT "CHK_UOM_SCALE" CHECK (
    (UOM_SCALE >= 0 And UOM_SCALE <= 4)) ENABLE,
  PRIMARY KEY ("UNIT_OF_MEASURE"));

CREATE TABLE VENDORS (
  VENDOR_ID VARCHAR2(15) NOT NULL ENABLE,
  VENDOR_NAME VARCHAR2(50),
  ADDR_1 VARCHAR2(50),
  ADDR_2 VARCHAR2(50),
  ADDR_3 VARCHAR2(50),
  CITY VARCHAR2(30),
  STATE VARCHAR2(10),
  ZIPCODE VARCHAR2(10),
  COUNTRY VARCHAR2(50),
  CONTACT_FIRST_NAME VARCHAR2(30),
  CONTACT_LAST_NAME VARCHAR2(30),
  CONTACT_INITIAL VARCHAR2(2),
  CONTACT_POSITION VARCHAR2(20),
  CONTACT_HONORIFIC VARCHAR2(4),
  CONTACT_SALUTATION VARCHAR2(60),
  CONTACT_PHONE VARCHAR2(20),
  CONTACT_FAX VARCHAR2(20),
  REMIT_TO_NAME VARCHAR2(50),
  REMIT_TO_ADDR_1 VARCHAR2(50),
  REMIT_TO_ADDR_2 VARCHAR2(50),
  REMIT_TO_ADDR_3 VARCHAR2(50),
  REMIT_TO_CITY VARCHAR2(30),
  REMIT_TO_STATE VARCHAR2(10),
  REMIT_TO_ZIPCODE VARCHAR2(10),
  REMIT_TO_COUNTRY VARCHAR2(50),
  FREE_ON_BOARD VARCHAR2(25),
  SHIP_VIA VARCHAR2(40),
  BUYER VARCHAR2(15),
  REPORT_1099_MISC CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  TERMS_NET_TYPE CHAR(1) DEFAULT ' ' NOT NULL ENABLE,
  TERMS_NET_DAYS NUMBER,
  TERMS_NET_DATE DATE,
  TERMS_DISC_TYPE CHAR(1) DEFAULT ' ' NOT NULL ENABLE,
  TERMS_DISC_DAYS NUMBER,
  TERMS_DISC_DATE DATE,
  TERMS_DISC_PERCENT NUMBER(5,3),
  TERMS_DESCRIPTION VARCHAR2(50),
  USER_1 VARCHAR2(80),
  USER_2 VARCHAR2(80),
  USER_3 VARCHAR2(80),
  USER_4 VARCHAR2(80),
  USER_5 VARCHAR2(80),
  USER_6 VARCHAR2(80),
  USER_7 VARCHAR2(80),
  USER_8 VARCHAR2(80),
  USER_9 VARCHAR2(80),
  USER_10 VARCHAR2(80),
  CONSTRAINT "CHK_VENDORS" CHECK (
    (REPORT_1099_MISC = 'Y' Or REPORT_1099_MISC = 'N')
    AND (TERMS_NET_TYPE = 'A'
      Or TERMS_NET_TYPE = 'M'
      Or TERMS_NET_TYPE = 'D'
      Or TERMS_NET_TYPE = 'N'
      Or TERMS_NET_TYPE = 'E')
    AND (TERMS_DISC_TYPE = 'A'
      Or TERMS_DISC_TYPE = 'M'
      Or TERMS_DISC_TYPE = 'D'
      Or TERMS_DISC_TYPE = 'N'
      Or TERMS_DISC_TYPE = 'E')) ENABLE,
  PRIMARY KEY (VENDOR_ID));

CREATE TABLE VENDORS_TEMP AS
SELECT
  *
FROM
  VENDORS;

CREATE TABLE PARTS (
  PART_ID VARCHAR2(30) NOT NULL ENABLE,
  DESCRIPTION VARCHAR2(40),
  STOCK_UM VARCHAR2(15) NOT NULL ENABLE,
  PLANNING_LEADTIME NUMBER DEFAULT 0 NOT NULL ENABLE,
  ORDER_POLICY CHAR(1) DEFAULT 'M' NOT NULL ENABLE,
  ORDER_POINT NUMBER(14,4),
  SAFETY_STOCK_QTY NUMBER(14,4),
  FIXED_ORDER_QTY NUMBER(14,4),
  DAYS_OF_SUPPLY NUMBER,
  MINIMUM_ORDER_QTY NUMBER(14,4),
  MAXIMUM_ORDER_QTY NUMBER(14,4),
  ENGINEERING_MSTR VARCHAR2(3),
  PRODUCT_CODE VARCHAR2(15),
  COMMODITY_CODE VARCHAR2(15),
  MFG_NAME VARCHAR2(30),
  MFG_PART_ID VARCHAR2(30),
  FABRICATED CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  PURCHASED CHAR(1) DEFAULT 'Y' NOT NULL ENABLE,
  STOCKED CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  DETAIL_ONLY CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  DEMAND_HISTORY CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  TOOL_OR_FIXTURE CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  INSPECTION_REQD CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  WEIGHT NUMBER(14,4),
  WEIGHT_UM VARCHAR2(15),
  DRAWING_ID VARCHAR2(15),
  DRAWING_REV_NO VARCHAR2(8),
  PREF_VENDOR_ID VARCHAR2(15),
  PRIMARY_WHS_ID VARCHAR2(15),
  PRIMARY_LOC_ID VARCHAR2(15),
  BACKFLUSH_WHS_ID VARCHAR2(15),
  BACKFLUSH_LOC_ID VARCHAR2(15),
  INSPECT_WHS_ID VARCHAR2(15),
  INSPECT_LOC_ID VARCHAR2(15),
  MRP_REQUIRED CHAR(1) DEFAULT 'N',
  MRP_EXCEPTIONS CHAR(1) DEFAULT 'N',
  PRIVATE_UM_CONV CHAR(1) DEFAULT 'N',
  AUTO_BACKFLUSH CHAR(1) DEFAULT 'Y',
  PLANNER_USER_ID VARCHAR2(20),
  BUYER_USER_ID VARCHAR2(20),
  ABC_CODE CHAR(1),
  ANNUAL_USAGE_QTY NUMBER(15,4),
  INVENTORY_LOCKED CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  UNIT_MATERIAL_COST NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  UNIT_LABOR_COST NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  UNIT_BURDEN_COST NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  UNIT_SERVICE_COST NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  BURDEN_PERCENT NUMBER(5,2) DEFAULT 0 NOT NULL ENABLE,
  BURDEN_PER_UNIT NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  PURC_BUR_PERCENT NUMBER(6,3) DEFAULT 0 NOT NULL ENABLE,
  PURC_BUR_PER_UNIT NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  FIXED_COST NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  UNIT_PRICE NUMBER(20,6),
  NEW_MATERIAL_COST NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  NEW_LABOR_COST NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  NEW_BURDEN_COST NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  NEW_SERVICE_COST NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  NEW_BURDEN_PERCENT NUMBER(5,2) DEFAULT 0 NOT NULL ENABLE,
  NEW_BURDEN_PERUNIT NUMBER(20,6) DEFAULT 0 NOT NULL ENABLE,
  NEW_FIXED_COST NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  MAT_GL_ACCT_ID VARCHAR2(30),
  LAB_GL_ACCT_ID VARCHAR2(30),
  BUR_GL_ACCT_ID VARCHAR2(30),
  SER_GL_ACCT_ID VARCHAR2(30),
  QTY_ON_HAND NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  QTY_AVAILABLE_ISS NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  QTY_AVAILABLE_MRP NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  QTY_ON_ORDER NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  QTY_IN_DEMAND NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  USER_1 VARCHAR2(80),
  USER_2 VARCHAR2(80),
  USER_3 VARCHAR2(80),
  USER_4 VARCHAR2(80),
  USER_5 VARCHAR2(80),
  USER_6 VARCHAR2(80),
  USER_7 VARCHAR2(80),
  USER_8 VARCHAR2(80),
  USER_9 VARCHAR2(80),
  USER_10 VARCHAR2(80),
  LT_PLUS_DAYS NUMBER,
  LT_MINUS_DAYS NUMBER,
  STATUS CHAR(1),
  USE_SUPPLY_BEF_LT CHAR(1),
  QTY_COMMITTED NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  PRT_CREATE_USER_ID VARCHAR2(30) DEFAULT USER,
  PRT_CREATE_DATE DATE DEFAULT SYSDATE,
  CONSTRAINT "CHK_PART1" CHECK (
    (PLANNING_LEADTIME >= 0)
    AND (ORDER_POLICY = 'N'
      Or ORDER_POLICY = 'M'
      Or ORDER_POLICY = 'F'
      Or ORDER_POLICY = 'E'
      Or ORDER_POLICY = 'D'
      Or ORDER_POLICY = 'P')
    AND (ORDER_POINT >= 0)
    AND (SAFETY_STOCK_QTY >= 0)
    AND (FIXED_ORDER_QTY >= 0)
    AND (DAYS_OF_SUPPLY >= 0)
    AND (MINIMUM_ORDER_QTY >= 0)
    AND (MAXIMUM_ORDER_QTY >= 0)
    AND (FABRICATED = 'Y' Or FABRICATED = 'N')
    AND (PURCHASED = 'Y' Or PURCHASED = 'N')
    AND (STOCKED = 'Y' Or STOCKED = 'N')
    AND (DETAIL_ONLY = 'Y' Or DETAIL_ONLY = 'N')
    AND (DEMAND_HISTORY = 'Y' Or DEMAND_HISTORY = 'N')
    AND (TOOL_OR_FIXTURE = 'Y' Or TOOL_OR_FIXTURE = 'N')
    AND (MRP_REQUIRED = 'Y' Or MRP_REQUIRED = 'N')
    AND (MRP_EXCEPTIONS = 'Y' Or MRP_EXCEPTIONS = 'N')
    AND (PRIVATE_UM_CONV = 'Y' Or PRIVATE_UM_CONV = 'N')
    AND (INVENTORY_LOCKED = 'Y' Or INVENTORY_LOCKED = 'N')
    AND (INSPECTION_REQD = 'Y' Or INSPECTION_REQD = 'N')) ENABLE,
  PRIMARY KEY (PART_ID),
  CONSTRAINT "FKEY_INSP" FOREIGN KEY (INSPECT_WHS_ID, INSPECT_LOC_ID)
    REFERENCES LOCATIONS (WAREHOUSE_ID, LOCATION_ID) ENABLE,
  CONSTRAINT "FKEY_PREF_VENDOR" FOREIGN KEY (PREF_VENDOR_ID)
    REFERENCES VENDORS (VENDOR_ID) ENABLE,
  CONSTRAINT "FKEY_UM" FOREIGN KEY (WEIGHT_UM)
    REFERENCES UMS (UNIT_OF_MEASURE) ENABLE,
  CONSTRAINT "FKEY_STOCK_UM" FOREIGN KEY (STOCK_UM)
    REFERENCES UMS (UNIT_OF_MEASURE) ENABLE);

CREATE INDEX IND_PARTS_1 ON PARTS (MRP_EXCEPTIONS);
CREATE INDEX IND_PARTS_2 ON PARTS (MFG_NAME, MFG_PART_ID);
CREATE INDEX IND_PARTS_3 ON PARTS (WEIGHT_UM);
CREATE INDEX IND_PARTS_4 ON PARTS (MRP_REQUIRED);
CREATE INDEX IND_PARTS_5 ON PARTS (PREF_VENDOR_ID);
CREATE INDEX IND_PARTS_6 ON PARTS (STOCK_UM);
CREATE INDEX IND_PARTS_7 ON PARTS (ORDER_POINT);

CREATE TABLE PARTS_TEMP AS
SELECT
  *
FROM
  PARTS;

CREATE TABLE PO_HEADER (
  PURC_ORDER_ID VARCHAR2(15) NOT NULL ENABLE,
  VENDOR_ID VARCHAR2(15) NOT NULL ENABLE,
  CONTACT_FIRST_NAME VARCHAR2(30),
  CONTACT_LAST_NAME VARCHAR2(30),
  CONTACT_INITIAL VARCHAR2(2),
  CONTACT_POSITION VARCHAR2(20),
  CONTACT_HONORIFIC VARCHAR2(4),
  CONTACT_SALUTATION VARCHAR2(60),
  CONTACT_PHONE VARCHAR2(20),
  CONTACT_FAX VARCHAR2(20),
  PURC_ORD_ADDR_NO NUMBER,
  SHIPTO_ADDR_NO NUMBER,
  ORDER_DATE DATE DEFAULT SYSDATE NOT NULL ENABLE,
  DESIRED_RECV_DATE DATE DEFAULT TRUNC(SYSDATE),
  BUYER VARCHAR2(15),
  FREE_ON_BOARD VARCHAR2(25),
  SHIP_VIA VARCHAR2(40),
  SALES_TAX_GROUP_ID VARCHAR2(15),
  PO_STATUS CHAR(1) DEFAULT ' ' NOT NULL ENABLE,
  BACK_ORDER CHAR(1) DEFAULT ' ' NOT NULL ENABLE,
  SELL_RATE NUMBER(15,8) NOT NULL ENABLE,
  BUY_RATE NUMBER(15,8) NOT NULL ENABLE,
  ENTITY_ID VARCHAR2(5) NOT NULL ENABLE,
  POSTING_CANDIDATE CHAR(1) DEFAULT 'Y' NOT NULL ENABLE,
  LAST_RECEIVED_DATE DATE,
  TOTAL_AMT_ORDERED NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  TOTAL_AMT_RECVD NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  MARKED_FOR_PURGE CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  EXCH_RATE_FIXED CHAR(1) DEFAULT 'N' NOT NULL ENABLE,
  PROMISE_DATE DATE,
  PRINTED_DATE DATE,
  TERMS_DISC_TYPE CHAR(1),
  EDI_BLANKET_FLAG CHAR(1),
  EDI_BLANKET_PO_NO VARCHAR2(30),
  CONTRACT_ID VARCHAR2(30),
  SHIPTO_ID VARCHAR2(20),
  TERMS_NET_TYPE CHAR(1) DEFAULT ' ' NOT NULL ENABLE,
  TERMS_NET_DAYS NUMBER,
  TERMS_NET_DATE DATE,
  TERMS_DISC_DAYS NUMBER,
  TERMS_DISC_DATE DATE,
  TERMS_DISC_PERCENT NUMBER(5,3),
  TERMS_DESCRIPTION VARCHAR2(50),
  CURRENCY_ID VARCHAR2(15),
  WAREHOUSE_ID VARCHAR2(15),
  CREATE_DATE DATE DEFAULT SYSDATE NOT NULL ENABLE,
  CONTACT_MOBILE VARCHAR2(20),
  CONTACT_EMAIL VARCHAR2(50),
  USER_1 VARCHAR2(80),
  USER_2 VARCHAR2(80),
  USER_3 VARCHAR2(80),
  USER_4 VARCHAR2(80),
  USER_5 VARCHAR2(80),
  USER_6 VARCHAR2(80),
  USER_7 VARCHAR2(80),
  USER_8 VARCHAR2(80),
  USER_9 VARCHAR2(80),
  USER_10 VARCHAR2(80),
  UDF_LAYOUT_ID VARCHAR2(15),
  PO_CREATE_USER_ID VARCHAR2(30) DEFAULT USER,
  CONSTRAINT "CHK_PO" CHECK (
    (PO_STATUS = 'F' Or PO_STATUS = 'R' Or PO_STATUS = 'C' Or PO_STATUS = 'X')
    AND (BACK_ORDER = 'Y' Or BACK_ORDER = 'N')
    AND (POSTING_CANDIDATE = 'Y' Or POSTING_CANDIDATE = 'N')
    AND (MARKED_FOR_PURGE = 'Y' Or MARKED_FOR_PURGE = 'N')
    AND (TERMS_DISC_TYPE = 'A' Or TERMS_DISC_TYPE = 'M' Or TERMS_DISC_TYPE = 'D' Or TERMS_DISC_TYPE = 'N' Or TERMS_DISC_TYPE = 'E')
    AND (TERMS_NET_TYPE = 'A' Or TERMS_NET_TYPE = 'M' Or TERMS_NET_TYPE = 'D' Or TERMS_NET_TYPE = 'N' Or TERMS_NET_TYPE = 'E')) ENABLE,
  PRIMARY KEY (PURC_ORDER_ID));

CREATE INDEX IND_PO_HEADER_1 ON PO_HEADER (VENDOR_ID, PURC_ORD_ADDR_NO);
CREATE INDEX IND_PO_HEADER_2 ON PO_HEADER (VENDOR_ID);
CREATE INDEX IND_PO_HEADER_3 ON PO_HEADER (SHIPTO_ADDR_NO);
CREATE INDEX IND_PO_HEADER_4 ON PO_HEADER (POSTING_CANDIDATE);

CREATE TABLE PO_HEADER_TEMP AS
SELECT
  *
FROM
  PO_HEADER;

CREATE TABLE PO_LINE (
  PURC_ORDER_ID VARCHAR2(15) NOT NULL ENABLE,
  LINE_NO NUMBER NOT NULL ENABLE,
  PART_ID VARCHAR2(30),
  VENDOR_PART_ID VARCHAR2(30),
  SERVICE_ID VARCHAR2(15),
  USER_ORDER_QTY NUMBER(14,4) NOT NULL ENABLE,
  ORDER_QTY NUMBER(14,4) NOT NULL ENABLE,
  PURCHASE_UM VARCHAR2(15),
  UNIT_PRICE NUMBER(20,6) NOT NULL ENABLE,
  TRADE_DISC_PERCENT NUMBER(6,3) DEFAULT 0 NOT NULL ENABLE,
  FIXED_CHARGE NUMBER(15,2),
  EST_FREIGHT NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  GL_EXPENSE_ACCT_ID VARCHAR2(30),
  SALES_TAX_GROUP_ID VARCHAR2(15),
  PRODUCT_CODE VARCHAR2(15),
  COMMODITY_CODE VARCHAR2(15),
  DESIRED_RECV_DATE DATE,
  LINE_STATUS CHAR(1) DEFAULT ' ' NOT NULL ENABLE,
  LAST_RECEIVED_DATE DATE,
  TOTAL_ACT_FREIGHT NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  TOTAL_USR_RECD_QTY NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  TOTAL_RECEIVED_QTY NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  TOTAL_AMT_RECVD NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  TOTAL_AMT_ORDERED NUMBER(15,2) DEFAULT 0 NOT NULL ENABLE,
  MFG_NAME VARCHAR2(30),
  MFG_PART_ID VARCHAR2(30),
  PROMISE_DATE DATE,
  PIECE_COUNT NUMBER(14,4),
  LENGTH NUMBER(14,4),
  WIDTH NUMBER(14,4),
  HEIGHT NUMBER(14,4),
  DIMENSIONS_UM VARCHAR2(15),
  VAT_CODE VARCHAR2(15),
  TOTAL_DISPATCH_QTY NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  TOTAL_USR_DISP_QTY NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  MINIMUM_CHARGE NUMBER(15,2),
  LAST_DISPATCH_DATE DATE,
  EDI_BLANKET_QTY NUMBER(14,4),
  EDI_BLANKET_USRQTY NUMBER(14,4),
  EDI_ACCUM_QTY_REL NUMBER(14,4),
  EDI_ACCUM_USR_REL NUMBER(14,4),
  EDI_ACCUM_QTY_REC NUMBER(14,4),
  EDI_ACCUM_USR_REC NUMBER(14,4),
  EDI_LAST_REC_DATE DATE,
  EDI_RELEASE_NO VARCHAR2(3),
  EDI_RELEASE_DATE DATE,
  EDI_QTY_RELEASED NUMBER(14,4),
  EDI_USR_QTY_REL NUMBER(14,4),
  EDI_REQ_REL_DATE DATE,
  SHIPTO_ID VARCHAR2(20),
  WAREHOUSE_ID VARCHAR2(15),
  WIP_VAS_REQUIRED CHAR(1),
  ALLOCATED_QTY NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  FULFILLED_QTY NUMBER(14,4) DEFAULT 0 NOT NULL ENABLE,
  HTS_CODE VARCHAR2(20),
  ORIG_COUNTRY_ID VARCHAR2(15),
  USER_1 VARCHAR2(80),
  USER_2 VARCHAR2(80),
  USER_3 VARCHAR2(80),
  USER_4 VARCHAR2(80),
  USER_5 VARCHAR2(80),
  USER_6 VARCHAR2(80),
  USER_7 VARCHAR2(80),
  USER_8 VARCHAR2(80),
  USER_9 VARCHAR2(80),
  USER_10 VARCHAR2(80),
  UDF_LAYOUT_ID VARCHAR2(15),
  POL_CREATE_USER_ID VARCHAR2(30) DEFAULT USER,
  POL_CREATE_DATE DATE DEFAULT SYSDATE,
  CONSTRAINT "CHK_PO_LINE" CHECK ((LINE_STATUS = 'A' Or LINE_STATUS = 'C')) ENABLE,
  PRIMARY KEY (PURC_ORDER_ID, LINE_NO),
  CONSTRAINT "FKEY_PO_HEADER" FOREIGN KEY (PURC_ORDER_ID)
    REFERENCES PO_HEADER (PURC_ORDER_ID) ON DELETE CASCADE ENABLE,
  CONSTRAINT "FKEY_PART_ID" FOREIGN KEY (PART_ID)
    REFERENCES PARTS (PART_ID) ENABLE,
  CONSTRAINT "FKEY_PURC_UM" FOREIGN KEY (PURCHASE_UM)
   REFERENCES UMS (UNIT_OF_MEASURE) ENABLE);

CREATE INDEX IND_PO_LINE_1 ON PO_LINE (WAREHOUSE_ID);
CREATE INDEX IND_PO_LINE_2 ON PO_LINE (SERVICE_ID);
CREATE INDEX IND_PO_LINE_3 ON PO_LINE (PART_ID);
CREATE INDEX IND_PO_LINE_4 ON PO_LINE (VENDOR_PART_ID);

CREATE TABLE PO_LINE_TEMP AS
SELECT
  *
FROM
  PO_LINE;

INSERT INTO
  LOCATIONS
SELECT /*+ ORDERED */
  LOC.LOCATION_ID,
  WH.WAREHOUSE_ID,
  RPAD(WH.WAREHOUSE_ID||'-'||LOC.LOCATION_ID,60),
  DECODE(MOD(ROWNUM,5),0,'T',1,'R','F')
FROM
  (SELECT
    TRIM(TO_CHAR(ABS(ROUND(COS(ROWNUM*3.1415/180*1.2)*1000000,0))))||'LOC' LOCATION_ID,
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=200) LOC,
  (SELECT
    TRIM(TO_CHAR(ABS(ROUND(SIN(ROWNUM*3.1415/180*10.1)*1000000,0))))||'WH' WAREHOUSE_ID,
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=20) WH
WHERE
  (MOD(WH.RN,10)*20+1) <= LOC.RN;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'LOCATIONS',CASCADE=>TRUE);

INSERT INTO
  UMS
SELECT
  DECODE(ROWNUM,1,'EA',2,'PC',3,'FT',4,'METER',5,'KG',6,'CASE',7,'LBS',8,'DOZEN'),
  NULL,
  4
FROM
  DUAL
CONNECT BY
  LEVEL<=8;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'UMS',CASCADE=>TRUE);

INSERT INTO
  VENDORS_TEMP
SELECT
  TRIM(TO_CHAR(ABS(ROUND(COS(ROWNUM*3.14159265/180*51.491976)*10000000,0))))||'VEN' VENDOR_ID,
  TRIM(TO_CHAR(ABS(ROUND(COS(ROWNUM*3.1415/180*.49)*1000000,0))))||'VENDOR NAME' VENDOR_NAME,
  RPAD('ADDR_1',40) ADDR_1,
  RPAD('ADDR_2',35) ADDR_2,
  NULL ADDR_3,
  RPAD('CITY',20) CITY,
  'CA' STATE,
  LPAD(TO_CHAR(ROWNUM),6) ZIPCODE,
  'NONE' COUNTRY,
  NULL CONTACT_FIRST_NAME,
  NULL CONTACT_LAST_NAME,
  NULL CONTACT_INITIAL,
  NULL CONTACT_POSITION,
  NULL CONTACT_HONORIFIC,
  NULL CONTACT_SALUTATION,
  NULL CONTACT_PHONE,
  NULL CONTACT_FAX,
  TRIM(TO_CHAR(ABS(ROUND(COS(ROWNUM*3.1415/180*4.491976)*1000000,0))))||'VENDOR NAME' REMIT_TO_NAME,
  RPAD('ADDR_1',40) REMIT_TO_ADDR_1,
  RPAD('ADDR_2',35) REMIT_TO_ADDR_2,
  NULL REMIT_TO_ADDR_3,
  RPAD('CITY',20) REMIT_TO_CITY,
  'CA' REMIT_TO_STATE,
  LPAD(TO_CHAR(ROWNUM),6) REMIT_TO_ZIPCODE,
  'NONE' REMIT_TO_COUNTRY,
  'NONE' FREE_ON_BOARD,
  'SPECIAL DEL' SHIP_VIA,
  'UNKNOWN' BUYER,
  'N' REPORT_1099_MISC,
  DECODE(MOD(ROWNUM,6),0,'A',1,'M',2,'D',3,'N','E') TERMS_NET_TYPE,
  ROWNUM TERMS_NET_DAYS,
  NULL TERMS_NET_DATE,
  DECODE(MOD(ROWNUM,6),0,'A',1,'M',2,'D',3,'N','E') TERMS_DISC_TYPE,
  MOD(ROWNUM,100)+10 TERMS_DISC_DAYS,
  NULL TERMS_DISC_DATE,
  3.5 TERMS_DISC_PERCENT,
  'STANDARD' TERMS_DESCRIPTION,
  'X' USER_1,
  TO_CHAR(TRUNC(SYSDATE,'YYYY'),'MON DD, YYYY') USER_2,
  NULL USER_3,
  NULL USER_4,
  NULL USER_5,
  NULL USER_6,
  NULL USER_7,
  NULL USER_8,
  NULL USER_9,
  NULL USER_10
FROM
  DUAL
CONNECT BY
  LEVEL<=50000;

DELETE FROM
  VENDORS_TEMP
WHERE
  (VENDOR_ID,TERMS_NET_DAYS) IN
    (SELECT
      V.VENDOR_ID,
      V.TERMS_NET_DAYS
    FROM
      VENDORS_TEMP V,
      (SELECT
        VENDOR_ID,
        MIN(TERMS_NET_DAYS) TERMS_NET_DAYS
      FROM
        VENDORS_TEMP
      GROUP BY
        VENDOR_ID
      HAVING
        COUNT(*)>1) M
    WHERE
      V.VENDOR_ID=M.VENDOR_ID
      AND V.TERMS_NET_DAYS>M.TERMS_NET_DAYS);

INSERT INTO
  VENDORS
SELECT
  *
FROM
  VENDORS_TEMP;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'VENDORS',CASCADE=>TRUE);

INSERT INTO
  PARTS_TEMP
SELECT
  TRIM(TO_CHAR(ABS(ROUND(SIN(ROWNUM*3.14159265/180*10.191976)*10000000,0))))||'PART' PART_ID,
  TRIM(TO_CHAR(ABS(ROUND(SIN(ROWNUM*3.14159265/180*10.191976)*10000000,0))))||'DESCRIPTION' DESCRIPTION,
  DECODE(MOD(ROWNUM,20),2,'PC',3,'FT',4,'METER',5,'KG',6,'CASE',7,'LBS',8,'DOZEN','EA') STOCK_UM,
  1 PLANNING_LEADTIME,
  'M' ORDER_POLICY,
  ROWNUM ORDER_POINT,
  1 SAFETY_STOCK_QTY,
  1 FIXED_ORDER_QTY,
  1 DAYS_OF_SUPPLY,
  1 MINIMUM_ORDER_QTY,
  9999 MAXIMUM_ORDER_QTY,
  '0' ENGINEERING_MSTR,
  DECODE(MOD(ROWNUM,20),1,'SHOP',2,'OFFICE',3,'JANITOR',4,'INVENTORY',5,'INVENTORY','FG') PRODUCT_CODE,
  DECODE(MOD(ROWNUM,7),1,'SHOP',2,'OFFICE',3,'JANITOR',4,'INVENTORY',5,'INVENTORY','FG') COMMODITY_CODE,
  'UNKNOWN' MFG_NAME,
  'UNKNOWN' MFG_PART_ID,
  DECODE(MOD(ROWNUM,3),1,'Y','N') FABRICATED,
  DECODE(MOD(ROWNUM,3),1,'N','Y') PURCHASED,
  'N' STOCKED,
  'N' DETAIL_ONLY,
  'N' DEMAND_HISTORY,
  'N' TOOL_OR_FIXTURE,
  'N' INSPECTION_REQD,
  0 WEIGHT,
  DECODE(MOD(ROWNUM,20),2,'PC',3,'FT',4,'METER',5,'KG',6,'CASE',7,'LBS',8,'DOZEN','EA') WEIGHT_UM,
  NULL DRAWING_ID,
  NULL DRAWING_REV_NO,
  NULL PREF_VENDOR_ID,
  NULL PRIMARY_WHS_ID,
  NULL PRIMARY_LOC_ID,
  NULL BACKFLUSH_WHS_ID,
  NULL BACKFLUSH_LOC_ID,
  NULL INSPECT_WHS_ID,
  NULL INSPECT_LOC_ID,
  'Y' MRP_REQUIRED,
  'N' MRP_EXCEPTIONS,
  'N' PRIVATE_UM_CONV,
  'Y' AUTO_BACKFLUSH,
  NULL PLANNER_USER_ID,
  NULL BUYER_USER_ID,
  DECODE(MOD(ROWNUM,7),1,'A',2,'B',3,'B','C') ABC_CODE,
  ROWNUM-100000 ANNUAL_USAGE_QTY,
  'N' INVENTORY_LOCKED,
  0 UNIT_MATERIAL_COST,
  0 UNIT_LABOR_COST,
  0 UNIT_BURDEN_COST,
  0 UNIT_SERVICE_COST,
  0 BURDEN_PERCENT,
  0 BURDEN_PER_UNIT,
  0 PURC_BUR_PERCENT,
  0 PURC_BUR_PER_UNIT,
  0 FIXED_COST,
  0 UNIT_PRICE,
  0 NEW_MATERIAL_COST,
  0 NEW_LABOR_COST,
  0 NEW_BURDEN_COST,
  0 NEW_SERVICE_COST,
  0 NEW_BURDEN_PERCENT,
  0 NEW_BURDEN_PERUNIT,
  0 NEW_FIXED_COST,
  '1111111' MAT_GL_ACCT_ID,
  '2222222' LAB_GL_ACCT_ID,
  '3333333' BUR_GL_ACCT_ID,
  '4444444' SER_GL_ACCT_ID,
  ABS(ROUND(SIN(ROWNUM*3.14159265/180*2)*100000,3)) QTY_ON_HAND,
  ABS(ROUND(SIN(ROWNUM*3.14159265/180*2)*100000,3)) QTY_AVAILABLE_ISS,
  ABS(ROUND(SIN(ROWNUM*3.14159265/180*2)*100000,3)) QTY_AVAILABLE_MRP,
  0 QTY_ON_ORDER,
  0 QTY_IN_DEMAND,
  RPAD('USER_1',30) USER_1,
  RPAD('USER_2',30) USER_2,
  RPAD('USER_3',30) USER_3,
  NULL USER_4,
  NULL USER_5,
  NULL USER_6,
  NULL USER_7,
  NULL USER_8,
  NULL USER_9,
  NULL USER_10,
  0 LT_PLUS_DAYS,
  0 LT_MINUS_DAYS,
  'A' STATUS,
  'Y' USE_SUPPLY_BEF_LT,
  0 QTY_COMMITTED,
  'TESTING' PRT_CREATE_USER_ID,
  SYSDATE PRT_CREATE_DATE
FROM
  DUAL
CONNECT BY
  LEVEL<=100000;

DELETE FROM
  PARTS_TEMP
WHERE
  (PART_ID,ORDER_POINT) IN
    (SELECT
      V.PART_ID,
      V.ORDER_POINT
    FROM
      PARTS_TEMP V,
      (SELECT
        PART_ID,
        MIN(ORDER_POINT) ORDER_POINT
      FROM
        PARTS_TEMP
      GROUP BY
        PART_ID
      HAVING
        COUNT(*)>1) M
    WHERE
      V.PART_ID=M.PART_ID
      AND V.ORDER_POINT>M.ORDER_POINT);

INSERT INTO
  PARTS
SELECT
  *
FROM
  PARTS_TEMP;

UPDATE
  PARTS P
SET
  (PRIMARY_WHS_ID,PRIMARY_LOC_ID)=(
    SELECT
      WAREHOUSE_ID,
      LOCATION_ID
    FROM
      (SELECT
        WAREHOUSE_ID,
        LOCATION_ID,
        ROWNUM RN
      FROM
        LOCATIONS)
    WHERE
      MOD(P.ORDER_POINT,2000)=RN);

UPDATE
  PARTS
SET
  PREF_VENDOR_ID=TRIM(TO_CHAR(ABS(ROUND(COS((MOD(ROWNUM,9000)*2+1)*3.14159265/180*51.491976)*10000000,0))))||'VEN'
WHERE
  PURCHASED='Y';

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'PARTS',CASCADE=>TRUE);

INSERT INTO
  PO_HEADER_TEMP
SELECT
  'PO'||TO_CHAR(ROWNUM) PURC_ORDER_ID,
  TRIM(TO_CHAR(ABS(ROUND(COS((MOD(ROWNUM,9000)*2+1)*3.14159265/180*51.491976)*10000000,0))))||'VEN' VENDOR_ID,
  NULL CONTACT_FIRST_NAME,
  NULL CONTACT_LAST_NAME,
  NULL CONTACT_INITIAL,
  NULL CONTACT_POSITION,
  NULL CONTACT_HONORIFIC,
  NULL CONTACT_SALUTATION,
  NULL CONTACT_PHONE,
  NULL CONTACT_FAX,
  1 PURC_ORD_ADDR_NO,
  1 SHIPTO_ADDR_NO,
  TRUNC(SYSDATE-(COS(ROWNUM*3.14159265/180)*1000)) ORDER_DATE,
  TRUNC(SYSDATE-(COS(ROWNUM*3.14159265/180)*1000))+10 DESIRED_RECV_DATE,
  'MY_BUYER' BUYER,
  NULL FREE_ON_BOARD,
  'BEST WAY' SHIP_VIA,
  'REGULAR' SALES_TAX_GROUP_ID,
  DECODE(MOD(ROWNUM,6),1,'F',2,'R',3,'X','C') PO_STATUS,
  'N' BACK_ORDER,
  1 SELL_RATE,
  1 BUY_RATE,
  '1' ENTITY_ID,
  DECODE(MOD(ROWNUM,3),1,'Y','N') POSTING_CANDIDATE,
  NULL LAST_RECEIVED_DATE,
  0 TOTAL_AMT_ORDERED,
  0 TOTAL_AMT_RECVD,
  'N' MARKED_FOR_PURGE,
  'Y' EXCH_RATE_FIXED,
  TRUNC(SYSDATE-(COS(ROWNUM*3.14159265/180)*1000))+10 PROMISE_DATE,
  SYSDATE PRINTED_DATE,
  DECODE(MOD(ROWNUM,6),0,'A',1,'M',2,'D',3,'N','E') TERMS_DISC_TYPE,
  NULL EDI_BLANKET_FLAG,
  NULL EDI_BLANKET_PO_NO,
  1 CONTRACT_ID,
  1 SHIPTO_ID,
  DECODE(MOD(ROWNUM,6),0,'A',1,'M',2,'D',3,'N','E') TERMS_NET_TYPE,
  1 TERMS_NET_DAYS,
  NULL TERMS_NET_DATE,
  1 TERMS_DISC_DAYS,
  NULL TERMS_DISC_DATE,
  3 TERMS_DISC_PERCENT,
  'ON TIME' TERMS_DESCRIPTION,
  'USD' CURRENCY_ID,
  NULL WAREHOUSE_ID,
  SYSDATE CREATE_DATE,
  NULL CONTACT_MOBILE,
  NULL CONTACT_EMAIL,
  NULL USER_1,
  NULL USER_2,
  NULL USER_3,
  NULL USER_4,
  NULL USER_5,
  NULL USER_6,
  NULL USER_7,
  NULL USER_8,
  NULL USER_9,
  NULL USER_10,
  'DEFAULT' UDF_LAYOUT_ID,
  'TESTING' PO_CREATE_USER_ID
FROM
  DUAL
CONNECT BY
  LEVEL<=500000;

INSERT INTO
  PO_HEADER
SELECT
  *
FROM
  PO_HEADER_TEMP;

COMMIT;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'PO_HEADER',CASCADE=>TRUE);

INSERT INTO PO_LINE_TEMP (
  PURC_ORDER_ID,
  LINE_NO,
  PART_ID,
  VENDOR_PART_ID,
  SERVICE_ID,
  USER_ORDER_QTY,
  ORDER_QTY,
  PURCHASE_UM,
  UNIT_PRICE,
  FIXED_CHARGE,
  GL_EXPENSE_ACCT_ID,
  SALES_TAX_GROUP_ID,
  PRODUCT_CODE,
  COMMODITY_CODE,
  DESIRED_RECV_DATE,
  TRADE_DISC_PERCENT,
  EST_FREIGHT,
  LINE_STATUS,
  TOTAL_ACT_FREIGHT,
  TOTAL_USR_RECD_QTY,
  TOTAL_RECEIVED_QTY,
  TOTAL_AMT_RECVD,
  TOTAL_AMT_ORDERED,
  TOTAL_DISPATCH_QTY,
  TOTAL_USR_DISP_QTY,
  ALLOCATED_QTY,
  FULFILLED_QTY)
SELECT /*+ ORDERED */
  PURC_ORDER_ID,
  ORDER_POINT-START_LINE+1,
  PART_ID,
  PART_ID,
  NULL,
  10,
  10,
  DECODE(MOD(ROWNUM,20),2,'PC',3,'FT',4,'METER',5,'KG',6,'CASE',7,'LBS',8,'DOZEN','EA'),
  1099.99,
  0,
  NULL,
  NULL,
  PRODUCT_CODE,
  COMMODITY_CODE,
  TRUNC(SYSDATE-1000+ROWNUM/1000),
  0,
  0,
  'A',
  0,
  0,
  0,
  0,
  0,
  0,
  0,
  0,
  0
FROM
  (SELECT
    'PO'||TO_CHAR(ROWNUM) PURC_ORDER_ID,
    ROWNUM RN,
    ABS(SIN(ROWNUM*3.14159265/180))*90000 START_LINE,
    MOD(ROWNUM,50)+1 LINES
  FROM
    DUAL
  CONNECT BY
    LEVEL<=500000) POL,
  PARTS P
WHERE
  P.ORDER_POINT BETWEEN START_LINE AND (START_LINE+LINES-1);

INSERT INTO
  PO_LINE
SELECT
  *
FROM
  PO_LINE_TEMP;

COMMIT;

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

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'PO_LINE',CASCADE=>TRUE); 

The second half of the test script, where the generated data is queried, should complete much faster than the table creation portion of the script.  The buffer cache will be flushed at the start of the script, so we might be able to see how the different data access strategies (using the buffer cache or bypassing the buffer cache through direct path reads during full table scans) from previous queries will affect the performance of later queries.  While reviewing the output, watch for changes in the number of blocks read from disk, number of consistent gets, the number of rows returned, elapsed time, and wait event statistics - in some cases those values will differ even if the execution plans are identical.

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS
ALTER SESSION SET TRACEFILE_IDENTIFIER = 'SELECT_FROM_TABLES';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';
ALTER SESSION SET EVENTS '10046 TRACE NAME CONTEXT FOREVER, LEVEL 8';

SELECT
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PO_HEADER PO,
  PO_LINE POL,
  PARTS P
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM;

SELECT
  POL.PART_ID,
  P.DESCRIPTION,
  MAX(DESIRED_RECV_DATE) LAST_RECEIVE_DATE
FROM
  PO_LINE POL,
  PARTS P
WHERE
  P.PRODUCT_CODE='FG'
  AND P.ABC_CODE='C'
  AND P.PART_ID=POL.PART_ID
GROUP BY
  POL.PART_ID,
  P.DESCRIPTION;

SELECT
  PRODUCT_CODE,
  COUNT(*) PARTS_LARGE_WH
FROM
  (SELECT
    WAREHOUSE_ID
  FROM
    LOCATIONS
  GROUP BY
    WAREHOUSE_ID
  HAVING
    COUNT(*)>160) W,
  PARTS P
WHERE
  W.WAREHOUSE_ID=P.PRIMARY_WHS_ID
GROUP BY
  PRODUCT_CODE
ORDER BY
  PRODUCT_CODE;

SELECT
  COUNT(*)
FROM
  PARTS
WHERE
  QTY_ON_HAND>1000;

SELECT
  COUNT(*)
FROM
  VENDORS
WHERE
  ZIPCODE>' 44444';

SELECT
  COUNT(*)
FROM
  PO_LINE POL,
  PARTS P
WHERE
  POL.PURC_ORDER_ID BETWEEN '10000' AND '20000'
  AND POL.PART_ID=P.PART_ID;

SELECT
  PART_ID,
  ABC_CODE,
  PRODUCT_CODE,
  MAX(QTY_ON_HAND) OVER (PARTITION BY PRODUCT_CODE,ABC_CODE) MAX_QTY_PRD_ABC,
  MIN(QTY_ON_HAND) OVER (PARTITION BY PRODUCT_CODE,ABC_CODE) MIN_QTY_PRD_ABC,
  DENSE_RANK() OVER (PARTITION BY PRODUCT_CODE,ABC_CODE ORDER BY QTY_ON_HAND) DR_QTY_PRD_ABC,
  DENSE_RANK() OVER (PARTITION BY PREF_VENDOR_ID ORDER BY ORDER_POINT) DR_OP_VEND
FROM
  PARTS
ORDER BY
  PART_ID;

SELECT
  V.VENDOR_ID,
  V.VENDOR_NAME
FROM
  VENDORS V,
  (SELECT DISTINCT
    PO.VENDOR_ID
  FROM
    PO_HEADER PO,
    PO_LINE POL,
    PARTS P
  WHERE
    PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
    AND POL.PART_ID=P.PART_ID
    AND P.PRODUCT_CODE='FG') PV
WHERE
  V.VENDOR_ID=PV.VENDOR_ID(+)
  AND PV.VENDOR_ID IS NULL
ORDER BY
  V.VENDOR_ID;

SELECT
  P.PART_ID,
  P.DESCRIPTION PART_DESCRIPTION,
  P.PRIMARY_WHS_ID,
  P.PRIMARY_LOC_ID,
  U.DESCRIPTION UMS_DESCRIPTION,
  U.UOM_SCALE,
  L.DESCRIPTION LOC_DESCRIPTION,
  V.VENDOR_ID,
  V.VENDOR_NAME,
  V.ADDR_1,
  V.ADDR_2,
  V.CITY,
  V.STATE
FROM
  UMS U,
  LOCATIONS L,
  PARTS P,
  VENDORS V
WHERE
  P.PRODUCT_CODE IN ('OFFICE','SHOP')
  AND P.PURCHASED='Y'
  AND P.STOCK_UM=U.UNIT_OF_MEASURE
  AND U.UNIT_OF_MEASURE IN ('EA','PC','CASE')
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND P.PRIMARY_WHS_ID=L.WAREHOUSE_ID
  AND P.PRIMARY_LOC_ID=L.LOCATION_ID;

SELECT
  VENDOR_ID,
  PART_ID,
  DESIRED_RECV_DATE
FROM
  (SELECT
    PO.VENDOR_ID,
    POL.PART_ID,
    POL.DESIRED_RECV_DATE,
    ROW_NUMBER() OVER (PARTITION BY POL.PART_ID ORDER BY POL.DESIRED_RECV_DATE DESC) RN
  FROM
    PO_HEADER PO,
    PO_LINE POL
  WHERE
    PO.PURC_ORDER_ID=POL.PURC_ORDER_ID)
WHERE
  RN=1
ORDER BY
  PART_ID;

SELECT
  P.PART_ID,
  P.DESCRIPTION PART_DESCRIPTION,
  P.PRIMARY_WHS_ID,
  P.PRIMARY_LOC_ID,
  U.DESCRIPTION UMS_DESCRIPTION,
  U.UOM_SCALE,
  L.DESCRIPTION LOC_DESCRIPTION,
  V.VENDOR_ID,
  V.VENDOR_NAME,
  V.ADDR_1,
  V.ADDR_2,
  V.CITY,
  V.STATE,
  LV.VENDOR_ID LAST_VENDOR_ID,
  V2.VENDOR_NAME LAST_VENDOR_NAME,
  V2.STATE LAST_VENDOR_STATE,
  LV.DESIRED_RECV_DATE LAST_DES_RECV_DATE
FROM
  UMS U,
  LOCATIONS L,
  PARTS P,
  VENDORS V,
  (SELECT
    VENDOR_ID,
    PART_ID,
    DESIRED_RECV_DATE
  FROM
    (SELECT
      PO.VENDOR_ID,
      POL.PART_ID,
      POL.DESIRED_RECV_DATE,
      ROW_NUMBER() OVER (PARTITION BY POL.PART_ID ORDER BY POL.DESIRED_RECV_DATE DESC) RN
    FROM
      PO_HEADER PO,
      PO_LINE POL
    WHERE
      PO.PURC_ORDER_ID=POL.PURC_ORDER_ID)
  WHERE
    RN=1) LV,
  VENDORS V2
WHERE
  P.PRODUCT_CODE IN ('OFFICE','SHOP')
  AND P.PURCHASED='Y'
  AND P.STOCK_UM=U.UNIT_OF_MEASURE
  AND U.UNIT_OF_MEASURE IN ('EA','PC','CASE')
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND P.PRIMARY_WHS_ID=L.WAREHOUSE_ID
  AND P.PRIMARY_LOC_ID=L.LOCATION_ID
  AND P.PART_ID=LV.PART_ID
  AND LV.VENDOR_ID=V2.VENDOR_ID;

SELECT
  P.PART_ID,
  P.DESCRIPTION PART_DESCRIPTION,
  P.PRIMARY_WHS_ID,
  P.PRIMARY_LOC_ID,
  U.DESCRIPTION UMS_DESCRIPTION,
  U.UOM_SCALE,
  L.DESCRIPTION LOC_DESCRIPTION,
  V.VENDOR_ID,
  V.VENDOR_NAME,
  V.ADDR_1,
  V.ADDR_2,
  V.CITY,
  V.STATE,
  LV.VENDOR_ID LAST_VENDOR_ID,
  V2.VENDOR_NAME LAST_VENDOR_NAME,
  V2.STATE LAST_VENDOR_STATE,
  LV.DESIRED_RECV_DATE LAST_DES_RECV_DATE
FROM
  UMS U,
  LOCATIONS L,
  PARTS P,
  VENDORS V,
  (SELECT
    VENDOR_ID,
    PART_ID,
    DESIRED_RECV_DATE
  FROM
    (SELECT
      PO.VENDOR_ID,
      POL.PART_ID,
      POL.DESIRED_RECV_DATE,
      ROW_NUMBER() OVER (PARTITION BY POL.PART_ID ORDER BY POL.DESIRED_RECV_DATE DESC) RN
    FROM
      PO_HEADER PO,
      PO_LINE POL
    WHERE
      PO.PURC_ORDER_ID=POL.PURC_ORDER_ID)
  WHERE
    RN=1) LV,
  VENDORS V2
WHERE
  (P.PRODUCT_CODE NOT IN ('OFFICE','SHOP')
     OR U.UNIT_OF_MEASURE NOT IN ('EA','PC','CASE'))
  AND P.PURCHASED='Y'
  AND P.STOCK_UM=U.UNIT_OF_MEASURE
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND P.PRIMARY_WHS_ID=L.WAREHOUSE_ID
  AND P.PRIMARY_LOC_ID=L.LOCATION_ID
  AND P.PART_ID=LV.PART_ID
  AND LV.VENDOR_ID=V2.VENDOR_ID;

SELECT
  P.PART_ID,
  P.DESCRIPTION,
  P.PREF_VENDOR_ID,
  V.VENDOR_NAME PREF_VENDOR_NAME,
  PV.VENDOR_ID,
  V2.VENDOR_NAME LAST_VENDOR_NAME,
  PV.ORDER_LINES,
  PV.FIRST_RECV_DATE,
  PV.LAST_RECV_DATE
FROM
  (SELECT
    PO.VENDOR_ID,
    POL.PART_ID,
    COUNT(*) ORDER_LINES,
    MIN(POL.DESIRED_RECV_DATE) FIRST_RECV_DATE,
    MAX(POL.DESIRED_RECV_DATE) LAST_RECV_DATE
  FROM
    PO_HEADER PO,
    PO_LINE POL
  WHERE
    PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  GROUP BY
    PO.VENDOR_ID,
    POL.PART_ID) PV,
  PARTS P,
  VENDORS V,
  VENDORS V2
WHERE
  P.PART_ID=PV.PART_ID
  AND P.PREF_VENDOR_ID != PV.VENDOR_ID
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND PV.VENDOR_ID=V2.VENDOR_ID;

SELECT
  *
FROM
  PO_HEADER PO,
  PO_LINE POL,
  PARTS P,
  VENDORS V
WHERE
  PO.VENDOR_ID LIKE '100%'
  AND PO.POSTING_CANDIDATE='N'
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID BETWEEN '80' AND '999999'
  AND POL.PART_ID=P.PART_ID
  AND PO.VENDOR_ID=V.VENDOR_ID;

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

Just for fun, I also ran the test script on my laptop, which was running Oracle Database Enterprise 11.2.0.1 configured with a 12000M SGA_TARGET and a 2000M PGA_AGGREGATE_TARGET.

Simple insert into a table:

INSERT INTO
  LOCATIONS
SELECT /*+ ORDERED */
  LOC.LOCATION_ID,
  WH.WAREHOUSE_ID,
  RPAD(WH.WAREHOUSE_ID||'-'||LOC.LOCATION_ID,60),
  DECODE(MOD(ROWNUM,5),0,'T',1,'R','F')
FROM
  (SELECT
... 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.14       0.13          0        141       3259        2200
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.17       0.15          0        141       3259        2200

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1   COUNT  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1    NESTED LOOPS  (cr=0 pr=0 pw=0 time=0 us cost=4 size=72 card=1)
         1          1          1     VIEW  (cr=0 pr=0 pw=0 time=0 us cost=2 size=36 card=1)
         1          1          1      COUNT  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1       CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=0 us)
         1          1          1        FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)
         1          1          1     VIEW  (cr=0 pr=0 pw=0 time=0 us cost=2 size=36 card=1)
        10         10         10      COUNT  (cr=0 pr=0 pw=0 time=18 us)
        10         10         10       CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=18 us)
         1          1          1        FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  rdbms ipc reply                                 2        0.00          0.00
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.07          0          0          0           0
Execute      1      0.09       0.12          0        258       3443        2200
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.10       0.20          0        258       3443        2200

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
   2200  COUNT  (cr=0 pr=0 pw=0 time=116495 us)
   2200   NESTED LOOPS  (cr=0 pr=0 pw=0 time=77138 us)
    200    VIEW  (cr=0 pr=0 pw=0 time=19754 us)
    200     COUNT  (cr=0 pr=0 pw=0 time=210 us)
    200      CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=11 us)
      1       FAST DUAL  (cr=0 pr=0 pw=0 time=1 us)
   2200    VIEW  (cr=0 pr=0 pw=0 time=52757 us)
   4000     COUNT  (cr=0 pr=0 pw=0 time=691 us)
   4000      CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=593 us)
    200       FAST DUAL  (cr=0 pr=0 pw=0 time=48 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.01          0.01 

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.14          0          0          0           0
Execute      1      0.10       0.10          0        259       3434        2200
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.12       0.25          0        259       3434        2200

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
   2200  COUNT  (cr=0 pr=0 pw=0 time=101335 us)
   2200   NESTED LOOPS  (cr=0 pr=0 pw=0 time=61984 us)
    200    VIEW  (cr=0 pr=0 pw=0 time=2423 us)
    200     COUNT  (cr=0 pr=0 pw=0 time=210 us)
    200      CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=209 us)
      1       FAST DUAL  (cr=0 pr=0 pw=0 time=0 us)
   2200    VIEW  (cr=0 pr=0 pw=0 time=54837 us)
   4000     COUNT  (cr=0 pr=0 pw=0 time=693 us)
   4000      CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=620 us)
    200       FAST DUAL  (cr=0 pr=0 pw=0 time=52 us) 

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.07       0.07          0        155       3447        2200
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.10       0.10          0        155       3447        2200

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=190 pr=0 pw=0 time=0 us)
   2200   COUNT  (cr=0 pr=0 pw=0 time=76598 us)
   2200    NESTED LOOPS  (cr=0 pr=0 pw=0 time=76476 us cost=4 size=72 card=1)
    200     VIEW  (cr=0 pr=0 pw=0 time=2288 us cost=2 size=36 card=1)
    200      COUNT  (cr=0 pr=0 pw=0 time=99 us)
    200       CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=0 us)
      1        FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)
   2200     VIEW  (cr=0 pr=0 pw=0 time=69004 us cost=2 size=36 card=1)
   4000      COUNT  (cr=0 pr=0 pw=0 time=2719 us)
   4000       CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=2026 us)
    200        FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.12       0.12          0        158       3547        2200
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.15       0.14          0        158       3547        2200

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
      1   COUNT  (cr=0 pr=0 pw=0 time=0 us)
      1    NESTED LOOPS  (cr=0 pr=0 pw=0 time=0 us cost=4 size=72 card=1)
      1     VIEW  (cr=0 pr=0 pw=0 time=0 us cost=2 size=36 card=1)
      1      COUNT  (cr=0 pr=0 pw=0 time=0 us)
      1       CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=0 us)
      1        FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)
      1     VIEW  (cr=0 pr=0 pw=0 time=0 us cost=2 size=36 card=1)
     10      COUNT  (cr=0 pr=0 pw=0 time=45 us)
     10       CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=36 us)
      1        FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file sync                                   1        0.01          0.01
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Deleting from the temporary holding table for the vendors, before inserting into the VENDORS table with the constraints:

DELETE FROM
  VENDORS_TEMP
WHERE
  (VENDOR_ID,TERMS_NET_DAYS) IN
    (SELECT
      V.VENDOR_ID,
      V.TERMS_NET_DAYS
    FROM
      VENDORS_TEMP V,
      (SELECT
        VENDOR_ID,
        MIN(TERMS_NET_DAYS) TERMS_NET_DAYS
      FROM
        VENDORS_TEMP
      GROUP BY
        VENDOR_ID
      HAVING
        COUNT(*)>1) M
    WHERE
      V.VENDOR_ID=M.VENDOR_ID
      AND V.TERMS_NET_DAYS>M.TERMS_NET_DAYS) 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.03          0         16          0           0
Execute      1      0.10       0.10          0       7521        244         214
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.12       0.14          0       7537        244         214

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  DELETE  VENDORS_TEMP (cr=7521 pr=0 pw=0 time=0 us)
       214        214        214   HASH JOIN RIGHT SEMI (cr=7521 pr=0 pw=0 time=64219 us cost=603 size=2061136 card=46844)
       214        214        214    VIEW  VW_NSO_1 (cr=5014 pr=0 pw=0 time=63367 us cost=403 size=51524 card=2342)
       214        214        214     HASH JOIN  (cr=5014 pr=0 pw=0 time=63367 us cost=403 size=103048 card=2342)
       135        135        135      VIEW  (cr=2507 pr=0 pw=0 time=936392 us cost=202 size=1030568 card=46844)
       135        135        135       FILTER  (cr=2507 pr=0 pw=0 time=936392 us)
     49786      49786      49786        SORT GROUP BY (cr=2507 pr=0 pw=0 time=12670 us cost=202 size=1030568 card=46844)
     50000      50000      50000         TABLE ACCESS FULL VENDORS_TEMP (cr=2507 pr=0 pw=0 time=26597 us cost=199 size=1030568 card=46844)
     50000      50000      50000      TABLE ACCESS FULL VENDORS_TEMP (cr=2507 pr=0 pw=0 time=19820 us cost=199 size=1030568 card=46844)
     50000      50000      50000    TABLE ACCESS FULL VENDORS_TEMP (cr=2507 pr=0 pw=0 time=22250 us cost=199 size=1030568 card=46844)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.03          0         12          0           0
Execute      1      0.10       0.11          0       7554        244         214
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.14       0.14          0       7566        244         214

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  VENDORS_TEMP (cr=7554 pr=0 pw=0 time=111433 us)
    214   HASH JOIN RIGHT SEMI (cr=7554 pr=0 pw=0 time=122775 us)
    214    VIEW  VW_NSO_1 (cr=5036 pr=0 pw=0 time=104690 us)
    214     HASH JOIN  (cr=5036 pr=0 pw=0 time=104688 us)
    135      VIEW  (cr=2518 pr=0 pw=0 time=1007463 us)
    135       FILTER  (cr=2518 pr=0 pw=0 time=1007462 us)
  49786        SORT GROUP BY (cr=2518 pr=0 pw=0 time=58205 us)
  50000         TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=17 us)
  50000      TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=23 us)
  50000    TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=20 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.02          0.02 

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.05          0         12          0           0
Execute      1      0.10       0.11          0       7554        244         214
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.14       0.16          0       7566        244         214

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  VENDORS_TEMP (cr=7554 pr=0 pw=0 time=112308 us)
    214   HASH JOIN RIGHT SEMI (cr=7554 pr=0 pw=0 time=229889 us)
    214    VIEW  VW_NSO_1 (cr=5036 pr=0 pw=0 time=210415 us)
    214     HASH JOIN  (cr=5036 pr=0 pw=0 time=210414 us)
    135      VIEW  (cr=2518 pr=0 pw=0 time=1052458 us)
    135       FILTER  (cr=2518 pr=0 pw=0 time=1052458 us)
  49786        SORT GROUP BY (cr=2518 pr=0 pw=0 time=58712 us)
  50000         TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=25 us)
  50000      TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=23 us)
  50000    TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=24 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.04          0         16          0           0
Execute      1      0.10       0.11          0       7554        242         214
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.12       0.15          0       7570        242         214

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  VENDORS_TEMP (cr=7554 pr=0 pw=0 time=0 us)
    214   HASH JOIN RIGHT SEMI (cr=7554 pr=0 pw=0 time=88501 us cost=661 size=2807068 card=63797)
    214    VIEW  VW_NSO_1 (cr=5036 pr=0 pw=0 time=0 us cost=459 size=70180 card=3190)
    214     HASH JOIN  (cr=5036 pr=0 pw=0 time=0 us cost=459 size=140360 card=3190)
  50000      TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=19564 us cost=201 size=1403534 card=63797)
    135      VIEW  (cr=2518 pr=0 pw=0 time=987714 us cost=204 size=1403534 card=63797)
    135       FILTER  (cr=2518 pr=0 pw=0 time=987580 us)
  49786        SORT GROUP BY (cr=2518 pr=0 pw=0 time=12414 us cost=204 size=1403534 card=63797)
  50000         TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=25191 us cost=201 size=1403534 card=63797)
  50000    TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=18925 us cost=201 size=1403534 card=63797)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        2        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.04       0.04          0         16          0           0
Execute      1      0.10       0.10          0       7554        242         214
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.15       0.14          0       7570        242         214

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  VENDORS_TEMP (cr=7554 pr=0 pw=0 time=0 us)
    214   HASH JOIN RIGHT SEMI (cr=7554 pr=0 pw=0 time=44730 us cost=607 size=2526348 card=57417)
    214    VIEW  VW_NSO_1 (cr=5036 pr=0 pw=0 time=44623 us cost=406 size=66638 card=3029)
    214     HASH JOIN  (cr=5036 pr=0 pw=0 time=44623 us cost=406 size=133276 card=3029)
    135      VIEW  (cr=2518 pr=0 pw=0 time=934047 us cost=204 size=1263174 card=57417)
    135       FILTER  (cr=2518 pr=0 pw=0 time=934047 us)
  49786        SORT GROUP BY (cr=2518 pr=0 pw=0 time=10494 us cost=204 size=1263174 card=57417)
  50000         TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=25191 us cost=201 size=1263174 card=57417)
  50000      TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=20587 us cost=201 size=1263174 card=57417)
  50000    TABLE ACCESS FULL VENDORS_TEMP (cr=2518 pr=0 pw=0 time=18030 us cost=201 size=1263174 card=57417)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00  

Deleting from the temporary holding table for the PARTS before inserting into the PARTS table:

DELETE FROM
  PARTS_TEMP
WHERE
  (PART_ID,ORDER_POINT) IN
    (SELECT
      V.PART_ID,
      V.ORDER_POINT
    FROM
      PARTS_TEMP V,
      (SELECT
        PART_ID,
        MIN(ORDER_POINT) ORDER_POINT
      FROM
        PARTS_TEMP
      GROUP BY
        PART_ID
      HAVING
        COUNT(*)>1) M
    WHERE
      V.PART_ID=M.PART_ID
      AND V.ORDER_POINT>M.ORDER_POINT) 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.04          0         16          0           0
Execute      1      0.21       0.21          0      15028        374         306
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.28       0.26          0      15044        374         306

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  DELETE  PARTS_TEMP (cr=15035 pr=0 pw=0 time=0 us)
       306        306        306   HASH JOIN RIGHT SEMI (cr=15027 pr=0 pw=0 time=29280 us cost=1274 size=4953360 card=82556)
       306        306        306    VIEW  VW_NSO_1 (cr=10018 pr=0 pw=0 time=26535 us cost=878 size=123840 card=4128)
       306        306        306     HASH JOIN  (cr=10018 pr=0 pw=0 time=26433 us cost=878 size=247680 card=4128)
       193        193        193      VIEW  (cr=5009 pr=0 pw=0 time=2787264 us cost=398 size=2476680 card=82556)
       193        193        193       FILTER  (cr=5009 pr=0 pw=0 time=2787168 us)
     99694      99694      99694        SORT GROUP BY (cr=5009 pr=0 pw=0 time=27386 us cost=398 size=2476680 card=82556)
    100000     100000     100000         TABLE ACCESS FULL PARTS_TEMP (cr=5009 pr=0 pw=0 time=46418 us cost=395 size=2476680 card=82556)
    100000     100000     100000      TABLE ACCESS FULL PARTS_TEMP (cr=5009 pr=0 pw=0 time=30945 us cost=395 size=2476680 card=82556)
    100000     100000     100000    TABLE ACCESS FULL PARTS_TEMP (cr=5009 pr=0 pw=0 time=31713 us cost=395 size=2476680 card=82556)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        2        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.04          0         12          0           0
Execute      1      0.20       0.20          0      15120        362         306
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.20       0.25          0      15132        362         306

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  PARTS_TEMP (cr=15120 pr=0 pw=0 time=203889 us)
    306   HASH JOIN RIGHT SEMI (cr=15120 pr=0 pw=0 time=186251 us)
    306    VIEW  VW_NSO_1 (cr=10080 pr=0 pw=0 time=158060 us)
    306     HASH JOIN  (cr=10080 pr=0 pw=0 time=158059 us)
    193      VIEW  (cr=5040 pr=0 pw=0 time=2709664 us)
    193       FILTER  (cr=5040 pr=0 pw=0 time=2709471 us)
  99694        SORT GROUP BY (cr=5040 pr=0 pw=0 time=115549 us)
 100000         TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=15 us)
 100000      TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=25 us)
 100000    TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.02          0.02 

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0         12          0           0
Execute      1      0.21       0.21          0      15120        362         306
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.24       0.24          0      15132        362         306

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  PARTS_TEMP (cr=15120 pr=0 pw=0 time=218918 us)
    306   HASH JOIN RIGHT SEMI (cr=15120 pr=0 pw=0 time=201432 us)
    306    VIEW  VW_NSO_1 (cr=10080 pr=0 pw=0 time=152694 us)
    306     HASH JOIN  (cr=10080 pr=0 pw=0 time=152694 us)
 100000      TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=27 us)
    193      VIEW  (cr=5040 pr=0 pw=0 time=2975280 us)
    193       FILTER  (cr=5040 pr=0 pw=0 time=2975279 us)
  99694        SORT GROUP BY (cr=5040 pr=0 pw=0 time=113516 us)
 100000         TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=19 us)
 100000    TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=32 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.04          0         16          0           0
Execute      1      0.21       0.21          0      15081        362         306
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.24       0.25          0      15097        362         306

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  PARTS_TEMP (cr=15081 pr=0 pw=0 time=0 us)
    306   HASH JOIN RIGHT SEMI (cr=15081 pr=0 pw=0 time=15250 us cost=1289 size=5367480 card=89458)
    306    VIEW  VW_NSO_1 (cr=10054 pr=0 pw=0 time=203 us cost=891 size=134190 card=4473)
    306     HASH JOIN  (cr=10054 pr=0 pw=0 time=203 us cost=891 size=268380 card=4473)
 100000      TABLE ACCESS FULL PARTS_TEMP (cr=5027 pr=0 pw=0 time=30306 us cost=398 size=2683740 card=89458)
    193      VIEW  (cr=5027 pr=0 pw=0 time=3036768 us cost=402 size=2683740 card=89458)
    193       FILTER  (cr=5027 pr=0 pw=0 time=3036480 us)
  99694        SORT GROUP BY (cr=5027 pr=0 pw=0 time=26618 us cost=402 size=2683740 card=89458)
 100000         TABLE ACCESS FULL PARTS_TEMP (cr=5027 pr=0 pw=0 time=40536 us cost=398 size=2683740 card=89458)
 100000    TABLE ACCESS FULL PARTS_TEMP (cr=5027 pr=0 pw=0 time=34015 us cost=398 size=2683740 card=89458)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        2        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.04          0         16          0           0
Execute      1      0.21       0.20          0      15120        362         306
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.24       0.24          0      15136        362         306

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  DELETE  PARTS_TEMP (cr=15120 pr=0 pw=0 time=0 us)
    306   HASH JOIN RIGHT SEMI (cr=15120 pr=0 pw=0 time=20028 us cost=1327 size=7380240 card=123004)
    306    VIEW  VW_NSO_1 (cr=10080 pr=0 pw=0 time=19215 us cost=927 size=184500 card=6150)
    306     HASH JOIN  (cr=10080 pr=0 pw=0 time=19215 us cost=927 size=369000 card=6150)
    193      VIEW  (cr=5040 pr=0 pw=0 time=2823264 us cost=404 size=3690120 card=123004)
    193       FILTER  (cr=5040 pr=0 pw=0 time=2823264 us)
  99694        SORT GROUP BY (cr=5040 pr=0 pw=0 time=29434 us cost=404 size=3690120 card=123004)
 100000         TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=44245 us cost=398 size=3690120 card=123004)
 100000      TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=34015 us cost=398 size=3690120 card=123004)
 100000    TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=33119 us cost=398 size=3690120 card=123004)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        2        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Inserting into the PARTS table with the foreign key constraints and other constraints, as well as existing indexes:

INSERT INTO
  PARTS
SELECT
  *
FROM
  PARTS_TEMP 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          1          0           0
Execute      1     10.40      10.47          0      22215     471969       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     10.42      10.49          0      22216     471969       99694

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1   TABLE ACCESS FULL PARTS_TEMP (cr=4 pr=0 pw=0 time=0 us cost=401 size=100456986 card=82477)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  rdbms ipc reply                                 8        0.00          0.00
  asynch descriptor resize                        8        0.00          0.00
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.01          0.01  

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.01          0          1          0           0
Execute      1      3.10      11.63          0      26941     515900       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      3.10      11.64          0      26942     515900       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
  99694  TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=39 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                      7        1.01          3.35
  log file switch (checkpoint incomplete)        10        1.01          4.51
  log buffer space                                3        0.02          0.05
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.07          0.07

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          1          0           0
Execute      1      3.15       4.06          0      26675     516513       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      3.16       4.07          0      26676     516513       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
  99694  TABLE ACCESS FULL PARTS_TEMP (cr=5040 pr=0 pw=0 time=46 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log buffer space                                4        0.38          0.49
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          1          0           0
Execute      1      2.85       3.87          0      23790     513495       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      2.88       3.89          0      23791     513495       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=25258 pr=0 pw=0 time=0 us)
  99694   TABLE ACCESS FULL PARTS_TEMP (cr=5027 pr=0 pw=0 time=58484 us cost=404 size=108570084 card=89138)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log buffer space                                9        0.17          0.76
  log file sync                                   1        0.05          0.05
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          1          0           0
Execute      1      2.91       4.13          0      23688     517295       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      2.93       4.16          0      23689     517295       99694

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
      1   TABLE ACCESS FULL PARTS_TEMP (cr=4 pr=0 pw=0 time=0 us cost=407 size=149527770 card=122765)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        8        0.00          0.00
  log buffer space                               17        0.18          1.14
  log file sync                                   1        0.02          0.02
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Setting the warehouse and location for the parts in the PARTS table:

UPDATE
  PARTS P
SET
  (PRIMARY_WHS_ID,PRIMARY_LOC_ID)=(
    SELECT
      WAREHOUSE_ID,
      LOCATION_ID
    FROM
      (SELECT
        WAREHOUSE_ID,
        LOCATION_ID,
        ROWNUM RN
      FROM
        LOCATIONS)
    WHERE
      MOD(P.ORDER_POINT,2000)=RN) 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          1          0           0
Execute      1    111.50     111.65          0    2131063     220890       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    111.52     111.67          0    2131064     220890       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  UPDATE  PARTS (cr=2003912 pr=0 pw=0 time=0 us)
    205731     205731     205731   TABLE ACCESS FULL PARTS (cr=10314 pr=0 pw=0 time=233967 us cost=396 size=3436164 card=110844)
    105985     105985     105985   VIEW  (cr=2120740 pr=0 pw=0 time=0 us cost=3 size=68200 card=2200)
 233281400  233281400  233281400    COUNT  (cr=2120740 pr=0 pw=0 time=49388820 us)
 233281400  233281400  233281400     INDEX FAST FULL SCAN SYS_C0024962 (cr=2120740 pr=0 pw=0 time=27487736 us cost=3 size=41800 card=2200)(object id 82045)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.01          0.01 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          1          0           0
Execute      1    185.62     185.65          0    3273130     490125       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    185.64     185.66          0    3273131     490125       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

  Rows     Row Source Operation
  -------  ---------------------------------------------------
        0  UPDATE  PARTS (cr=1704883 pr=0 pw=0 time=96171788 us)
   291367   TABLE ACCESS FULL PARTS (cr=14687 pr=0 pw=0 time=291444 us)
   191580   VIEW  (cr=3258441 pr=0 pw=0 time=181333700 us)
421680600    COUNT  (cr=3258441 pr=0 pw=0 time=1555388 us)
421680600     INDEX FAST FULL SCAN SYS_C004567 (cr=3258441 pr=0 pw=0 time=1482697 us)(object id 47888)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                      2        0.02          0.03
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.04          0.04

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          1          0           0
Execute      1    101.22     101.26          0    1800041     223772       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    101.24     101.27          0    1800042     223772       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

  Rows     Row Source Operation
  -------  ---------------------------------------------------
        0  UPDATE  PARTS (cr=1704883 pr=0 pw=0 time=96199569 us)
   204969   TABLE ACCESS FULL PARTS (cr=10364 pr=0 pw=0 time=69 us)
   105224   VIEW  (cr=1789675 pr=0 pw=0 time=99082917 us)
231605000    COUNT  (cr=1789675 pr=0 pw=0 time=920840 us)
231605000     INDEX FAST FULL SCAN SYS_C0012074 (cr=1789675 pr=0 pw=0 time=882985 us)(object id 51693)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                      2        0.02          0.04
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          1          0           0
Execute      1    185.57     185.57          0    3300666     462095       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    185.60     185.59          0    3300667     462095       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

  Rows     Row Source Operation
  -------  ---------------------------------------------------
        0  UPDATE  PARTS (cr=1804551 pr=0 pw=0 time=0 us)
   282275   TABLE ACCESS FULL PARTS (cr=14206 pr=0 pw=0 time=358592 us cost=401 size=3466482 card=111822)
   182491   VIEW  (cr=3286458 pr=0 pw=0 time=0 us cost=3 size=68200 card=2200)
401678200    COUNT  (cr=3286458 pr=0 pw=0 time=81721128 us)
401678200     INDEX FAST FULL SCAN SYS_C009200 (cr=3286458 pr=0 pw=0 time=43336740 us cost=3 size=41800 card=2200)(object id 20300)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          1          0           0
Execute      1    199.94     199.95          0    3426213     483539       99694
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    199.97     199.98          0    3426214     483539       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

  Rows     Row Source Operation
  -------  ---------------------------------------------------
        0  UPDATE  PARTS (cr=1804577 pr=0 pw=0 time=0 us)
   289229   TABLE ACCESS FULL PARTS (cr=14581 pr=0 pw=0 time=375661 us cost=400 size=3020795 card=97445)
   189443   VIEW  (cr=3411630 pr=0 pw=0 time=0 us cost=3 size=68200 card=2200)
416977000    COUNT  (cr=3411630 pr=0 pw=0 time=86533192 us)
416977000     INDEX FAST FULL SCAN SYS_C0024649 (cr=3411630 pr=0 pw=0 time=46295536 us cost=3 size=41800 card=2200)(object id 83195)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Inserting into the header level detail table for purchase orders from the temporary holding table that was initially set up, several check constraints on this table:

INSERT INTO
  PO_HEADER
SELECT
  *
FROM
  PO_HEADER_TEMP 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          1          0           0
Execute      1     60.52      60.68          0      75970    3853984      500000
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     60.54      60.70          0      75971    3853984      500000

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1   TABLE ACCESS FULL PO_HEADER_TEMP (cr=4 pr=0 pw=0 time=0 us cost=1060 size=402093498 card=412827)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  rdbms ipc reply                                 5        0.00          0.00
  asynch descriptor resize                        5        0.00          0.00
  log file switch completion                      1        0.00          0.00
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          1          0           0
Execute      1     13.97      56.05          0      75785    3954396      500000
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     13.99      56.06          0      75786    3954396      500000

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
 500000  TABLE ACCESS FULL PO_HEADER_TEMP (cr=13190 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                     26        1.01         12.10
  log file switch (checkpoint incomplete)        55        1.01         27.12
  log buffer space                                5        0.12          0.25
  rdbms ipc reply                                34        0.00          0.00
  control file sequential read                   68        0.36          0.84
  db file sequential read                         8        0.02          0.02
  Data file init write                           44        0.01          0.13
  direct path sync                                4        0.00          0.00
  db file single write                            4        0.00          0.00
  control file parallel write                    12        0.00          0.00
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.02          0.02 

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          1          0           0
Execute      1     13.93      29.44          0      73557    3946136      500000
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     13.94      29.45          0      73558    3946136      500000

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
 500000  TABLE ACCESS FULL PO_HEADER_TEMP (cr=13190 pr=0 pw=0 time=22 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log buffer space                               44        0.99          9.17
  log file switch completion                     13        0.44          1.42
  log file switch (checkpoint incomplete)         8        1.01          3.10
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          1          0           0
Execute      1     12.71      15.53          0      72026    3962055      500000
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     12.72      15.55          0      72027    3962055      500000

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=73940 pr=0 pw=0 time=0 us)
 500000   TABLE ACCESS FULL PO_HEADER_TEMP (cr=13190 pr=0 pw=0 time=222932 us cost=1144 size=474746106 card=487419)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log buffer space                               36        0.18          2.01
  log file switch completion                      4        0.27          0.56
  log file sync                                   1        0.15          0.15
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          1          0           0
Execute      1     12.65      17.11          0      71508    3958260      500000
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     12.68      17.13          0      71509    3958260      500000

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
      1   TABLE ACCESS FULL PO_HEADER_TEMP (cr=4 pr=0 pw=0 time=0 us cost=1147 size=516390450 card=530175)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  asynch descriptor resize                        5        0.00          0.00
  log buffer space                               62        0.29          3.91
  log file switch (private strand flush incomplete)
                                                  2        0.10          0.19
  log file switch completion                      1        0.06          0.06
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00   

Inserting more than 12 million rows into a table before inserting those rows into the table with the constraints and indexes:

INSERT INTO PO_LINE_TEMP (
  PURC_ORDER_ID,
  LINE_NO,
  PART_ID,
...
  FULFILLED_QTY)
SELECT /*+ ORDERED */
  PURC_ORDER_ID,
  ORDER_POINT-START_LINE+1,
  PART_ID,
...
FROM
  (SELECT
    'PO'||TO_CHAR(ROWNUM) PURC_ORDER_ID,
    ROWNUM RN,
    ABS(SIN(ROWNUM*3.14159265/180))*90000 START_LINE,
    MOD(ROWNUM,50)+1 LINES
  FROM
    DUAL
  CONNECT BY
    LEVEL<=500000) POL,
  PARTS P
WHERE
  P.ORDER_POINT BETWEEN START_LINE AND (START_LINE+LINES-1) 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1     93.07      95.64          0    1924137    1376229    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     93.10      95.67          0    1924137    1376229    12205347

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1   COUNT  (cr=3 pr=0 pw=0 time=0 us)
         1          1          1    NESTED LOOPS  (cr=3 pr=0 pw=0 time=0 us)
         1          1          1     NESTED LOOPS  (cr=2 pr=0 pw=0 time=0 us cost=26 size=19422 card=249)
         1          1          1      VIEW  (cr=0 pr=0 pw=0 time=0 us cost=2 size=49 card=1)
         1          1          1       COUNT  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1        CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=0 us)
         1          1          1         FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)
         1          1          1      INDEX RANGE SCAN IND_PARTS_7 (cr=2 pr=0 pw=0 time=0 us cost=1 size=0 card=449)(object id 82060)
         1          1          1     TABLE ACCESS BY INDEX ROWID PARTS (cr=1 pr=0 pw=0 time=0 us cost=24 size=7221 card=249)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch (private strand flush incomplete)
                                                  2        0.00          0.01
  latch: object queue header operation            5        0.00          0.00
  log file switch completion                      4        0.04          0.09
  log buffer space                                2        1.41          1.45
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1       53.66         53.66 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.04          0          0          0           0
Execute      1     91.10     231.44          0    2573862    2165886    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     91.12     231.49          0    2573862    2165886    12205347

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
12205347  COUNT  (cr=2136585 pr=0 pw=0 time=24410743 us)
12205347   NESTED LOOPS  (cr=2136585 pr=0 pw=0 time=24425909 us)
  500000    VIEW  (cr=0 pr=0 pw=0 time=8000015 us)
  500000     COUNT  (cr=0 pr=0 pw=0 time=500012 us)
  500000      CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=500354 us)
       1       FAST DUAL  (cr=0 pr=0 pw=0 time=0 us)
12205347    TABLE ACCESS BY INDEX ROWID PARTS (cr=2136585 pr=0 pw=0 time=15311808 us)
12205347     INDEX RANGE SCAN IND_PARTS_7 (cr=532876 pr=0 pw=0 time=2172989 us)(object id 47903)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                     97        1.01         39.20
  log file switch (checkpoint incomplete)       168        1.01         95.13
  control file sequential read                  187        0.72          2.68
  db file sequential read                        22        0.06          0.12
  Data file init write                           66        0.04          0.49
  direct path sync                               11        0.00          0.00
  db file single write                           11        0.00          0.00
  control file parallel write                    33        0.00          0.00
  rdbms ipc reply                                11        0.00          0.00
  log buffer space                                2        0.48          0.56
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.04          0.04

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.04          0          0          0           0
Execute      1     88.98     142.98          4    2615674    2163468    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     89.01     143.02          4    2615674    2163468    12205347

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
12205347  COUNT  (cr=2137204 pr=4 pw=0 time=24410741 us)
12205347   NESTED LOOPS  (cr=2137204 pr=4 pw=0 time=24426124 us)
  500000    VIEW  (cr=0 pr=0 pw=0 time=8000012 us)
  500000     COUNT  (cr=0 pr=0 pw=0 time=500012 us)
  500000      CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=500341 us)
       1       FAST DUAL  (cr=0 pr=0 pw=0 time=1 us)
12205347    TABLE ACCESS BY INDEX ROWID PARTS (cr=2137204 pr=4 pw=0 time=16373725 us)
12205347     INDEX RANGE SCAN IND_PARTS_7 (cr=533368 pr=0 pw=0 time=2101123 us)(object id 51708)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                     52        1.00         14.60
  log buffer space                              118        1.00         18.55
  log file switch (checkpoint incomplete)        30        1.01         13.35
  db file sequential read                         4        0.60          1.23
  latch: object queue header operation            1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.03          0          0          0           0
Execute      1     83.00     100.61          0    2554010    2164473    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     83.03     100.65          0    2554010    2164473    12205347

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
       0  LOAD TABLE CONVENTIONAL  (cr=2555697 pr=0 pw=0 time=0 us)
12205347   COUNT  (cr=2070136 pr=0 pw=0 time=30568852 us)
12205347    NESTED LOOPS  (cr=2070136 pr=0 pw=0 time=28919458 us)
12205347     NESTED LOOPS  (cr=521689 pr=0 pw=0 time=15529864 us cost=44 size=19422 card=249)
  500000      VIEW  (cr=0 pr=0 pw=0 time=8116185 us cost=2 size=49 card=1)
  500000       COUNT  (cr=0 pr=0 pw=0 time=828383 us)
  500000        CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=744494 us)
       1         FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)
12205347      INDEX RANGE SCAN IND_PARTS_7 (cr=521689 pr=0 pw=0 time=4129164 us cost=2 size=0 card=449)(object id 20315)
12205347     TABLE ACCESS BY INDEX ROWID PARTS (cr=1548447 pr=0 pw=0 time=0 us cost=42 size=7221 card=249)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log file switch completion                      4        0.49          0.80
  log buffer space                               43        1.55         15.66
  latch: object queue header operation            1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.03          0          0          0           0
Execute      1     84.80     107.84          0    2613657    2162650    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     84.83     107.87          0    2613657    2162650    12205347

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
      1   COUNT  (cr=3 pr=0 pw=0 time=0 us)
      1    NESTED LOOPS  (cr=3 pr=0 pw=0 time=0 us)
      1     NESTED LOOPS  (cr=2 pr=0 pw=0 time=0 us cost=47 size=19422 card=249)
      1      VIEW  (cr=0 pr=0 pw=0 time=0 us cost=2 size=49 card=1)
      1       COUNT  (cr=0 pr=0 pw=0 time=0 us)
      1        CONNECT BY WITHOUT FILTERING (cr=0 pr=0 pw=0 time=0 us)
      1         FAST DUAL  (cr=0 pr=0 pw=0 time=0 us cost=2 size=0 card=1)
      1      INDEX RANGE SCAN IND_PARTS_7 (cr=2 pr=0 pw=0 time=0 us cost=2 size=0 card=449)(object id 83210)
      1     TABLE ACCESS BY INDEX ROWID PARTS (cr=1 pr=0 pw=0 time=0 us cost=45 size=7221 card=249)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log buffer space                              189        0.56         20.65
  log file switch (private strand flush incomplete)
                                                  2        0.73          0.79
  log file switch completion                      3        0.15          0.37
  latch: object queue header operation            1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00   

Inserting more than 12 million rows into a table with several foreign keys, check constraints, and indexes:

INSERT INTO
  PO_LINE
SELECT
  *
FROM
  PO_LINE_TEMP 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.01          0          1          0           0
Execute      1   1136.71    1156.64      28932    1733923  139706464    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2   1136.71    1156.66      28932    1733924  139706464    12205347

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         0          0          0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
         1          1          1   TABLE ACCESS FULL PO_LINE_TEMP (cr=4 pr=0 pw=0 time=0 us cost=20365 size=12823639038 card=11626146)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  rdbms ipc reply                               172        0.10          0.71
  asynch descriptor resize                        5        0.00          0.00
  log file switch completion                     27        0.02          0.27
  latch: object queue header operation            1        0.00          0.00
  Disk file operations I/O                      476        0.00          0.23
  control file sequential read                 3318        0.05          0.63
  db file sequential read                       696        0.07          0.40
  Data file init write                          158        0.00          0.00
  db file single write                          158        0.00          0.05
  control file parallel write                   474        0.00          0.17
  reliable message                                9        0.00          0.00
  db file scattered read                        240        0.05          0.36
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          1          0           0
Execute      1    353.56    2568.62     124584    1578922  141542735    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    353.57    2568.63     124584    1578923  141542735    12205347

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
12205347  TABLE ACCESS FULL PO_LINE_TEMP (cr=249230 pr=122013 pw=0 time=305133674 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  control file sequential read                 3043        3.50         76.00
  db file sequential read                      2991        3.22         39.92
  Data file init write                         6414        1.84         64.88
  direct path sync                              179        0.00          0.00
  db file single write                          179        0.00          0.01
  control file parallel write                   537        0.10          0.32
  rdbms ipc reply                               199        1.49          2.48
  log file switch completion                    420        1.01        262.79
  log file switch (checkpoint incomplete)      1523        1.01       1032.99
  enq: CF - contention                            2        0.36          0.42
  log buffer space                              125        1.01         62.52
  latch: object queue header operation            3        0.00          0.00
  latch: cache buffers lru chain                  2        0.00          0.00
  db file scattered read                       1098        3.99        123.07
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.02          0.02
 

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.01          0          1          0           0
Execute      1    353.09    1648.72     258026    1511940  141720375    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    353.09    1648.73     258026    1511941  141720375    12205347

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
12205347  TABLE ACCESS FULL PO_LINE_TEMP (cr=249562 pr=248589 pw=0 time=915409964 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  db file scattered read                       2055        4.47        345.49
  db file sequential read                      9591        4.02        434.71
  log buffer space                              111        1.01         46.34
  log file switch completion                    272        1.01         64.43
  log file switch (checkpoint incomplete)       169        1.01         94.82
  latch: object queue header operation            2        0.00          0.00
  rdbms ipc reply                               176        0.30          0.75
  control file sequential read                 1258        3.65         58.57
  Data file init write                         4959        1.85         69.14
  direct path sync                               74        0.00          0.00
  db file single write                           74        0.40          0.40
  control file parallel write                   222        1.19          1.90
  enq: CF - contention                           12        1.95          4.11
  buffer exterminate                            182        0.01          2.79
  latch: cache buffers lru chain                  2        0.00          0.00
  latch free                                      1        0.00          0.00
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          1          0           0
Execute      1    331.28     901.42     131243    1484367  141539241    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    331.29     901.44     131243    1484368  141539241    12205347

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
       0  LOAD TABLE CONVENTIONAL  (cr=1490464 pr=131243 pw=0 time=0 us)
12205347   TABLE ACCESS FULL PO_LINE_TEMP (cr=249198 pr=128481 pw=0 time=745579520 us cost=20775 size=14111383817 card=12793639)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  log buffer space                              522        6.87        145.23
  log file switch completion                     31        4.22         11.47
  reliable message                               20        0.38          0.38
  rdbms ipc reply                                78        1.22          1.65
  Disk file operations I/O                      176        1.20          1.60
  control file sequential read                 1218        2.85         54.69
  db file sequential read                      2895        2.72         88.80
  Data file init write                           58        1.10          1.10
  db file single write                           58        0.00          0.00
  control file parallel write                   174        0.07          0.44
  latch: redo allocation                          2        0.00          0.00
  enq: CF - contention                           12        0.83          6.59
  db file scattered read                       1046        2.71        128.56
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          1          0           0
Execute      1    327.08     777.27     260153    1483975  141436854    12205347
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    327.11     777.29     260153    1483976  141436854    12205347

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  LOAD TABLE CONVENTIONAL  (cr=0 pr=0 pw=0 time=0 us)
      1   TABLE ACCESS FULL PO_LINE_TEMP (cr=4 pr=5 pw=0 time=0 us cost=20566 size=10857297775 card=9843425)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  db file scattered read                       2055        0.82        195.44
  asynch descriptor resize                        5        0.00          0.00
  db file sequential read                     11123        0.94        222.31
  log buffer space                              115        0.38          6.49
  log file switch completion                     30        0.36          2.98
  latch: object queue header operation            1        0.00          0.00
  latch free                                      2        0.00          0.00
  reliable message                               10        0.00          0.00
  rdbms ipc reply                                29        0.09          0.15
  Disk file operations I/O                       59        0.03          0.06
  control file sequential read                  399        0.64          4.11
  Data file init write                           19        0.00          0.00
  db file single write                           19        0.00          0.00
  control file parallel write                    57        0.00          0.00
  log file sync                                   1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  SQL*Net message from client                     1        0.00          0.00   

Determining how many of each part was ordered in the last 90 days:

SELECT
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM,
  SUM(POL.ORDER_QTY) ORDER_QTY
FROM
  PO_HEADER PO,
  PO_LINE POL,
  PARTS P
WHERE
  PO.ORDER_DATE BETWEEN TRUNC(SYSDATE-90) AND TRUNC(SYSDATE)
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID=P.PART_ID
GROUP BY
  PO.VENDOR_ID,
  P.PRODUCT_CODE,
  P.STOCK_UM 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.09       0.09         28        975          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4      3.18       4.54     267202     267225          0        2245
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6      3.27       4.63     267230     268200          0        2245

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      2245       2245       2245  HASH GROUP BY (cr=267225 pr=267202 pw=0 time=132 us cost=25911 size=12588193 card=172441)
    399249     399249     399249   FILTER  (cr=267225 pr=267202 pw=0 time=3877952 us)
    399249     399249     399249    HASH JOIN  (cr=267225 pr=267202 pw=0 time=3818192 us cost=21791 size=50701858 card=694546)
     99694      99694      99694     TABLE ACCESS FULL PARTS (cr=4996 pr=4989 pw=0 time=44919 us cost=394 size=2093574 card=99694)
    399249     399249     399249     HASH JOIN  (cr=262229 pr=262213 pw=0 time=3642370 us cost=20823 size=36116392 card=694546)
     16668      16668      16668      TABLE ACCESS FULL PO_HEADER (cr=13173 pr=13163 pw=0 time=905107 us cost=1068 size=785568 card=28056)
  12205347   12205347   12205347      TABLE ACCESS FULL PO_LINE (cr=249056 pr=249050 pw=0 time=2135535 us cost=19697 size=292928328 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                         3        0.00          0.00
  db file scattered read                        172        0.00          0.32
  direct path read                              678        0.00          0.34
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                     5        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.26         26        917          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4      4.13      22.17     267421     283033          0        2245
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6      4.13      22.43     267447     283950          0        2245

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2245  HASH GROUP BY (cr=283033 pr=267421 pw=0 time=22168922 us)
  399249   FILTER  (cr=283033 pr=267421 pw=0 time=19262355 us)
  399249    HASH JOIN  (cr=283033 pr=267421 pw=0 time=19262351 us)
   99694     TABLE ACCESS FULL PARTS (cr=5040 pr=5033 pw=0 time=7895521 us)
  399249     HASH JOIN  (cr=277993 pr=262388 pw=0 time=18091601 us)
   16668      TABLE ACCESS FULL PO_HEADER (cr=17931 pr=13180 pw=0 time=1189286 us)
12205347      TABLE ACCESS FULL PO_LINE (cr=260062 pr=249208 pw=0 time=12216877 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                         8        0.04          0.17
  db file scattered read                       2148        0.06         17.70
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                    27        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.09       0.27         39        950          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4      4.05      30.56     267371     278582          0        2245
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6      4.14      30.83     267410     279532          0        2245

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2245  HASH GROUP BY (cr=278582 pr=267371 pw=0 time=30561759 us)
  399249   FILTER  (cr=278582 pr=267371 pw=0 time=14361948 us)
  399249    HASH JOIN  (cr=278582 pr=267371 pw=0 time=14361943 us)
   99694     TABLE ACCESS FULL PARTS (cr=5040 pr=5033 pw=0 time=4535877 us)
  399249     HASH JOIN  (cr=273542 pr=262338 pw=0 time=13730984 us)
   16668      TABLE ACCESS FULL PO_HEADER (cr=13190 pr=13180 pw=0 time=4023636 us)
12205347      TABLE ACCESS FULL PO_LINE (cr=260352 pr=249158 pw=0 time=12247459 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                         8        0.04          0.19
  db file scattered read                       2145        0.83         24.42
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                    27        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.07       0.16         26        948          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4      3.05      19.97     267756     267779          0        2245
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6      3.13      20.14     267782     268727          0        2245

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2245  HASH GROUP BY (cr=267779 pr=267756 pw=0 time=528 us cost=26366 size=12586733 card=172421)
  399249   FILTER  (cr=267779 pr=267756 pw=0 time=16199360 us)
  399249    HASH JOIN  (cr=267779 pr=267756 pw=0 time=16159946 us cost=22250 size=50646378 card=693786)
   99694     TABLE ACCESS FULL PARTS (cr=5027 pr=5020 pw=0 time=7047105 us cost=399 size=2093574 card=99694)
  399249     HASH JOIN  (cr=262752 pr=262736 pw=0 time=16006774 us cost=21279 size=36076872 card=693786)
   16668      TABLE ACCESS FULL PO_HEADER (cr=13190 pr=13180 pw=0 time=3079960 us cost=1148 size=784700 card=28025)
12205347      TABLE ACCESS FULL PO_LINE (cr=249562 pr=249556 pw=0 time=19074670 us cost=20073 size=292928328 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  Disk file operations I/O                        2        0.00          0.00
  db file sequential read                        10        0.02          0.15
  db file scattered read                        179        0.06          2.35
  direct path read                             1961        0.05         14.05
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                     5        0.00          0.00
 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.12       0.47         30        979          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4      2.90      19.77     267379     267391          0        2245
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6      3.02      20.24     267409     268370          0        2245

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2245  HASH GROUP BY (cr=267391 pr=267379 pw=0 time=792 us cost=26322 size=12589653 card=172461)
  399249   FILTER  (cr=267391 pr=267379 pw=0 time=15617891 us)
  399249    HASH JOIN  (cr=267391 pr=267379 pw=0 time=15576303 us cost=22201 size=50757922 card=695314)
   99694     TABLE ACCESS FULL PARTS (cr=5036 pr=5033 pw=0 time=3415029 us cost=399 size=2093574 card=99694)
  399249     HASH JOIN  (cr=262355 pr=262346 pw=0 time=15423001 us cost=21229 size=36156328 card=695314)
   16668      TABLE ACCESS FULL PO_HEADER (cr=13183 pr=13180 pw=0 time=6721890 us cost=1148 size=786436 card=28087)
12205347      TABLE ACCESS FULL PO_LINE (cr=249172 pr=249166 pw=0 time=3846626 us cost=20023 size=292928328 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  Disk file operations I/O                        2        0.00          0.00
  db file sequential read                         7        0.03          0.13
  direct path read                             2030        0.08         16.32
  asynch descriptor resize                        6        0.00          0.00
  db file scattered read                          2        0.02          0.04
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                     5        0.00          0.00   

Determining the last date each C level (defines the frequency of purchase with the purchase cost) for parts with a product code of FG:

SELECT
  POL.PART_ID,
  P.DESCRIPTION,
  MAX(DESIRED_RECV_DATE) LAST_RECEIVE_DATE
FROM
  PO_LINE POL,
  PARTS P
WHERE
  P.PRODUCT_CODE='FG'
  AND P.ABC_CODE='C'
  AND P.PART_ID=POL.PART_ID
GROUP BY
  POL.PART_ID,
  P.DESCRIPTION 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          9          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        3      4.61       5.10     249049     254052          0        1815
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      4.64       5.13     249049     254061          0        1815

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      1815       1815       1815  HASH GROUP BY (cr=254052 pr=249049 pw=0 time=388 us cost=20819 size=250514 card=4246)
      1815       1815       1815   HASH JOIN  (cr=254052 pr=249049 pw=0 time=1814 us cost=20818 size=250514 card=4246)
      4246       4246       4246    VIEW  VW_GBC_5 (cr=249056 pr=249049 pw=0 time=998 us cost=20420 size=89166 card=4246)
      4246       4246       4246     HASH GROUP BY (cr=249056 pr=249049 pw=0 time=499 us cost=20420 size=84920 card=4246)
  12205347   12205347   12205347      TABLE ACCESS FULL PO_LINE (cr=249056 pr=249049 pw=0 time=2001392 us cost=19811 size=244106940 card=12205347)
     42727      42727      42727    TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=21874 us cost=398 size=252548 card=6646)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  direct path read                               84        0.00          0.04
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     3        0.00          0.00
  SQL*Net more data to client                     7        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.02          0          9          0           0
Execute      1      0.00       0.01          0          0          0           0
Fetch        3      6.25       6.26          0     254270          0        1815
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      6.25       6.30          0     254279          0        1815

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    1815  HASH GROUP BY (cr=254270 pr=0 pw=0 time=6274965 us)
 5203352   HASH JOIN  (cr=254270 pr=0 pw=0 time=35124 us)
   42727    TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=24 us)
12205347    TABLE ACCESS FULL PO_LINE (cr=249230 pr=0 pw=0 time=19 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  SQL*Net message from client                     3        0.00          0.00
  SQL*Net more data to client                    36        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.01          0          9          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        3      6.41       9.64     109023     254220          0        1815
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      6.41       9.65     109023     254229          0        1815

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    1815  HASH GROUP BY (cr=254220 pr=109023 pw=0 time=9646123 us)
 5203352   HASH JOIN  (cr=254220 pr=109023 pw=0 time=5238045 us)
   42727    TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=26 us)
12205347    TABLE ACCESS FULL PO_LINE (cr=249180 pr=109023 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  db file sequential read                        10        0.01          0.02
  db file scattered read                        906        0.04          3.16
  SQL*Net message from client                     3        0.00          0.00
  SQL*Net more data to client                    36        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.05          1          9          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        3      4.64      17.70     249545     254589          0        1815
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      4.64      17.76     249546     254598          0        1815

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    1815  HASH GROUP BY (cr=254589 pr=249545 pw=0 time=259 us cost=21200 size=250514 card=4246)
    1815   HASH JOIN  (cr=254589 pr=249545 pw=0 time=967 us cost=21199 size=250514 card=4246)
    4246    VIEW  VW_GBC_5 (cr=249562 pr=249545 pw=0 time=1747 us cost=20796 size=89166 card=4246)
    4246     HASH GROUP BY (cr=249562 pr=249545 pw=0 time=1123 us cost=20796 size=84920 card=4246)
12205347      TABLE ACCESS FULL PO_LINE (cr=249562 pr=249545 pw=0 time=16761216 us cost=20188 size=244106940 card=12205347)
   42727    TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=24305 us cost=402 size=252548 card=6646)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  direct path read                             1955        0.05         12.83
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     3        0.00          0.00
  SQL*Net more data to client                     7        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.05          1          9          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        3      4.92      15.73     254188     254212          0        1815
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      4.92      15.79     254189     254221          0        1815

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    1815  HASH GROUP BY (cr=254212 pr=254188 pw=0 time=388 us cost=21149 size=250514 card=4246)
    1815   HASH JOIN  (cr=254212 pr=254188 pw=0 time=8465 us cost=21148 size=250514 card=4246)
    4246    VIEW  VW_GBC_5 (cr=249172 pr=249156 pw=0 time=1123 us cost=20746 size=89166 card=4246)
    4246     HASH GROUP BY (cr=249172 pr=249156 pw=0 time=374 us cost=20746 size=84920 card=4246)
12205347      TABLE ACCESS FULL PO_LINE (cr=249172 pr=249156 pw=0 time=3973985 us cost=20138 size=244106940 card=12205347)
   42727    TABLE ACCESS FULL PARTS (cr=5040 pr=5032 pw=0 time=18548 us cost=402 size=252548 card=6646)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  direct path read                             1889        0.08         10.13
  asynch descriptor resize                        4        0.00          0.00
  db file scattered read                         55        0.04          0.94
  SQL*Net message from client                     3        0.00          0.00
  SQL*Net more data to client                     7        0.00          0.00   

For those parts in warehouses with more than 160 warehouse locations, determines the number of parts with each distinct product code that resides in the warehouse: 

SELECT
  PRODUCT_CODE,
  COUNT(*) PARTS_LARGE_WH
FROM
  (SELECT
    WAREHOUSE_ID
  FROM
    LOCATIONS
  GROUP BY
    WAREHOUSE_ID
  HAVING
    COUNT(*)>160) W,
  PARTS P
WHERE
  W.WAREHOUSE_ID=P.PRIMARY_WHS_ID
GROUP BY
  PRODUCT_CODE
ORDER BY
  PRODUCT_CODE 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.04       0.04         16       5016          0           5
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.07       0.07         16       5016          0           5

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         5          5          5  SORT GROUP BY (cr=5016 pr=16 pw=0 time=0 us cost=402 size=115 card=5)
     37891      37891      37891   HASH JOIN  (cr=5016 pr=16 pw=0 time=35338 us cost=401 size=120612 card=5244)
         4          4          4    VIEW  (cr=20 pr=16 pw=0 time=6 us cost=4 size=9 card=1)
         4          4          4     FILTER  (cr=20 pr=16 pw=0 time=6 us)
        20         20         20      HASH GROUP BY (cr=20 pr=16 pw=0 time=19 us cost=4 size=9 card=1)
      2200       2200       2200       INDEX FAST FULL SCAN SYS_C0024962 (cr=20 pr=16 pw=0 time=244 us cost=3 size=19800 card=2200)(object id 82045)
     99694      99694      99694    TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=39416 us cost=396 size=1395716 card=99694)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.00          0.00
  db file scattered read                          2        0.00          0.00
  asynch descriptor resize                        1        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.09          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.04       0.09         14       5057          0           5
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.06       0.18         14       5057          0           5

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
      5  SORT GROUP BY (cr=5057 pr=14 pw=0 time=90608 us)
  36233   HASH JOIN  (cr=5057 pr=14 pw=0 time=83180 us)
      4    VIEW  (cr=17 pr=14 pw=0 time=46755 us)
      4     FILTER  (cr=17 pr=14 pw=0 time=46754 us)
     20      HASH GROUP BY (cr=17 pr=14 pw=0 time=46769 us)
   2200       INDEX FAST FULL SCAN SYS_C004567 (cr=17 pr=14 pw=0 time=25602 us)(object id 47888)
  99694    TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=18 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.02          0.02
  db file scattered read                          2        0.02          0.02
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.04       0.14         14       5057          0           5
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.06       0.16         14       5057          0           5

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
      5  SORT GROUP BY (cr=5057 pr=14 pw=0 time=147128 us)
  36229   HASH JOIN  (cr=5057 pr=14 pw=0 time=140062 us)
      4    VIEW  (cr=17 pr=14 pw=0 time=103639 us)
      4     FILTER  (cr=17 pr=14 pw=0 time=103639 us)
     20      HASH GROUP BY (cr=17 pr=14 pw=0 time=103633 us)
   2200       INDEX FAST FULL SCAN SYS_C0012074 (cr=17 pr=14 pw=0 time=58040 us)(object id 51693)
  99694    TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=20 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.01          0.01
  db file scattered read                          2        0.04          0.08
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.03          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.04       0.08         14       5045          0           5
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.06       0.11         14       5045          0           5

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      5  SORT GROUP BY (cr=5045 pr=14 pw=0 time=0 us cost=406 size=115 card=5)
  37881   HASH JOIN  (cr=5045 pr=14 pw=0 time=42870 us cost=405 size=120612 card=5244)
      4    VIEW  (cr=18 pr=14 pw=0 time=6 us cost=4 size=9 card=1)
      4     FILTER  (cr=18 pr=14 pw=0 time=3 us)
     20      HASH GROUP BY (cr=18 pr=14 pw=0 time=19 us cost=4 size=9 card=1)
   2200       INDEX FAST FULL SCAN SYS_C009200 (cr=18 pr=14 pw=0 time=0 us cost=3 size=19800 card=2200)(object id 20300)
  99694    TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=36473 us cost=400 size=1395716 card=99694)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.01          0.01
  db file scattered read                          2        0.01          0.02
  asynch descriptor resize                        1        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.03          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.04       0.06         14       5058          0           5
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.07       0.10         14       5058          0           5

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      5  SORT GROUP BY (cr=5058 pr=14 pw=0 time=0 us cost=406 size=115 card=5)
  37897   HASH JOIN  (cr=5058 pr=14 pw=0 time=31261 us cost=405 size=127328 card=5536)
      4    VIEW  (cr=18 pr=14 pw=0 time=6 us cost=4 size=9 card=1)
      4     FILTER  (cr=18 pr=14 pw=0 time=3 us)
     20      HASH GROUP BY (cr=18 pr=14 pw=0 time=19 us cost=4 size=9 card=1)
   2200       INDEX FAST FULL SCAN SYS_C0024649 (cr=18 pr=14 pw=0 time=244 us cost=3 size=19800 card=2200)(object id 83195)
  99694    TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=37368 us cost=400 size=1395716 card=99694)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.01          0.01
  db file scattered read                          2        0.00          0.00
  asynch descriptor resize                        2        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00

Simple query that finds the number of parts for which there are more than 1000 in inventory:

SELECT
  COUNT(*)
FROM
  PARTS
WHERE
  QTY_ON_HAND>1000 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.03       0.02          0       4996          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.04       0.04          0       4996          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         1          1          1  SORT AGGREGATE (cr=4996 pr=0 pw=0 time=0 us)
     98586      98586      98586   TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=29025 us cost=400 size=690879 card=98697)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.01       0.02          0       5040          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.03       0.03          0       5040          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=5040 pr=0 pw=0 time=29574 us)
  98586   TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.03       0.03          0       5040          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.03       0.03          0       5040          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=5040 pr=0 pw=0 time=30228 us)
  98586   TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.03       0.03          0       5027          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.04       0.04          0       5027          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=5027 pr=0 pw=0 time=0 us)
  98586   TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=34396 us cost=404 size=690879 card=98697)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.03       0.02          0       5040          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.04       0.04          0       5040          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=5040 pr=0 pw=0 time=0 us)
  98586   TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=29665 us cost=404 size=690879 card=98697)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00   

Simple query that determines the vendors that have a zipcode larger than 44444:

SELECT
  COUNT(*)
FROM
  VENDORS
WHERE
  ZIPCODE>' 44444' 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.01       0.05       2492       2497          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.03       0.07       2492       2497          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         1          1          1  SORT AGGREGATE (cr=2497 pr=2492 pw=0 time=0 us)
      5528       5528       5528   TABLE ACCESS FULL VENDORS (cr=2497 pr=2492 pw=0 time=376 us cost=198 size=16289 card=2327)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.00          0.00
  db file scattered read                         35        0.00          0.03
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.01       0.61       2513       2518          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.03       0.62       2513       2518          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=2518 pr=2513 pw=0 time=616794 us)
   5528   TABLE ACCESS FULL VENDORS (cr=2518 pr=2513 pw=0 time=559645 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.00          0.00
  db file scattered read                         35        0.05          0.59
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.03       0.24       2513       2518          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.04       0.25       2513       2518          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=2518 pr=2513 pw=0 time=247456 us)
   5528   TABLE ACCESS FULL VENDORS (cr=2518 pr=2513 pw=0 time=227501 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.01          0.01
  db file scattered read                         35        0.03          0.22
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.45       2500       2505          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.03       0.47       2500       2505          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=2505 pr=2500 pw=0 time=0 us)
   5528   TABLE ACCESS FULL VENDORS (cr=2505 pr=2500 pw=0 time=628 us cost=200 size=16289 card=2327)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         4        0.01          0.01
  db file scattered read                         37        0.04          0.42
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.50       2513       2518          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.01       0.52       2513       2518          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=2518 pr=2513 pw=0 time=0 us)
   5528   TABLE ACCESS FULL VENDORS (cr=2518 pr=2513 pw=0 time=502 us cost=200 size=16289 card=2327)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         1        0.00          0.00
  db file scattered read                         35        0.04          0.46
  SQL*Net message from client                     2        0.00          0.00   

Find the number of purchase order lines for purchase orders in the range from 10000 to 20000.  The query contains an unnecessary join to the PARTS table, which the optimizer should eliminate:

SELECT
  COUNT(*)
FROM
  PO_LINE POL,
  PARTS P
WHERE
  POL.PURC_ORDER_ID BETWEEN '10000' AND '20000'
  AND POL.PART_ID=P.PART_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.00          3          3          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.01       0.01          3          3          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
         1          1          1  SORT AGGREGATE (cr=3 pr=3 pw=0 time=0 us)
         0          0          0   TABLE ACCESS BY INDEX ROWID PO_LINE (cr=3 pr=3 pw=0 time=0 us cost=4 size=525 card=25)
         0          0          0    INDEX RANGE SCAN SYS_C0025101 (cr=3 pr=3 pw=0 time=0 us cost=3 size=0 card=25)(object id 82070)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         3        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.09          6          4          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.03       0.10          6          4          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=4 pr=6 pw=0 time=91072 us)
      0   TABLE ACCESS BY INDEX ROWID PO_LINE (cr=4 pr=6 pw=0 time=91066 us)
      0    INDEX RANGE SCAN SYS_C004706 (cr=4 pr=6 pw=0 time=91066 us)(object id 47913)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         2        0.04          0.05
  db file scattered read                          1        0.03          0.03
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.06          6          4          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.00       0.07          6          4          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=4 pr=6 pw=0 time=64632 us)
      0   TABLE ACCESS BY INDEX ROWID PO_LINE (cr=4 pr=6 pw=0 time=64623 us)
      0    INDEX RANGE SCAN SYS_C0012213 (cr=4 pr=6 pw=0 time=64623 us)(object id 51718)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         2        0.03          0.06
  db file scattered read                          1        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00 

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.06          7          4          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.01       0.08          7          4          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=4 pr=7 pw=0 time=0 us)
      0   TABLE ACCESS BY INDEX ROWID PO_LINE (cr=4 pr=7 pw=0 time=0 us cost=5 size=525 card=25)
      0    INDEX RANGE SCAN SYS_C009339 (cr=4 pr=7 pw=0 time=0 us cost=3 size=0 card=25)(object id 20325)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         3        0.02          0.06
  db file scattered read                          1        0.00          0.00
  SQL*Net message from client                     2        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.04          6          4          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.01       0.06          6          4          0           1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=4 pr=6 pw=0 time=0 us)
      0   TABLE ACCESS BY INDEX ROWID PO_LINE (cr=4 pr=6 pw=0 time=0 us cost=5 size=525 card=25)
      0    INDEX RANGE SCAN SYS_C0024788 (cr=4 pr=6 pw=0 time=0 us cost=3 size=0 card=25)(object id 83220)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                         2        0.01          0.01
  db file scattered read                          1        0.02          0.02
  SQL*Net message from client                     2        0.00          0.00   

Analytic example to find statistics about related parts:

SELECT
  PART_ID,
  ABC_CODE,
  PRODUCT_CODE,
  MAX(QTY_ON_HAND) OVER (PARTITION BY PRODUCT_CODE,ABC_CODE) MAX_QTY_PRD_ABC,
  MIN(QTY_ON_HAND) OVER (PARTITION BY PRODUCT_CODE,ABC_CODE) MIN_QTY_PRD_ABC,
  DENSE_RANK() OVER (PARTITION BY PRODUCT_CODE,ABC_CODE ORDER BY QTY_ON_HAND) DR_QTY_PRD_ABC,
  DENSE_RANK() OVER (PARTITION BY PREF_VENDOR_ID ORDER BY ORDER_POINT) DR_OP_VEND
FROM
  PARTS
ORDER BY
  PART_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      101      0.42       0.42          0       4996          0       99694
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      103      0.45       0.44          0       4996          0       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
     99694      99694      99694  SORT ORDER BY (cr=4996 pr=0 pw=0 time=43439 us cost=2902 size=3888066 card=99694)
     99694      99694      99694   WINDOW SORT (cr=4996 pr=0 pw=0 time=78321 us cost=2902 size=3888066 card=99694)
     99694      99694      99694    WINDOW SORT (cr=4996 pr=0 pw=0 time=89710 us cost=2902 size=3888066 card=99694)
     99694      99694      99694     TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=43511 us cost=399 size=3888066 card=99694)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     101        0.00          0.00
  SQL*Net message from client                   101        0.00          0.16
  SQL*Net more data to client                   398        0.00          0.01 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.06          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      101      0.45       0.41          0       5040          0       99694
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      103      0.46       0.47          0       5040          0       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
  99694  SORT ORDER BY (cr=5040 pr=0 pw=0 time=299155 us)
  99694   WINDOW SORT (cr=5040 pr=0 pw=0 time=217786 us)
  99694    WINDOW SORT (cr=5040 pr=0 pw=0 time=662142 us)
  99694     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=29 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     101        0.00          0.00
  SQL*Net message from client                   101        0.00          0.14
  SQL*Net more data to client                  1595        0.00          0.02

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.03          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      101      0.49       0.41          0       5040          0       99694
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      103      0.49       0.45          0       5040          0       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
  99694  SORT ORDER BY (cr=5040 pr=0 pw=0 time=295718 us)
  99694   WINDOW SORT (cr=5040 pr=0 pw=0 time=211922 us)
  99694    WINDOW SORT (cr=5040 pr=0 pw=0 time=64268 us)
  99694     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=20 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     101        0.00          0.00
  SQL*Net message from client                   101        0.00          0.14
  SQL*Net more data to client                  1595        0.00          0.02

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      101      0.40       0.41          0       5027          0       99694
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      103      0.42       0.43          0       5027          0       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
  99694  SORT ORDER BY (cr=5027 pr=0 pw=0 time=42414 us cost=2906 size=3888066 card=99694)
  99694   WINDOW SORT (cr=5027 pr=0 pw=0 time=83568 us cost=2906 size=3888066 card=99694)
  99694    WINDOW SORT (cr=5027 pr=0 pw=0 time=91758 us cost=2906 size=3888066 card=99694)
  99694     TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=51062 us cost=403 size=3888066 card=99694)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     101        0.00          0.00
  SQL*Net message from client                   101        0.00          0.16
  SQL*Net more data to client                   396        0.00          0.00 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      101      0.39       0.40          0       5040          0       99694
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      103      0.40       0.42          0       5040          0       99694

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
  99694  SORT ORDER BY (cr=5040 pr=0 pw=0 time=47668 us cost=2906 size=3888066 card=99694)
  99694   WINDOW SORT (cr=5040 pr=0 pw=0 time=83184 us cost=2906 size=3888066 card=99694)
  99694    WINDOW SORT (cr=5040 pr=0 pw=0 time=91630 us cost=2906 size=3888066 card=99694)
  99694     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=40824 us cost=403 size=3888066 card=99694)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     101        0.00          0.00
  SQL*Net message from client                   101        0.00          0.17
  SQL*Net more data to client                   398        0.00          0.00   

Query to find those vendors from which we have never ordered parts with a FG product code:

SELECT
  V.VENDOR_ID,
  V.VENDOR_NAME
FROM
  VENDORS V,
  (SELECT DISTINCT
    PO.VENDOR_ID
  FROM
    PO_HEADER PO,
    PO_LINE POL,
    PARTS P
  WHERE
    PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
    AND POL.PART_ID=P.PART_ID
    AND P.PRODUCT_CODE='FG') PV
WHERE
  V.VENDOR_ID=PV.VENDOR_ID(+)
  AND PV.VENDOR_ID IS NULL
ORDER BY
  V.VENDOR_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.04       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       43      8.65       8.76     249049     269722          0       41120
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       45      8.70       8.81     249049     269722          0       41120

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
     41120      41120      41120  MERGE JOIN ANTI (cr=269722 pr=249049 pw=0 time=34201 us cost=27359 size=1632120 card=40803)
     49786      49786      49786   SORT JOIN (cr=2497 pr=0 pw=0 time=15357 us cost=531 size=1443794 card=49786)
     49786      49786      49786    TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=13566 us cost=197 size=1443794 card=49786)
      8666       8666       8666   SORT UNIQUE (cr=267225 pr=249049 pw=0 time=0 us cost=26828 size=98813 card=8983)
      8666       8666       8666    VIEW  (cr=267225 pr=249049 pw=0 time=1529 us cost=26827 size=98813 card=8983)
      8666       8666       8666     HASH UNIQUE (cr=267225 pr=249049 pw=0 time=637 us cost=26827 size=521014 card=8983)
   9176048    9176048    9176048      HASH JOIN  (cr=267225 pr=249049 pw=0 time=7566066 us cost=26218 size=707903050 card=12205225)
     74768      74768      74768       TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=16231 us cost=395 size=338963 card=19939)
  12205347   12205347   12205347       HASH JOIN  (cr=262229 pr=249049 pw=0 time=5527253 us cost=25766 size=500419227 card=12205347)
    500000     500000     500000        TABLE ACCESS FULL PO_HEADER (cr=13173 pr=0 pw=0 time=63731 us cost=1038 size=10000000 card=500000)
  12205347   12205347   12205347        TABLE ACCESS FULL PO_LINE (cr=249056 pr=249049 pw=0 time=1461748 us cost=19651 size=256312287 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      43        0.00          0.00
  direct path read                                7        0.00          0.01
  asynch descriptor resize                        4        0.00          0.00
  SQL*Net message from client                    43        0.00          0.02
  SQL*Net more data to client                   124        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.09          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       43      8.01       8.01          0     269978          0       41120
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       45      8.01       8.11          0     269978          0       41120

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
   41120  MERGE JOIN ANTI (cr=269978 pr=0 pw=0 time=7967223 us)
   49786   SORT JOIN (cr=2518 pr=0 pw=0 time=17624 us)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=20 us)
    8666   SORT UNIQUE (cr=267460 pr=0 pw=0 time=7964103 us)
    8666    VIEW  (cr=267460 pr=0 pw=0 time=7943712 us)
    8666     HASH UNIQUE (cr=267460 pr=0 pw=0 time=7943710 us)
 9176048      HASH JOIN  (cr=267460 pr=0 pw=0 time=218654 us)
   74768       TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=25 us)
12205347       HASH JOIN  (cr=262420 pr=0 pw=0 time=186465 us)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=23 us)
12205347        TABLE ACCESS FULL PO_LINE (cr=249230 pr=0 pw=0 time=22 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      43        0.00          0.00
  SQL*Net message from client                    43        0.00          0.02
  SQL*Net more data to client                   610        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.04          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       43      8.48      11.12     109794     269928          0       41120
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       45      8.50      11.16     109794     269928          0       41120

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
   41120  MERGE JOIN ANTI (cr=269928 pr=109794 pw=0 time=11070193 us)
   49786   SORT JOIN (cr=2518 pr=0 pw=0 time=17744 us)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=20 us)
    8666   SORT UNIQUE (cr=267410 pr=109794 pw=0 time=11066943 us)
    8666    VIEW  (cr=267410 pr=109794 pw=0 time=11046105 us)
    8666     HASH UNIQUE (cr=267410 pr=109794 pw=0 time=11046103 us)
 9176048      HASH JOIN  (cr=267410 pr=109794 pw=0 time=221402 us)
   74768       TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=24 us)
12205347       HASH JOIN  (cr=262370 pr=109794 pw=0 time=188692 us)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=21 us)
12205347        TABLE ACCESS FULL PO_LINE (cr=249180 pr=109794 pw=0 time=20 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      43        0.00          0.00
  db file sequential read                       196        0.03          0.11
  db file scattered read                        941        0.04          2.61
  SQL*Net message from client                    43        0.00          0.01
  SQL*Net more data to client                   610        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       43      8.33      17.85     249545     270284          0       41120
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       45      8.39      17.91     249545     270284          0       41120

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
   41120  MERGE JOIN ANTI (cr=270284 pr=249545 pw=0 time=29462 us cost=27821 size=1632120 card=40803)
   49786   SORT JOIN (cr=2505 pr=0 pw=0 time=12798 us cost=533 size=1443794 card=49786)
   49786    TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=14589 us cost=199 size=1443794 card=49786)
    8666   SORT UNIQUE (cr=267779 pr=249545 pw=0 time=0 us cost=27288 size=98813 card=8983)
    8666    VIEW  (cr=267779 pr=249545 pw=0 time=2293 us cost=27287 size=98813 card=8983)
    8666     HASH UNIQUE (cr=267779 pr=249545 pw=0 time=1146 us cost=27287 size=521014 card=8983)
 9176048      HASH JOIN  (cr=267779 pr=249545 pw=0 time=21976024 us cost=26678 size=707903050 card=12205225)
   74768       TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=19426 us cost=399 size=338963 card=19939)
12205347       HASH JOIN  (cr=262752 pr=249545 pw=0 time=18076660 us cost=26222 size=500419227 card=12205347)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=63347 us cost=1118 size=10000000 card=500000)
12205347        TABLE ACCESS FULL PO_LINE (cr=249562 pr=249545 pw=0 time=14012692 us cost=20028 size=256312287 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      43        0.00          0.00
  direct path read                             1950        0.05          9.21
  asynch descriptor resize                        4        0.00          0.00
  SQL*Net message from client                    43        0.00          0.03

  SQL*Net more data to client                   124        0.00          0.00
 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.04       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       43      8.62      17.57     262329     269920          0       41120
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       45      8.67      17.62     262329     269920          0       41120

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
   41120  MERGE JOIN ANTI (cr=269920 pr=262329 pw=0 time=30486 us cost=27771 size=1632120 card=40803)
   49786   SORT JOIN (cr=2518 pr=0 pw=0 time=14206 us cost=533 size=1443794 card=49786)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=16125 us cost=199 size=1443794 card=49786)
    8666   SORT UNIQUE (cr=267402 pr=262329 pw=0 time=0 us cost=27238 size=98813 card=8983)
    8666    VIEW  (cr=267402 pr=262329 pw=0 time=2038 us cost=27237 size=98813 card=8983)
    8666     HASH UNIQUE (cr=267402 pr=262329 pw=0 time=1146 us cost=27237 size=521014 card=8983)
 9176048      HASH JOIN  (cr=267402 pr=262329 pw=0 time=13292648 us cost=26628 size=707903050 card=12205225)
   74768       TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=19554 us cost=399 size=338963 card=19939)
12205347       HASH JOIN  (cr=262362 pr=262329 pw=0 time=6456142 us cost=26172 size=500419227 card=12205347)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=13173 pw=0 time=3462112 us cost=1118 size=10000000 card=500000)
12205347        TABLE ACCESS FULL PO_LINE (cr=249172 pr=249156 pw=0 time=2428525 us cost=19977 size=256312287 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      43        0.00          0.00
  db file scattered read                        120        0.10          2.49
  direct path read                             1218        0.07          6.37
  asynch descriptor resize                        4        0.00          0.00
  SQL*Net message from client                    43        0.00          0.02
  SQL*Net more data to client                   124        0.00          0.00   

Determine the storage location and preferred vendor for all office and shop products that have a unit of measure that is EA, PC, or CASE:

SELECT
  P.PART_ID,
  P.DESCRIPTION PART_DESCRIPTION,
  P.PRIMARY_WHS_ID,
  P.PRIMARY_LOC_ID,
  U.DESCRIPTION UMS_DESCRIPTION,
  U.UOM_SCALE,
  L.DESCRIPTION LOC_DESCRIPTION,
  V.VENDOR_ID,
  V.VENDOR_NAME,
  V.ADDR_1,
  V.ADDR_2,
  V.CITY,
  V.STATE
FROM
  UMS U,
  LOCATIONS L,
  PARTS P,
  VENDORS V
WHERE
  P.PRODUCT_CODE IN ('OFFICE','SHOP')
  AND P.PURCHASED='Y'
  AND P.STOCK_UM=U.UNIT_OF_MEASURE
  AND U.UNIT_OF_MEASURE IN ('EA','PC','CASE')
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND P.PRIMARY_WHS_ID=L.WAREHOUSE_ID
  AND P.PRIMARY_LOC_ID=L.LOCATION_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.04       0.04          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        8      0.06       0.06         31       7534          0        6647
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       10      0.10       0.10         31       7534          0        6647

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      6647       6647       6647  HASH JOIN  (cr=7534 pr=31 pw=0 time=9643 us cost=602 size=720148 card=2518)
      6647       6647       6647   HASH JOIN  (cr=5030 pr=31 pw=0 time=28501 us cost=404 size=392808 card=2518)
      2200       2200       2200    TABLE ACCESS FULL LOCATIONS (cr=31 pr=29 pw=0 time=366 us cost=4 size=176000 card=2200)
      6647       6647       6647    HASH JOIN  (cr=4999 pr=2 pw=0 time=26328 us cost=399 size=191368 card=2518)
         3          3          3     TABLE ACCESS FULL UMS (cr=3 pr=2 pw=0 time=0 us cost=2 size=21 card=3)
      6647       6647       6647     TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=23900 us cost=397 size=463335 card=6715)
     49786      49786      49786   TABLE ACCESS FULL VENDORS (cr=2504 pr=0 pw=0 time=16808 us cost=197 size=6472180 card=49786)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       8        0.00          0.00
  db file sequential read                         3        0.00          0.00
  db file scattered read                          4        0.00          0.00
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     8        0.00          0.01
  SQL*Net more data to client                   108        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.11          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        8      0.06       0.12         31       7602          0        6647
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       10      0.09       0.23         31       7602          0        6647

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
   6647  HASH JOIN  (cr=7602 pr=31 pw=0 time=96852 us)
   6647   HASH JOIN  (cr=5077 pr=31 pw=0 time=88946 us)
   2200    TABLE ACCESS FULL LOCATIONS (cr=31 pr=29 pw=0 time=16541 us)
   6647    HASH JOIN  (cr=5046 pr=2 pw=0 time=49703 us)
      3     INLIST ITERATOR  (cr=6 pr=2 pw=0 time=22888 us)
      3      TABLE ACCESS BY INDEX ROWID UMS (cr=6 pr=2 pw=0 time=22913 us)
      3       INDEX UNIQUE SCAN SYS_C004571 (cr=3 pr=1 pw=0 time=332 us)(object id 47891)
   6647     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=26601 us)
  49786   TABLE ACCESS FULL VENDORS (cr=2525 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       8        0.00          0.00
  db file sequential read                         3        0.02          0.03
  db file scattered read                          4        0.01          0.01
  SQL*Net message from client                     8        0.00          0.01
  SQL*Net more data to client                   455        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        8      0.06       0.14         31       7602          0        6647
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       10      0.12       0.19         31       7602          0        6647

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
   6647  HASH JOIN  (cr=7602 pr=31 pw=0 time=106066 us)
   6647   HASH JOIN  (cr=5077 pr=31 pw=0 time=98872 us)
   2200    TABLE ACCESS FULL LOCATIONS (cr=31 pr=29 pw=0 time=23994 us)
   6647    HASH JOIN  (cr=5046 pr=2 pw=0 time=30133 us)
      3     INLIST ITERATOR  (cr=6 pr=2 pw=0 time=10008 us)
      3      TABLE ACCESS BY INDEX ROWID UMS (cr=6 pr=2 pw=0 time=9997 us)
      3       INDEX UNIQUE SCAN SYS_C0012078 (cr=3 pr=1 pw=0 time=2124 us)(object id 51696)
   6647     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=19957 us)
  49786   TABLE ACCESS FULL VENDORS (cr=2525 pr=0 pw=0 time=19 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       8        0.00          0.00
  db file sequential read                         3        0.02          0.03
  db file scattered read                          4        0.02          0.03
  SQL*Net message from client                     8        0.00          0.01
  SQL*Net more data to client                   454        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.04          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        8      0.04       0.12         31       7573          0        6647
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       10      0.07       0.16         31       7573          0        6647

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
   6647  HASH JOIN  (cr=7573 pr=31 pw=0 time=6124 us cost=608 size=712426 card=2491)
   6647   HASH JOIN  (cr=5061 pr=31 pw=0 time=33102 us cost=408 size=388596 card=2491)
   2200    TABLE ACCESS FULL LOCATIONS (cr=31 pr=29 pw=0 time=244 us cost=4 size=176000 card=2200)
   6647    HASH JOIN  (cr=5030 pr=2 pw=0 time=30801 us cost=403 size=189316 card=2491)
      3     INLIST ITERATOR  (cr=3 pr=2 pw=0 time=32 us)
      3      TABLE ACCESS BY INDEX ROWID UMS (cr=3 pr=2 pw=0 time=0 us cost=2 size=21 card=3)
      3       INDEX UNIQUE SCAN SYS_C009204 (cr=2 pr=1 pw=0 time=0 us cost=1 size=0 card=3)(object id 20303)
   6647     TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=28245 us cost=401 size=458367 card=6643)
  49786   TABLE ACCESS FULL VENDORS (cr=2512 pr=0 pw=0 time=18091 us cost=199 size=6472180 card=49786)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       8        0.00          0.00
  db file sequential read                         3        0.01          0.01
  db file scattered read                          4        0.02          0.04
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     8        0.00          0.01
  SQL*Net more data to client                   109        0.00          0.00  

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.04       0.04          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        8      0.06       0.12         31       7598          0        6647
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       10      0.10       0.17         31       7598          0        6647

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
   6647  HASH JOIN  (cr=7598 pr=31 pw=0 time=8470 us cost=608 size=710424 card=2484)
   6647   HASH JOIN  (cr=5074 pr=31 pw=0 time=32974 us cost=408 size=387504 card=2484)
   2200    TABLE ACCESS FULL LOCATIONS (cr=31 pr=29 pw=0 time=122 us cost=4 size=176000 card=2200)
   6647    HASH JOIN  (cr=5043 pr=2 pw=0 time=29140 us cost=403 size=188784 card=2484)
      3     INLIST ITERATOR  (cr=3 pr=2 pw=0 time=34 us)
      3      TABLE ACCESS BY INDEX ROWID UMS (cr=3 pr=2 pw=0 time=0 us cost=2 size=21 card=3)
      3       INDEX UNIQUE SCAN SYS_C0024653 (cr=2 pr=1 pw=0 time=0 us cost=1 size=0 card=3)(object id 83198)
   6647     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=26328 us cost=401 size=456987 card=6623)
  49786   TABLE ACCESS FULL VENDORS (cr=2524 pr=0 pw=0 time=21299 us cost=199 size=6472180 card=49786)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       8        0.00          0.00
  db file sequential read                         3        0.01          0.01
  db file scattered read                          4        0.02          0.05
  asynch descriptor resize                        3        0.00          0.00
  SQL*Net message from client                     8        0.00          0.01
  SQL*Net more data to client                   109        0.00          0.00   

Locating the most recent vendor for each part:

SELECT
  VENDOR_ID,
  PART_ID,
  DESIRED_RECV_DATE
FROM
  (SELECT
    PO.VENDOR_ID,
    POL.PART_ID,
    POL.DESIRED_RECV_DATE,
    ROW_NUMBER() OVER (PARTITION BY POL.PART_ID ORDER BY POL.DESIRED_RECV_DATE DESC) RN
  FROM
    PO_HEADER PO,
    PO_LINE POL
  WHERE
    PO.PURC_ORDER_ID=POL.PURC_ORDER_ID)
WHERE
  RN=1
ORDER BY
  PART_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6     25.44      25.67     252854     262229         63        4246
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8     25.45      25.69     252854     262229         63        4246

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      4246       4246       4246  VIEW  (cr=262229 pr=252854 pw=3805 time=837165 us cost=150135 size=585856656 card=12205347)
    519965     519965     519965   WINDOW SORT PUSHED RANK (cr=262229 pr=252854 pw=3805 time=844973 us cost=150135 size=598062003 card=12205347)
  12205347   12205347   12205347    HASH JOIN  (cr=262229 pr=249049 pw=0 time=6314575 us cost=27081 size=598062003 card=12205347)
    500000     500000     500000     TABLE ACCESS FULL PO_HEADER (cr=13173 pr=0 pw=0 time=61684 us cost=1038 size=10000000 card=500000)
  12205347   12205347   12205347     TABLE ACCESS FULL PO_LINE (cr=249056 pr=249049 pw=0 time=1914609 us cost=19811 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  direct path read                                8        0.05          0.06
  Disk file operations I/O                        1        0.00          0.00
  asynch descriptor resize                        4        0.00          0.00
  direct path write temp                          1        0.00          0.00
  direct path read temp                         128        0.00          0.08
  SQL*Net message from client                     6        0.00          0.00
  SQL*Net more data to client                    13        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.03          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6     27.79      28.59       3624     262420        112        4246
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8     27.79      28.62       3624     262420        112        4246

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    4246  VIEW  (cr=262420 pr=3624 pw=3622 time=28575597 us)
    8895   WINDOW SORT PUSHED RANK (cr=262420 pr=3624 pw=3622 time=28491688 us)
12205347    HASH JOIN  (cr=262420 pr=0 pw=0 time=174567 us)
  500000     TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=28 us)
12205347     TABLE ACCESS FULL PO_LINE (cr=249230 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  db file sequential read                         2        0.00          0.00
  local write wait                               78        0.00          0.01
  direct path read temp                          98        0.03          0.49
  SQL*Net message from client                     6        0.00          0.00
  SQL*Net more data to client                    68        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6     28.92      30.65     116653     262370         59        4246
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8     28.93      30.66     116653     262370         59        4246

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    4246  VIEW  (cr=262370 pr=116653 pw=3563 time=30646863 us)
    8928   WINDOW SORT PUSHED RANK (cr=262370 pr=116653 pw=3563 time=30551159 us)
12205347    HASH JOIN  (cr=262370 pr=113090 pw=0 time=176948 us)
  500000     TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=29 us)
12205347     TABLE ACCESS FULL PO_LINE (cr=249180 pr=113090 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  db file sequential read                       222        0.01          0.23
  db file scattered read                       1229        0.04          1.31
  i/o slave wait                                163        0.03          0.36
  direct path write temp                          3        0.00          0.00
  direct path read temp                         118        0.03          0.30
  SQL*Net message from client                     6        0.00          0.00
  SQL*Net more data to client                    68        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6     27.33      31.14     253289     262752        116        4246
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8     27.34      31.16     253289     262752        116        4246

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    4246  VIEW  (cr=262752 pr=253289 pw=3742 time=659004 us cost=150591 size=585856656 card=12205347)
  511557   WINDOW SORT PUSHED RANK (cr=262752 pr=253289 pw=3742 time=1603029 us cost=150591 size=598062003 card=12205347)
12205347    HASH JOIN  (cr=262752 pr=249545 pw=0 time=8244288 us cost=27537 size=598062003 card=12205347)
  500000     TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=66035 us cost=1118 size=10000000 card=500000)
12205347     TABLE ACCESS FULL PO_LINE (cr=249562 pr=249545 pw=0 time=3445861 us cost=20188 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  direct path read                              157        0.04          1.88
  Disk file operations I/O                        1        0.00          0.00
  db file sequential read                         2        0.03          0.05
  local write wait                               81        0.00          0.01
  asynch descriptor resize                        4        0.00          0.00
  direct path read temp                         102        0.03          0.50
  SQL*Net message from client                     6        0.00          0.00
  SQL*Net more data to client                    13        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6     26.52      30.65     252898     262362         62        4246
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8     26.55      30.68     252898     262362         62        4246

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
   4246  VIEW  (cr=262362 pr=252898 pw=3742 time=655016 us cost=150541 size=585856656 card=12205347)
  511304   WINDOW SORT PUSHED RANK (cr=262362 pr=252898 pw=3742 time=699361 us cost=150541 size=598062003 card=12205347)
12205347    HASH JOIN  (cr=262362 pr=249156 pw=0 time=10892972 us cost=27487 size=598062003 card=12205347)
  500000     TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=67570 us cost=1118 size=10000000 card=500000)
 12205347     TABLE ACCESS FULL PO_LINE (cr=249172 pr=249156 pw=0 time=6413774 us cost=20138 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  direct path read                              218        0.06          3.72
  Disk file operations I/O                        1        0.00          0.00
  asynch descriptor resize                        4        0.00          0.00
  direct path write temp                          2        0.00          0.01
  direct path read temp                         126        0.04          0.44
  SQL*Net message from client                     6        0.00          0.00
  SQL*Net more data to client                    13        0.00          0.00   

Comparing the most recent vendor for each part with the expected vendor for each purchased part that has either an OFFICE or SHOP product code:

SELECT
  P.PART_ID,
  P.DESCRIPTION PART_DESCRIPTION,
  P.PRIMARY_WHS_ID,
  P.PRIMARY_LOC_ID,
  U.DESCRIPTION UMS_DESCRIPTION,
  U.UOM_SCALE,
  L.DESCRIPTION LOC_DESCRIPTION,
  V.VENDOR_ID,
  V.VENDOR_NAME,
  V.ADDR_1,
  V.ADDR_2,
  V.CITY,
  V.STATE,
  LV.VENDOR_ID LAST_VENDOR_ID,
  V2.VENDOR_NAME LAST_VENDOR_NAME,
  V2.STATE LAST_VENDOR_STATE,
  LV.DESIRED_RECV_DATE LAST_DES_RECV_DATE
FROM
  UMS U,
  LOCATIONS L,
  PARTS P,
  VENDORS V,
  (SELECT
    VENDOR_ID,
    PART_ID,
    DESIRED_RECV_DATE
  FROM
    (SELECT
      PO.VENDOR_ID,
      POL.PART_ID,
      POL.DESIRED_RECV_DATE,
      ROW_NUMBER() OVER (PARTITION BY POL.PART_ID ORDER BY POL.DESIRED_RECV_DATE DESC) RN
    FROM
      PO_HEADER PO,
      PO_LINE POL
    WHERE
      PO.PURC_ORDER_ID=POL.PURC_ORDER_ID)
  WHERE
    RN=1) LV,
  VENDORS V2
WHERE
  P.PRODUCT_CODE IN ('OFFICE','SHOP')
  AND P.PURCHASED='Y'
  AND P.STOCK_UM=U.UNIT_OF_MEASURE
  AND U.UNIT_OF_MEASURE IN ('EA','PC','CASE')
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND P.PRIMARY_WHS_ID=L.WAREHOUSE_ID
  AND P.PRIMARY_LOC_ID=L.LOCATION_ID
  AND P.PART_ID=LV.PART_ID
  AND LV.VENDOR_ID=V2.VENDOR_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.39       0.39          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2     25.56      25.78     252854     272253         63         278
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4     25.95      26.18     252854     272253         63         278

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
       278        278        278  HASH JOIN  (cr=272253 pr=252854 pw=3805 time=535302 us cost=165495 size=1675035600 card=4576600)
      2200       2200       2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=488 us cost=4 size=176000 card=2200)
       278        278        278   HASH JOIN  (cr=272222 pr=252854 pw=3805 time=535164 us cost=165469 size=1308907600 card=4576600)
     49786      49786      49786    TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=13822 us cost=197 size=1593152 card=49786)
       278        278        278    HASH JOIN  (cr=269725 pr=252854 pw=3805 time=534887 us cost=150791 size=1162456400 card=4576600)
      6647       6647       6647     HASH JOIN  (cr=7496 pr=0 pw=0 time=5879 us cost=598 size=518708 card=2518)
      6647       6647       6647      HASH JOIN  (cr=4999 pr=0 pw=0 time=25689 us cost=399 size=191368 card=2518)
         3          3          3       TABLE ACCESS FULL UMS (cr=3 pr=0 pw=0 time=2 us cost=2 size=21 card=3)
      6647       6647       6647       TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=23261 us cost=397 size=463335 card=6715)
     49786      49786      49786      TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=14717 us cost=197 size=6472180 card=49786)
      4246       4246       4246     VIEW  (cr=262229 pr=252854 pw=3805 time=777459 us cost=150135 size=585856656 card=12205347)
    519965     519965     519965      WINDOW SORT PUSHED RANK (cr=262229 pr=252854 pw=3805 time=786536 us cost=150135 size=598062003 card=12205347)
  12205347   12205347   12205347       HASH JOIN  (cr=262229 pr=249049 pw=0 time=6259791 us cost=27081 size=598062003 card=12205347)
    500000     500000     500000        TABLE ACCESS FULL PO_HEADER (cr=13173 pr=0 pw=0 time=61812 us cost=1038 size=10000000 card=500000)
  12205347   12205347   12205347        TABLE ACCESS FULL PO_LINE (cr=249056 pr=249049 pw=0 time=1906545 us cost=19811 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  asynch descriptor resize                        9        0.00          0.00
  direct path read                                7        0.00          0.01
  direct path write temp                          1        0.00          0.00
  direct path read temp                         100        0.00          0.06
  SQL*Net message from client                     2        0.00          0.00
  SQL*Net more data to client                     6        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.60       0.81          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2     28.04      28.91       3622     272533         60         278
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4     28.65      29.73       3622     272533         60         278

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
     278  HASH JOIN  (cr=272533 pr=3622 pw=3622 time=28652546 us)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=35 us)
     278   HASH JOIN  (cr=272502 pr=3622 pw=3622 time=28651159 us)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=13 us)
     278    HASH JOIN  (cr=269984 pr=3622 pw=3622 time=28629675 us)
    6647     HASH JOIN  (cr=7564 pr=0 pw=0 time=38331 us)
    6647      HASH JOIN  (cr=5046 pr=0 pw=0 time=26841 us)
       3       INLIST ITERATOR  (cr=6 pr=0 pw=0 time=47 us)
       3        TABLE ACCESS BY INDEX ROWID UMS (cr=6 pr=0 pw=0 time=38 us)
       3         INDEX UNIQUE SCAN SYS_C004571 (cr=3 pr=0 pw=0 time=15 us)(object id 47891)
    6647       TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=26610 us)
   49786      TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=24 us)
    4246     VIEW  (cr=262420 pr=3622 pw=3622 time=28787059 us)
    8895      WINDOW SORT PUSHED RANK (cr=262420 pr=3622 pw=3622 time=28681926 us)
12205347       HASH JOIN  (cr=262420 pr=0 pw=0 time=178699 us)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=24 us)
12205347        TABLE ACCESS FULL PO_LINE (cr=249230 pr=0 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  direct path write temp                          1        0.00          0.00
  direct path read temp                         119        0.04          0.78
  SQL*Net message from client                     2        0.00          0.00
  SQL*Net more data to client                    25        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.73       1.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2     28.71      30.86     116593     272483         59         278
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4     29.45      31.89     116593     272483         59         278

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
     278  HASH JOIN  (cr=272483 pr=116593 pw=3563 time=30547001 us)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=32 us)
     278   HASH JOIN  (cr=272452 pr=116593 pw=3563 time=30545857 us)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=13 us)
     278    HASH JOIN  (cr=269934 pr=116593 pw=3563 time=30524105 us)
    6647     HASH JOIN  (cr=7564 pr=0 pw=0 time=31940 us)
    6647      HASH JOIN  (cr=5046 pr=0 pw=0 time=20180 us)
       3       INLIST ITERATOR  (cr=6 pr=0 pw=0 time=46 us)
       3        TABLE ACCESS BY INDEX ROWID UMS (cr=6 pr=0 pw=0 time=37 us)
       3         INDEX UNIQUE SCAN SYS_C0012078 (cr=3 pr=0 pw=0 time=16 us)(object id 51696)
    6647       TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=19965 us)
   49786      TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=22 us)
    4246     VIEW  (cr=262370 pr=116593 pw=3563 time=30599938 us)
    8928      WINDOW SORT PUSHED RANK (cr=262370 pr=116593 pw=3563 time=30473211 us)
12205347       HASH JOIN  (cr=262370 pr=113030 pw=0 time=179051 us)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=25 us)
12205347        TABLE ACCESS FULL PO_LINE (cr=249180 pr=113030 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                       241        0.03          0.25
  db file scattered read                       1145        0.04          1.17
  i/o slave wait                                152        0.04          0.57
  direct path write temp                          1        0.00          0.00
  direct path read temp                         102        0.04          0.48
  SQL*Net message from client                     2        0.00          0.00
  SQL*Net more data to client                    25        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows

------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.42       0.41          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2     26.66      29.77     253287     272823         62         278
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4     27.08      30.18     253287     272823         62         278

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
     278  HASH JOIN  (cr=272823 pr=253287 pw=3742 time=459543 us cost=165959 size=1675042188 card=4576618)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=122 us cost=4 size=176000 card=2200)
     278   HASH JOIN  (cr=272792 pr=253287 pw=3742 time=459404 us cost=165933 size=1308912748 card=4576618)
   49786    TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=17789 us cost=199 size=1593152 card=49786)
     278    HASH JOIN  (cr=270287 pr=253287 pw=3742 time=459127 us cost=151253 size=1162460972 card=4576618)
    6647     HASH JOIN  (cr=7535 pr=0 pw=0 time=5240 us cost=604 size=513146 card=2491)
    6647      HASH JOIN  (cr=5030 pr=0 pw=0 time=31951 us cost=403 size=189316 card=2491)
       3       INLIST ITERATOR  (cr=3 pr=0 pw=0 time=16 us)
       3        TABLE ACCESS BY INDEX ROWID UMS (cr=3 pr=0 pw=0 time=0 us cost=2 size=21 card=3)
       3         INDEX UNIQUE SCAN SYS_C009204 (cr=2 pr=0 pw=0 time=0 us cost=1 size=0 card=3)(object id 20303)
    6647       TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=29523 us cost=401 size=458367 card=6643)
   49786      TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=16765 us cost=199 size=6472180 card=49786)
    4246     VIEW  (cr=262752 pr=253287 pw=3742 time=688439 us cost=150591 size=585856656 card=12205347)
  511557      WINDOW SORT PUSHED RANK (cr=262752 pr=253287 pw=3742 time=675760 us cost=150591 size=598062003 card=12205347)
12205347       HASH JOIN  (cr=262752 pr=249545 pw=0 time=7621317 us cost=27537 size=598062003 card=12205347)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=82032 us cost=1118 size=10000000 card=500000)
12205347        TABLE ACCESS FULL PO_LINE (cr=249562 pr=249545 pw=0 time=3013736 us cost=20188 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  asynch descriptor resize                        9        0.00          0.00
  direct path read                              178        0.06          2.38
  direct path write temp                          1        0.00          0.00
  direct path read temp                         125        0.02          0.53
  SQL*Net message from client                     2        0.00          0.00

  SQL*Net more data to client                     6        0.00          0.00
 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.43       0.44          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2     26.44      29.82     252898     272472         62         278
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4     26.87      30.26     252898     272472         62         278

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
     278  HASH JOIN  (cr=272472 pr=252898 pw=3742 time=475747 us cost=165907 size=1674935682 card=4576327)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=244 us cost=4 size=176000 card=2200)
     278   HASH JOIN  (cr=272441 pr=252898 pw=3742 time=475470 us cost=165881 size=1308829522 card=4576327)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=16125 us cost=199 size=1593152 card=49786)
     278    HASH JOIN  (cr=269923 pr=252898 pw=3742 time=475193 us cost=151203 size=1162387058 card=4576327)
    6647     HASH JOIN  (cr=7561 pr=0 pw=0 time=6773 us cost=604 size=511704 card=2484)
    6647      HASH JOIN  (cr=5043 pr=0 pw=0 time=26584 us cost=403 size=188784 card=2484)
       3       INLIST ITERATOR  (cr=3 pr=0 pw=0 time=16 us)
       3        TABLE ACCESS BY INDEX ROWID UMS (cr=3 pr=0 pw=0 time=0 us cost=2 size=21 card=3)
       3         INDEX UNIQUE SCAN SYS_C0024653 (cr=2 pr=0 pw=0 time=0 us cost=1 size=0 card=3)(object id 83198)
    6647       TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=24666 us cost=401 size=456987 card=6623)
   49786      TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=15101 us cost=199 size=6472180 card=49786)
    4246     VIEW  (cr=262362 pr=252898 pw=3742 time=713534 us cost=150541 size=585856656 card=12205347)
  511304      WINDOW SORT PUSHED RANK (cr=262362 pr=252898 pw=3742 time=688947 us cost=150541 size=598062003 card=12205347)
12205347       HASH JOIN  (cr=262362 pr=249156 pw=0 time=6328527 us cost=27487 size=598062003 card=12205347)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=68978 us cost=1118 size=10000000 card=500000)
12205347        TABLE ACCESS FULL PO_LINE (cr=249172 pr=249156 pw=0 time=1858929 us cost=20138 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  asynch descriptor resize                        9        0.00          0.00
  direct path read                              174        0.05          2.85
  direct path write temp                          1        0.00          0.00
  direct path read temp                         101        0.01          0.39
  SQL*Net message from client                     2        0.00          0.00
  SQL*Net more data to client                     6        0.00          0.00   

Comparing the most recent vendor for each part with the expected vendor for each purchased part that was excluded from the previous query:

SELECT
  P.PART_ID,
  P.DESCRIPTION PART_DESCRIPTION,
  P.PRIMARY_WHS_ID,
  P.PRIMARY_LOC_ID,
  U.DESCRIPTION UMS_DESCRIPTION,
  U.UOM_SCALE,
  L.DESCRIPTION LOC_DESCRIPTION,
  V.VENDOR_ID,
  V.VENDOR_NAME,
  V.ADDR_1,
  V.ADDR_2,
  V.CITY,
  V.STATE,
  LV.VENDOR_ID LAST_VENDOR_ID,
  V2.VENDOR_NAME LAST_VENDOR_NAME,
  V2.STATE LAST_VENDOR_STATE,
  LV.DESIRED_RECV_DATE LAST_DES_RECV_DATE
FROM
  UMS U,
  LOCATIONS L,
  PARTS P,
  VENDORS V,
  (SELECT
    VENDOR_ID,
    PART_ID,
    DESIRED_RECV_DATE
  FROM
    (SELECT
      PO.VENDOR_ID,
      POL.PART_ID,
      POL.DESIRED_RECV_DATE,
      ROW_NUMBER() OVER (PARTITION BY POL.PART_ID ORDER BY POL.DESIRED_RECV_DATE DESC) RN
    FROM
      PO_HEADER PO,
      PO_LINE POL
    WHERE
      PO.PURC_ORDER_ID=POL.PURC_ORDER_ID)
  WHERE
    RN=1) LV,
  VENDORS V2
WHERE
  (P.PRODUCT_CODE NOT IN ('OFFICE','SHOP')
     OR U.UNIT_OF_MEASURE NOT IN ('EA','PC','CASE'))
  AND P.PURCHASED='Y'
  AND P.STOCK_UM=U.UNIT_OF_MEASURE
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND P.PRIMARY_WHS_ID=L.WAREHOUSE_ID
  AND P.PRIMARY_LOC_ID=L.LOCATION_ID
  AND P.PART_ID=LV.PART_ID
  AND LV.VENDOR_ID=V2.VENDOR_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.60       0.60          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4     25.75      26.00     252854     272253         63        2550
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6     26.36      26.61     252854     272253         63        2550

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      2550       2550       2550  HASH JOIN  (cr=272253 pr=252854 pw=3805 time=917103 us cost=190663 size=3936278028 card=10754858)
      2200       2200       2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=366 us cost=4 size=176000 card=2200)
      2551       2551       2551   HASH JOIN  (cr=272222 pr=252854 pw=3805 time=703263 us cost=190608 size=3075889388 card=10754858)
     49786      49786      49786    TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=14973 us cost=197 size=6472180 card=49786)
      2551       2551       2551    HASH JOIN  (cr=269725 pr=252854 pw=3805 time=700981 us cost=168838 size=1677757848 card=10754858)
     49786      49786      49786     TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=13950 us cost=197 size=1593152 card=49786)
      2551       2551       2551     HASH JOIN  (cr=267228 pr=252854 pw=3805 time=700310 us cost=151200 size=1333602392 card=10754858)
         8          8          8      TABLE ACCESS FULL UMS (cr=3 pr=0 pw=0 time=0 us cost=2 size=56 card=8)
      2829       2829       2829      MERGE JOIN  (cr=267225 pr=252854 pw=3805 time=817292 us cost=151140 size=1428005592 card=12205176)
      4246       4246       4246       VIEW  (cr=262229 pr=252854 pw=3805 time=800432 us cost=150135 size=585856656 card=12205347)
    519965     519965     519965        WINDOW SORT PUSHED RANK (cr=262229 pr=252854 pw=3805 time=822060 us cost=150135 size=598062003 card=12205347)
  12205347   12205347   12205347         HASH JOIN  (cr=262229 pr=249049 pw=0 time=6367055 us cost=27081 size=598062003 card=12205347)
    500000     500000     500000          TABLE ACCESS FULL PO_HEADER (cr=13173 pr=0 pw=0 time=63219 us cost=1038 size=10000000 card=500000)
  12205347   12205347   12205347          TABLE ACCESS FULL PO_LINE (cr=249056 pr=249049 pw=0 time=1935473 us cost=19811 size=353955063 card=12205347)
      2829       2829       2829       SORT JOIN (cr=4996 pr=0 pw=0 time=0 us cost=1005 size=3089061 card=44769)
     66462      66462      66462        TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=22494 us cost=398 size=3089061 card=44769)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  direct path read                                8        0.04          0.05
  asynch descriptor resize                        8        0.00          0.00
  direct path write temp                          1        0.00          0.00
  direct path read temp                         128        0.00          0.08
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                    56        0.00          0.00 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.99       1.20          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4     28.00      28.65       3627     272534         60        2550
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6     29.00      29.86       3627     272534         60        2550

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2550  HASH JOIN  (cr=272534 pr=3627 pw=3622 time=28590189 us)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=35 us)
    2551   HASH JOIN  (cr=272503 pr=3627 pw=3622 time=28551033 us)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=15 us)
    2551    HASH JOIN  (cr=269985 pr=3627 pw=3622 time=28522524 us)
   49786     TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=23 us)
    2551     HASH JOIN  (cr=267467 pr=3627 pw=3622 time=28498973 us)
       8      TABLE ACCESS FULL UMS (cr=7 pr=5 pw=0 time=20191 us)
    2829      MERGE JOIN  (cr=267460 pr=3622 pw=3622 time=28472228 us)
    4246       VIEW  (cr=262420 pr=3622 pw=3622 time=28456925 us)
    8895        WINDOW SORT PUSHED RANK (cr=262420 pr=3622 pw=3622 time=28377263 us)
12205347         HASH JOIN  (cr=262420 pr=0 pw=0 time=173557 us)
  500000          TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=17 us)
12205347          TABLE ACCESS FULL PO_LINE (cr=249230 pr=0 pw=0 time=20 us)
    2829       SORT JOIN (cr=5040 pr=0 pw=0 time=62158 us)
   66462        TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=49 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                         1        0.01          0.01
  db file scattered read                          2        0.00          0.00
  direct path write temp                          1        0.00          0.00
  direct path read temp                         100        0.03          0.61
  SQL*Net message from client                     4        0.00          0.01
  SQL*Net more data to client                   229        0.00          0.00

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.99       1.80          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4     28.93      30.98     116717     272484         59        2550
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6     29.93      32.78     116717     272484         59        2550

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2550  HASH JOIN  (cr=272484 pr=116717 pw=3563 time=30946899 us)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=31 us)
    2551   HASH JOIN  (cr=272453 pr=116717 pw=3563 time=31958392 us)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=13 us)
    2551    HASH JOIN  (cr=269935 pr=116717 pw=3563 time=31926556 us)
   49786     TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=21 us)
    2551     HASH JOIN  (cr=267417 pr=116717 pw=3563 time=31902630 us)
       8      TABLE ACCESS FULL UMS (cr=7 pr=5 pw=0 time=39672 us)
    2829      MERGE JOIN  (cr=267410 pr=116712 pw=3563 time=30871775 us)
    4246       VIEW  (cr=262370 pr=116712 pw=3563 time=30771072 us)
    8928        WINDOW SORT PUSHED RANK (cr=262370 pr=116712 pw=3563 time=30671567 us)
12205347         HASH JOIN  (cr=262370 pr=113149 pw=0 time=173557 us)
  500000          TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=18 us)
12205347          TABLE ACCESS FULL PO_LINE (cr=249180 pr=113149 pw=0 time=21 us)
    2829       SORT JOIN (cr=5040 pr=0 pw=0 time=60695 us)
   66462        TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=47 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                       265        0.02          0.27
  db file scattered read                       1076        0.05          1.33
  i/o slave wait                                162        0.03          0.45
  direct path write temp                          1        0.00          0.00
  direct path read temp                         118        0.03          0.38
  SQL*Net message from client                     4        0.00          0.01
  SQL*Net more data to client                   229        0.00          0.00

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.63       0.64          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4     26.87      30.38     253292     272827         62        2550
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6     27.51      31.03     253292     272827         62        2550

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2550  HASH JOIN  (cr=272827 pr=253292 pw=3742 time=707146 us cost=191123 size=3936296694 card=10754909)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=0 us cost=4 size=176000 card=2200)
    2551   HASH JOIN  (cr=272796 pr=253292 pw=3742 time=617905 us cost=191068 size=3075903974 card=10754909)
   49786    TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=17533 us cost=199 size=6472180 card=49786)
    2551    HASH JOIN  (cr=270291 pr=253292 pw=3742 time=616563 us cost=169295 size=1677765804 card=10754909)
   49786     TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=15741 us cost=199 size=1593152 card=49786)
    2551     HASH JOIN  (cr=267786 pr=253292 pw=3742 time=614550 us cost=151655 size=1333608716 card=10754909)
       8      TABLE ACCESS FULL UMS (cr=7 pr=5 pw=0 time=0 us cost=2 size=56 card=8)
    2829      MERGE JOIN  (cr=267779 pr=253287 pw=3742 time=1493184 us cost=151595 size=1428012378 card=12205234)
    4246       VIEW  (cr=262752 pr=253287 pw=3742 time=660596 us cost=150591 size=585856656 card=12205347)
  511557        WINDOW SORT PUSHED RANK (cr=262752 pr=253287 pw=3742 time=1379383 us cost=150591 size=598062003 card=12205347)
12205347         HASH JOIN  (cr=262752 pr=249545 pw=0 time=8177985 us cost=27537 size=598062003 card=12205347)
  500000          TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=65267 us cost=1118 size=10000000 card=500000)
12205347          TABLE ACCESS FULL PO_LINE (cr=249562 pr=249545 pw=0 time=3676259 us cost=20188 size=353955063 card=12205347)
    2829       SORT JOIN (cr=5027 pr=0 pw=0 time=0 us cost=1003 size=3056010 card=44290)
   66462        TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=27734 us cost=402 size=3056010 card=44290)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                         2        0.01          0.01
  db file scattered read                          1        0.00          0.00
  direct path read                              202        0.07          2.80
  asynch descriptor resize                        8        0.00          0.00
  direct path write temp                          1        0.00          0.00
  direct path read temp                         101        0.04          0.51
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                    56        0.00          0.00

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.67       0.66          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        4     26.75      30.20     252903     272476         62        2550
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6     27.42      30.86     252903     272476         62        2550

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
    2550  HASH JOIN  (cr=272476 pr=252903 pw=3742 time=712244 us cost=191070 size=3936284616 card=10754876)
    2200   TABLE ACCESS FULL LOCATIONS (cr=31 pr=0 pw=0 time=244 us cost=4 size=176000 card=2200)
    2551   HASH JOIN  (cr=272445 pr=252903 pw=3742 time=614550 us cost=191015 size=3075894536 card=10754876)
   49786    TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=17661 us cost=199 size=6472180 card=49786)
    2551    HASH JOIN  (cr=269927 pr=252903 pw=3742 time=613476 us cost=169243 size=1677760656 card=10754876)
   49786     TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=14973 us cost=199 size=1593152 card=49786)
    2551     HASH JOIN  (cr=267409 pr=252903 pw=3742 time=611597 us cost=151602 size=1333604624 card=10754876)
       8      TABLE ACCESS FULL UMS (cr=7 pr=5 pw=0 time=0 us cost=2 size=56 card=8)
    2829      MERGE JOIN  (cr=267402 pr=252898 pw=3742 time=705457 us cost=151543 size=1428008049 card=12205197)
    4246       VIEW  (cr=262362 pr=252898 pw=3742 time=659098 us cost=150541 size=585856656 card=12205347)
  511304        WINDOW SORT PUSHED RANK (cr=262362 pr=252898 pw=3742 time=711906 us cost=150541 size=598062003 card=12205347)
12205347         HASH JOIN  (cr=262362 pr=249156 pw=0 time=9688757 us cost=27487 size=598062003 card=12205347)
  500000          TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=61939 us cost=1118 size=10000000 card=500000)
12205347          TABLE ACCESS FULL PO_LINE (cr=249172 pr=249156 pw=0 time=5162968 us cost=20138 size=353955063 card=12205347)
   2829       SORT JOIN (cr=5040 pr=0 pw=0 time=0 us cost=1001 size=3046557 card=44153)
  66462        TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=26200 us cost=402 size=3046557 card=44153)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  db file sequential read                         1        0.00          0.00
  db file scattered read                          2        0.00          0.00
  direct path read                              187        0.07          2.90
  asynch descriptor resize                        8        0.00          0.00
  direct path write temp                          1        0.00          0.00
  direct path read temp                         127        0.03          0.44
  SQL*Net message from client                     4        0.00          0.00
  SQL*Net more data to client                    56        0.00          0.00   

For all parts, determine the number of purchase order line exceptions where a part was purchase from a vendor other than the preferred vendor:

SELECT
  P.PART_ID,
  P.DESCRIPTION,
  P.PREF_VENDOR_ID,
  V.VENDOR_NAME PREF_VENDOR_NAME,
  PV.VENDOR_ID,
  V2.VENDOR_NAME LAST_VENDOR_NAME,
  PV.ORDER_LINES,
  PV.FIRST_RECV_DATE,
  PV.LAST_RECV_DATE
FROM
  (SELECT
    PO.VENDOR_ID,
    POL.PART_ID,
    COUNT(*) ORDER_LINES,
    MIN(POL.DESIRED_RECV_DATE) FIRST_RECV_DATE,
    MAX(POL.DESIRED_RECV_DATE) LAST_RECV_DATE
  FROM
    PO_HEADER PO,
    PO_LINE POL
  WHERE
    PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  GROUP BY
    PO.VENDOR_ID,
    POL.PART_ID) PV,
  PARTS P,
  VENDORS V,
  VENDORS V2
WHERE
  P.PART_ID=PV.PART_ID
  AND P.PREF_VENDOR_ID != PV.VENDOR_ID
  AND P.PREF_VENDOR_ID=V.VENDOR_ID
  AND PV.VENDOR_ID=V2.VENDOR_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.09       0.08          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      151      9.98      10.16     249049     272219          0      149403
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      153     10.07      10.24     249049     272219          0      149403

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
    149403     149403     149403  HASH JOIN  (cr=272219 pr=249049 pw=0 time=244266 us cost=161133 size=1879414152 card=12203988)
     49786      49786      49786   TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=13182 us cost=197 size=1443794 card=49786)
    149403     149403     149403   HASH JOIN  (cr=269722 pr=249049 pw=0 time=166941 us cost=160877 size=1525498500 card=12203988)
     66462      66462      66462    JOIN FILTER CREATE :BF0000 (cr=7493 pr=0 pw=0 time=62115 us cost=594 size=4519416 card=66462)
     66462      66462      66462     HASH JOIN  (cr=7493 pr=0 pw=0 time=51123 us cost=594 size=4519416 card=66462)
     49786      49786      49786      TABLE ACCESS FULL VENDORS (cr=2497 pr=0 pw=0 time=12286 us cost=197 size=1443794 card=49786)
     66462      66462      66462      TABLE ACCESS FULL PARTS (cr=4996 pr=0 pw=0 time=31824 us cost=396 size=2592018 card=66462)
    150920     150920     150920    VIEW  (cr=262229 pr=249049 pw=0 time=99204 us cost=150135 size=695704779 card=12205347)
    150920     150920     150920     HASH GROUP BY (cr=262229 pr=249049 pw=0 time=65027 us cost=150135 size=598062003 card=12205347)
   8219280    8219280    8219280      JOIN FILTER USE :BF0000 (cr=262229 pr=249049 pw=0 time=5918254 us cost=27081 size=598062003 card=12205347)
  12205347   12205347   12205347       HASH JOIN  (cr=262229 pr=249049 pw=0 time=5812435 us cost=27081 size=598062003 card=12205347)
    500000     500000     500000        TABLE ACCESS FULL PO_HEADER (cr=13173 pr=0 pw=0 time=58612 us cost=1038 size=10000000 card=500000)
  12205347   12205347   12205347        TABLE ACCESS FULL PO_LINE (cr=249056 pr=249049 pw=0 time=1746674 us cost=19811 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     151        0.00          0.00
  asynch descriptor resize                        6        0.00          0.00
  direct path read                                9        0.00          0.01
  SQL*Net message from client                   151        0.00          0.23
  SQL*Net more data to client                  1643        0.00          0.07 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.10       0.14          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      151     12.05      12.14          0     272496          0      149395
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      153     12.16      12.29          0     272496          0      149395

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
  149395  HASH JOIN  (cr=272496 pr=0 pw=0 time=11778583 us)
   49786   TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=36 us)
  149395   HASH JOIN  (cr=269978 pr=0 pw=0 time=11761016 us)
   66462    HASH JOIN  (cr=7558 pr=0 pw=0 time=17370 us)
   49786     TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=20 us)
   66462     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=18 us)
  224290    VIEW  (cr=262420 pr=0 pw=0 time=11532768 us)
  224290     HASH GROUP BY (cr=262420 pr=0 pw=0 time=11532765 us)
12205347      HASH JOIN  (cr=262420 pr=0 pw=0 time=178331 us)
  500000       TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=23 us)
12205347       TABLE ACCESS FULL PO_LINE (cr=249230 pr=0 pw=0 time=20 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     151        0.00          0.00
  SQL*Net message from client                   151        0.00          0.24
  SQL*Net more data to client                  7448        0.00          0.10

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.21          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      151     12.65      14.34     113149     272446          0      149407
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      153     12.71      14.56     113149     272446          0      149407

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
  149407  HASH JOIN  (cr=272446 pr=113149 pw=0 time=13979365 us)
   49786   TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=25 us)
  149407   HASH JOIN  (cr=269928 pr=113149 pw=0 time=13961727 us)
   66462    HASH JOIN  (cr=7558 pr=0 pw=0 time=17388 us)
   49786     TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=20 us)
   66462     TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=19 us)
  224290    VIEW  (cr=262370 pr=113149 pw=0 time=13733144 us)
  224290     HASH GROUP BY (cr=262370 pr=113149 pw=0 time=13733143 us)
12205347      HASH JOIN  (cr=262370 pr=113149 pw=0 time=172881 us)
  500000       TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=26 us)
12205347       TABLE ACCESS FULL PO_LINE (cr=249180 pr=113149 pw=0 time=21 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     151        0.00          0.00
  db file sequential read                       245        0.02          0.25
  db file scattered read                       1215        0.04          1.33
  SQL*Net message from client                   151        0.00          0.24
  SQL*Net more data to client                  7458        0.00          0.10 

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.09       0.09          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      151      9.96      18.19     249545     272789          0      149400
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      153     10.06      18.28     249545     272789          0      149400

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
  149400  HASH JOIN  (cr=272789 pr=249545 pw=0 time=200990 us cost=161597 size=1879414152 card=12203988)
   49786   TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=15101 us cost=199 size=1443794 card=49786)
  149400   HASH JOIN  (cr=270284 pr=249545 pw=0 time=130068 us cost=161339 size=1525498500 card=12203988)
   66462    JOIN FILTER CREATE :BF0000 (cr=7532 pr=0 pw=0 time=61092 us cost=600 size=4519416 card=66462)
   66462     HASH JOIN  (cr=7532 pr=0 pw=0 time=50101 us cost=600 size=4519416 card=66462)
   49786      TABLE ACCESS FULL VENDORS (cr=2505 pr=0 pw=0 time=13182 us cost=199 size=1443794 card=49786)
   66462      TABLE ACCESS FULL PARTS (cr=5027 pr=0 pw=0 time=25817 us cost=400 size=2592018 card=66462)
  150920    VIEW  (cr=262752 pr=249545 pw=0 time=80131 us cost=150591 size=695704779 card=12205347)
  150920     HASH GROUP BY (cr=262752 pr=249545 pw=0 time=53506 us cost=150591 size=598062003 card=12205347)
 8219280      JOIN FILTER USE :BF0000 (cr=262752 pr=249545 pw=0 time=20817762 us cost=27537 size=598062003 card=12205347)
12205347       HASH JOIN  (cr=262752 pr=249545 pw=0 time=16388226 us cost=27537 size=598062003 card=12205347)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=65651 us cost=1118 size=10000000 card=500000)
12205347        TABLE ACCESS FULL PO_LINE (cr=249562 pr=249545 pw=0 time=12278561 us cost=20188 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     151        0.00          0.00
  asynch descriptor resize                        6        0.00          0.00
  direct path read                             1943        0.04          7.84
  SQL*Net message from client                   151        0.00          0.26
  SQL*Net more data to client                  1792        0.00          0.03 

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.09       0.09          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      151     10.34      15.04     249156     272438          0      149408
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      153     10.43      15.13     249156     272438          0      149408

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

 Rows     Row Source Operation
 -------  ---------------------------------------------------
  149408  HASH JOIN  (cr=272438 pr=249156 pw=0 time=202794 us cost=161546 size=1879414152 card=12203988)
   49786   TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=12798 us cost=199 size=1443794 card=49786)
  149408   HASH JOIN  (cr=269920 pr=249156 pw=0 time=133531 us cost=161289 size=1525498500 card=12203988)
   66462    JOIN FILTER CREATE :BF0000 (cr=7558 pr=0 pw=0 time=60198 us cost=600 size=4519416 card=66462)
   66462     HASH JOIN  (cr=7558 pr=0 pw=0 time=48567 us cost=600 size=4519416 card=66462)
   49786      TABLE ACCESS FULL VENDORS (cr=2518 pr=0 pw=0 time=12286 us cost=199 size=1443794 card=49786)
   66462      TABLE ACCESS FULL PARTS (cr=5040 pr=0 pw=0 time=23900 us cost=400 size=2592018 card=66462)
  150920    VIEW  (cr=262362 pr=249156 pw=0 time=82819 us cost=150541 size=695704779 card=12205347)
  150920     HASH GROUP BY (cr=262362 pr=249156 pw=0 time=51970 us cost=150541 size=598062003 card=12205347)
 8219280      JOIN FILTER USE :BF0000 (cr=262362 pr=249156 pw=0 time=6369576 us cost=27487 size=598062003 card=12205347)
12205347       HASH JOIN  (cr=262362 pr=249156 pw=0 time=6154577 us cost=27487 size=598062003 card=12205347)
  500000        TABLE ACCESS FULL PO_HEADER (cr=13190 pr=0 pw=0 time=65779 us cost=1118 size=10000000 card=500000)
12205347        TABLE ACCESS FULL PO_LINE (cr=249172 pr=249156 pw=0 time=2004720 us cost=20138 size=353955063 card=12205347)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                     151        0.00          0.00
  asynch descriptor resize                        6        0.00          0.00
  direct path read                              578        0.06          4.78
  SQL*Net message from client                   151        0.00          0.26
  SQL*Net more data to client                  1793        0.00          0.03   

A give me every column type query, were the user doesn’t know exactly what vendor they are looking for, or exactly what part, but they know that the purchase order line has been posted to the GL:

SELECT
  *
FROM
  PO_HEADER PO,
  PO_LINE POL,
  PARTS P,
  VENDORS V
WHERE
  PO.VENDOR_ID LIKE '100%'
  AND PO.POSTING_CANDIDATE='N'
  AND PO.PURC_ORDER_ID=POL.PURC_ORDER_ID
  AND POL.PART_ID BETWEEN '80' AND '999999'
  AND POL.PART_ID=P.PART_ID
  AND PO.VENDOR_ID=V.VENDOR_ID 

Laptop running 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6      0.12       0.64       1410      11322          0        4629
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      0.18       0.69       1410      11322          0        4629

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 286 
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
      4629       4629       4629  NESTED LOOPS  (cr=11322 pr=1410 pw=0 time=707312 us)
      4629       4629       4629   NESTED LOOPS  (cr=6693 pr=1410 pw=0 time=724219 us cost=12 size=2964 card=3)
      4629       4629       4629    NESTED LOOPS  (cr=2058 pr=1343 pw=0 time=606393 us cost=9 size=1875 card=3)
       387        387        387     NESTED LOOPS  (cr=571 pr=6 pw=0 time=2991 us cost=6 size=505 card=1)
        33         33         33      TABLE ACCESS BY INDEX ROWID VENDORS (cr=40 pr=2 pw=0 time=224 us cost=3 size=342 card=1)
        33         33         33       INDEX RANGE SCAN SYS_C0024972 (cr=7 pr=2 pw=0 time=128 us cost=2 size=0 card=1)(object id 82050)
       387        387        387      TABLE ACCESS BY INDEX ROWID PO_HEADER (cr=531 pr=4 pw=0 time=3040 us cost=3 size=163 card=1)
       497        497        497       INDEX RANGE SCAN IND_PO_HEADER_1 (cr=34 pr=4 pw=0 time=1057 us cost=2 size=0 card=1)(object id 82064)
      4629       4629       4629     TABLE ACCESS BY INDEX ROWID PO_LINE (cr=1487 pr=1337 pw=0 time=117812 us cost=3 size=360 card=3)
     10634      10634      10634      INDEX RANGE SCAN SYS_C0025101 (cr=901 pr=756 pw=0 time=24583 us cost=2 size=0 card=25)(object id 82070)
      4629       4629       4629    INDEX UNIQUE SCAN SYS_C0025012 (cr=4635 pr=67 pw=0 time=0 us cost=0 size=0 card=1)(object id 82053)
      4629       4629       4629   TABLE ACCESS BY INDEX ROWID PARTS (cr=4629 pr=0 pw=0 time=0 us cost=1 size=363 card=1)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  SQL*Net more data to client                   125        0.00          0.00
  db file sequential read                      1410        0.00          0.46
  SQL*Net message from client                     6        0.03          0.17 

Oracle Database 10.2.0.5 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6      0.20       9.66        966      12017          0        4629
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      0.23       9.71        966      12017          0        4629

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
   4629  NESTED LOOPS  (cr=12017 pr=966 pw=0 time=10450963 us)
   4629   NESTED LOOPS  (cr=2753 pr=822 pw=0 time=9710630 us)
    387    NESTED LOOPS  (cr=620 pr=12 pw=0 time=71052 us)
     33     TABLE ACCESS BY INDEX ROWID VENDORS (cr=40 pr=5 pw=0 time=25381 us)
     33      INDEX RANGE SCAN SYS_C004577 (cr=7 pr=5 pw=0 time=25183 us)(object id 47893)
    387     TABLE ACCESS BY INDEX ROWID PO_HEADER (cr=580 pr=7 pw=0 time=68799 us)
    497      INDEX RANGE SCAN IND_PO_HEADER_2 (cr=83 pr=7 pw=0 time=42360 us)(object id 47908)
   4629    TABLE ACCESS BY INDEX ROWID PO_LINE (cr=2133 pr=810 pw=0 time=7763613 us)
  10634     INDEX RANGE SCAN SYS_C004706 (cr=1363 pr=810 pw=0 time=10702791 us)(object id 47913)
   4629   TABLE ACCESS BY INDEX ROWID PARTS (cr=9264 pr=144 pw=0 time=737759 us)
   4629    INDEX UNIQUE SCAN SYS_C004617 (cr=4635 pr=144 pw=0 time=705778 us)(object id 47896)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  SQL*Net more data to client                   519        0.00          0.01
  db file sequential read                       730        0.03          8.94
  db file scattered read                         46        0.02          0.52
  SQL*Net message from client                     6        0.04          0.19

Oracle Database 10.2.0.5 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6      0.28       7.26       1191      11989          0        4629
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      0.34       7.32       1191      11989          0        4629

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
   4629  NESTED LOOPS  (cr=11989 pr=1191 pw=0 time=5359344 us)
   4629   NESTED LOOPS  (cr=2725 pr=1058 pw=0 time=4838370 us)
    387    NESTED LOOPS  (cr=620 pr=12 pw=0 time=53788 us)
     33     TABLE ACCESS BY INDEX ROWID VENDORS (cr=40 pr=5 pw=0 time=18936 us)
     33      INDEX RANGE SCAN SYS_C0012084 (cr=7 pr=5 pw=0 time=18834 us)(object id 51698)
    387     TABLE ACCESS BY INDEX ROWID PO_HEADER (cr=580 pr=7 pw=0 time=48231 us)
    497      INDEX RANGE SCAN IND_PO_HEADER_1 (cr=83 pr=7 pw=0 time=31669 us)(object id 51712)
   4629    TABLE ACCESS BY INDEX ROWID PO_LINE (cr=2105 pr=1046 pw=0 time=5891086 us)
  10634     INDEX RANGE SCAN SYS_C0012213 (cr=1333 pr=760 pw=0 time=5874269 us)(object id 51718)
   4629   TABLE ACCESS BY INDEX ROWID PARTS (cr=9264 pr=133 pw=0 time=406748 us)
   4629    INDEX UNIQUE SCAN SYS_C0012124 (cr=4635 pr=133 pw=0 time=373924 us)(object id 51701)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  SQL*Net more data to client                   517        0.00          0.01
  db file sequential read                       895        0.04          6.78
  db file scattered read                         56        0.01          0.27
  SQL*Net message from client                     6        0.04          0.19

Oracle Database 11.2.0.1 Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6      0.17      10.28       2000      11985          0        4629
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      0.23      10.34       2000      11985          0        4629

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
   4629  NESTED LOOPS  (cr=11985 pr=2000 pw=0 time=16662600 us)
   4629   NESTED LOOPS  (cr=7356 pr=2000 pw=0 time=17419042 us cost=13 size=2964 card=3)
   4629    NESTED LOOPS  (cr=2721 pr=1845 pw=0 time=15284658 us cost=10 size=1875 card=3)
    387     NESTED LOOPS  (cr=587 pr=12 pw=0 time=3088 us cost=6 size=505 card=1)
     33      TABLE ACCESS BY INDEX ROWID VENDORS (cr=40 pr=5 pw=0 time=608 us cost=3 size=342 card=1)
     33       INDEX RANGE SCAN SYS_C009210 (cr=7 pr=5 pw=0 time=512 us cost=2 size=0 card=1)(object id 20305)
    387      TABLE ACCESS BY INDEX ROWID PO_HEADER (cr=547 pr=7 pw=0 time=3040 us cost=3 size=163 card=1)
    497       INDEX RANGE SCAN IND_PO_HEADER_1 (cr=50 pr=7 pw=0 time=976 us cost=2 size=0 card=1)(object id 20319)
   4629     TABLE ACCESS BY INDEX ROWID PO_LINE (cr=2134 pr=1833 pw=0 time=550076 us cost=4 size=360 card=3)
  10634      INDEX RANGE SCAN SYS_C009339 (cr=1353 pr=750 pw=0 time=11113 us cost=2 size=0 card=25)(object id 20325)
   4629    INDEX UNIQUE SCAN SYS_C009250 (cr=4635 pr=155 pw=0 time=0 us cost=0 size=0 card=1)(object id 20308)
   4629   TABLE ACCESS BY INDEX ROWID PARTS (cr=4629 pr=0 pw=0 time=0 us cost=1 size=363 card=1)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  SQL*Net more data to client                   125        0.00          0.00
  db file sequential read                      1179        0.04          8.25
  db file scattered read                        121        0.03          0.55
  SQL*Net message from client                     6        0.04          0.19
  db file parallel read                         120        0.04          1.25

Oracle Database 11.2.0.1 Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.05          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        6      0.35      14.98       1999      11963          0        4629
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      0.39      15.03       1999      11963          0        4629

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
   4629  NESTED LOOPS  (cr=11963 pr=1999 pw=0 time=19636346 us)
   4629   NESTED LOOPS  (cr=7334 pr=1999 pw=0 time=20963088 us cost=13 size=2964 card=3)
   4629    NESTED LOOPS  (cr=2699 pr=1869 pw=0 time=18515502 us cost=10 size=1875 card=3)
    387     NESTED LOOPS  (cr=589 pr=13 pw=0 time=3474 us cost=6 size=505 card=1)
     33      TABLE ACCESS BY INDEX ROWID VENDORS (cr=40 pr=5 pw=0 time=1248 us cost=3 size=342 card=1)
     33       INDEX RANGE SCAN SYS_C0024659 (cr=7 pr=5 pw=0 time=1056 us cost=2 size=0 card=1)(object id 83200)
    387      TABLE ACCESS BY INDEX ROWID PO_HEADER (cr=549 pr=8 pw=0 time=3761 us cost=3 size=163 card=1)
    497       INDEX RANGE SCAN IND_PO_HEADER_1 (cr=52 pr=8 pw=0 time=1342 us cost=2 size=0 card=1)(object id 83214)
   4629     TABLE ACCESS BY INDEX ROWID PO_LINE (cr=2110 pr=1856 pw=0 time=321223 us cost=4 size=360 card=3)
  10634      INDEX RANGE SCAN SYS_C0024788 (cr=1342 pr=781 pw=0 time=3534 us cost=2 size=0 card=25)(object id 83220)
   4629    INDEX UNIQUE SCAN SYS_C0024699 (cr=4635 pr=130 pw=0 time=0 us cost=0 size=0 card=1)(object id 83203)
   4629   TABLE ACCESS BY INDEX ROWID PARTS (cr=4629 pr=0 pw=0 time=0 us cost=1 size=363 card=1)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       6        0.00          0.00
  SQL*Net more data to client                   125        0.00          0.00
  db file sequential read                      1177        0.03         12.48
  db file scattered read                        129        0.02          0.69
  SQL*Net message from client                     6        0.04          0.19
  db file parallel read                         110        0.02          1.59   

—————–

While the above output only shows a small number of execution plan changes, there are in fact a couple of notable changes.  In some cases, the number of physical block reads for one release version and/or edition was double, possibly even 1000 times as large as one of the other release versions – the differences in the types of wait events and the use or avoidance of the buffer cache for previously executed SQL statements in the database, as well as changes in the execution plans help explain many of the odd differences in the statistics.  One of the questions that remains to be answered is how would an execution that required an additional 3 seconds to execute in the above output, due to a significant increase in the number of physical block reads, behave once it is released into production where it might be simultaneously executed by a dozen or more users.  What about an execution that required significantly more CPU time – could that cause a similar problem once concurrency exists in production?

We still have not experimented with bind variables, an insufficient number of hints in complex SQL statements, rapid fire execution of SQL statements – each of which return only a small number of rows, and probably a couple other problem areas.





Different Performance from Standard Edition and Enterprise Edition? 3

22 11 2010

November 22, 2010

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

In the previous articles of this series we looked at different performance behavior exhibited by Standard Edition and Enterprise Editions for release versions 10.2.0.5 and 11.2.0.1, when presented with a very simple SQL statement that forced an index access path.  Today’s article takes a slightly different path, where we will see radically different execution plans for the Standard Edition and Enterprise Edition, as well as an issue that will cause some of the proponents of the buffer cache hit ratio to panic when the statistics produced by the Enterprise Edition of 10.2.0.5 are compared to the statistics produced by the Enterprise Edition of 11.2.0.1 (another new discussion thread on the OTN forums discussing the BCHR). 

Once again, we will manually specify the system (CPU) statistics as follows so that we might prevent slight differences in the statistics already set for the databases from causing unexpected results:

EXEC DBMS_STATS.SET_SYSTEM_STATS('MBRC',16)
EXEC DBMS_STATS.SET_SYSTEM_STATS('CPUSPEED',2664)
EXEC DBMS_STATS.SET_SYSTEM_STATS('SREADTIM',8)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MREADTIM',10)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MAXTHR',19181568) 

The script to create the two test tables and associated indexes:

CREATE TABLE T1 (
  C1 NUMBER NOT NULL,
  C2 VARCHAR2(20) NOT NULL,
  C3 NUMBER NOT NULL,
  C4 DATE NOT NULL,
  PADDING VARCHAR2(500));

INSERT INTO
  T1
SELECT
  TO_NUMBER(TO_CHAR(TRUNC(SYSDATE)+(ROWNUM-1), 'DD')),
  TRIM(TO_CHAR(TRUNC(SYSDATE)+(ROWNUM-1), 'DAY')),
  TO_NUMBER(TO_CHAR(TRUNC(SYSDATE)+(ROWNUM-1), 'DDD')),
  TRUNC(SYSDATE)+(ROWNUM-1),
  LPAD('A',500,'A')
FROM
  DUAL
CONNECT BY
  LEVEL<=500000;

COMMIT;

CREATE INDEX IND_T1_C1 ON T1(C1);
CREATE INDEX IND_T1_C2 ON T1(C2);
CREATE INDEX IND_T1_C3 ON T1(C3);

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',ESTIMATE_PERCENT=>NULL,METHOD_OPT=>'FOR ALL COLUMNS SIZE 1',NO_INVALIDATE=>FALSE)

CREATE TABLE T2 AS
SELECT
  *
FROM
  T1;

CREATE INDEX IND_T2_C1 ON T2(C1);
CREATE INDEX IND_T2_C2 ON T2(C2);
CREATE INDEX IND_T2_C3 ON T2(C3);

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',ESTIMATE_PERCENT=>NULL,METHOD_OPT=>'FOR ALL COLUMNS SIZE 1',NO_INVALIDATE=>FALSE)

COLUMN SEGMENT FORMAT A12

SELECT
  SEGMENT_NAME SEGMENT,
  COUNT(*) EXTENTS,
  BYTES/1024 EXT_SIZE_KB,
  (COUNT(*) * BYTES)/1048576 TOTAL_MB
FROM
  DBA_EXTENTS
WHERE
  OWNER=USER
  AND SEGMENT_NAME IN ('IND_T1_C1','IND_T1_C2','IND_T1_C3','T1')
GROUP BY
  SEGMENT_NAME,
  BYTES
ORDER BY
  SEGMENT_NAME,
  BYTES;

The tables were created in an ASSM autoallocate tablespace, with extents allocated as follows (consistent results with 10.2.0.5 and 11.2.0.1):

SEGMENT         EXTENTS EXT_SIZE_KB   TOTAL_MB
------------ ---------- ----------- ----------
IND_T1_C1            16          64          1
IND_T1_C1             7        1024          7
IND_T1_C2            16          64          1
IND_T1_C2            10        1024         10
IND_T1_C3            16          64          1
IND_T1_C3             8        1024          8
T1                   16          64          1
T1                   63        1024         63
T1                   30        8192        240 

The test script, once again divided into two nearly identical halves, with the results from the first half thrown out.  The first SQL statement retrieves the dates on which the day of the week is Monday and the day of the year is between 200 and 255.  The second SQL statement repeats the request with table T1 joined in a many to many type join to table T2:

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /* JUNK */
  T1.C4
FROM
  T1
WHERE
  T1.C2='MONDAY'
  AND T1.C3 BETWEEN 200 AND 255;

SELECT /* JUNK */
  T1.C4,
  T2.C4
FROM
  T1,
  T2
WHERE
  T1.C2='MONDAY'
  AND T1.C3 BETWEEN 200 AND 255
  AND T1.C1=T2.C1
  AND T1.C3=T2.C3;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /* FIND_ME */
  T1.C4
FROM
  T1
WHERE
  T1.C2='MONDAY'
  AND T1.C3 BETWEEN 200 AND 255;

SELECT SYSDATE FROM DUAL;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

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

SELECT /* FIND_ME */
  T1.C4,
  T2.C4
FROM
  T1,
  T2
WHERE
  T1.C2='MONDAY'
  AND T1.C3 BETWEEN 200 AND 255
  AND T1.C1=T2.C1
  AND T1.C3=T2.C3;

SELECT SYSDATE FROM DUAL;

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

We will start by comparing the statistics when the above script is executed in Oracle Database 10.2.0.5.

Standard Edition:

SQL> SELECT /* FIND_ME */
  2    T1.C4
  3  FROM
  4    T1
  5  WHERE
  6    T1.C2='MONDAY'
  7    AND T1.C3 BETWEEN 200 AND 255;

10952 rows selected.

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      38681  consistent gets
      38658  physical reads
          0  redo size
     104979  bytes sent via SQL*Net to client
        582  bytes received via SQL*Net from client
         12  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      10952  rows processed 

Enterprise Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
       6878  consistent gets
      33648  physical reads
          0  redo size
     104979  bytes sent via SQL*Net to client
        582  bytes received via SQL*Net from client
         12  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      10952  rows processed 

The Standard Edition read 38,658 blocks from disk and performed 38,681 consistent gets, so it might have selected to perform a full table scan (using the extent allocation displayed above, 304MB / 8KB = 38,912, which is close to the number of physical blocks that were read).  The Enterprise Edition read 33,648 blocks from disk and performed only 6,878 consistent gets (what happened to my BCHR, quick – downgrade to Standard Edition).  It is interesting that the number of consistent gets is significantly less than the number of blocks read from disk, and the number of blocks read from disk is less than that of the Standard Edition.  Interesting, how did the Enterprise Edition do that?  Let’s take a look at the TKPROF output.

Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.01       0.02          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch       12      0.15       3.72      38658      38681          0       10952
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       16      0.17       3.74      38658      38681          0       10952

Misses in library cache during parse: 1
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
  10952  TABLE ACCESS FULL T1 (cr=38681 pr=38658 pw=0 time=25071316 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      13        0.00          0.00
  SQL*Net message from client                    13        0.01          0.02
  db file sequential read                         1        0.01          0.01
  db file scattered read                        319        0.05          3.49
  SQL*Net more data to client                    46        0.00          0.00 

Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.01       0.05          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch       12      0.40       3.93      33648       6878          0       10952
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       16      0.42       3.99      33648       6878          0       10952

Misses in library cache during parse: 1
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
  10952  TABLE ACCESS BY INDEX ROWID T1 (cr=6878 pr=33648 pw=0 time=5271629 us)
  10952   BITMAP CONVERSION TO ROWIDS (cr=346 pr=376 pw=0 time=162037 us)
      2    BITMAP AND  (cr=346 pr=376 pw=0 time=189455 us)
     11     BITMAP CONVERSION FROM ROWIDS (cr=183 pr=200 pw=0 time=103387 us)
  71429      INDEX RANGE SCAN IND_T1_C2 (cr=183 pr=200 pw=0 time=65401 us)(object id 51682)
      3     BITMAP CONVERSION FROM ROWIDS (cr=163 pr=176 pw=0 time=71984 us)
  76664      SORT ORDER BY (cr=163 pr=176 pw=0 time=57590 us)
  76664       INDEX RANGE SCAN IND_T1_C3 (cr=163 pr=176 pw=0 time=13038 us)(object id 51683)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      13        0.00          0.00
  SQL*Net message from client                    13        0.01          0.01
  db file scattered read                       4181        0.04          3.47
  SQL*Net more data to client                    46        0.00          0.00
  db file sequential read                       206        0.03          0.13 

Even though the Standard Edition read more blocks from disk, and performed considerably more consistent gets, it executed the SQL statement 0.25 seconds faster than the Enterprise Edition.  Enterprise Edition certainly gnerated a more interesting execution plan.  So, why are the consistent gets significantly less than the number of blocks read from disk (cr= and query indicates consistent gets, pr= and disk indicates blocks read from disk)?  Is the difference caused by a bug (scroll down and compare with the output from 11.2.0.1)?  Moving on to the second SQL statement.

Standard Edition:

SQL> SELECT /* FIND_ME */
  2    T1.C4,
  3    T2.C4
  4  FROM
  5    T1,
  6    T2
  7  WHERE
  8    T1.C2='MONDAY'
  9    AND T1.C3 BETWEEN 200 AND 255
 10    AND T1.C1=T2.C1
 11    AND T1.C3=T2.C3;

9484744 rows selected.

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      85913  consistent gets
      77121  physical reads
          0  redo size
  125651171  bytes sent via SQL*Net to client
     104796  bytes received via SQL*Net from client
       9486  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
    9484744  rows processed  

Enterprise Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      54035  consistent gets
      72111  physical reads
          0  redo size
  125651171  bytes sent via SQL*Net to client
     104796  bytes received via SQL*Net from client
       9486  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
    9484744  rows processed 

The physical reads are close for the two editions, but again the consistent gets differs significantly.  Taking a look at the output of TKPROF.

Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.01       0.04          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch     9486      6.50      10.21      77121      85913          0     9484744
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     9490      6.52      10.26      77121      85913          0     9484744

Misses in library cache during parse: 1
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
9484744  HASH JOIN  (cr=85913 pr=77121 pw=0 time=3814912 us)
  10952   TABLE ACCESS FULL T1 (cr=38670 pr=38658 pw=0 time=20749036 us)
  76664   TABLE ACCESS FULL T2 (cr=47243 pr=38463 pw=0 time=2036828 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                    9487        0.00          0.00
  SQL*Net message from client                  9487        0.01          5.04
  db file sequential read                         2        0.01          0.01
  db file scattered read                        637        0.06          4.01
  SQL*Net more data to client                 56908        0.00          1.54 

Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.03       0.09          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch     9486      5.91       8.81      72111      54035          0     9484744
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     9490      5.94       8.91      72111      54035          0     9484744

Misses in library cache during parse: 1
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
9484744  HASH JOIN  (cr=54035 pr=72111 pw=0 time=2857143 us)
  10952   TABLE ACCESS BY INDEX ROWID T1 (cr=6870 pr=33648 pw=0 time=2991228 us)
  10952    BITMAP CONVERSION TO ROWIDS (cr=345 pr=376 pw=0 time=145613 us)
      2     BITMAP AND  (cr=345 pr=376 pw=0 time=172112 us)
     11      BITMAP CONVERSION FROM ROWIDS (cr=182 pr=200 pw=0 time=75187 us)
  71429       INDEX RANGE SCAN IND_T1_C2 (cr=182 pr=200 pw=0 time=35170 us)(object id 51682)
      3      BITMAP CONVERSION FROM ROWIDS (cr=163 pr=176 pw=0 time=89497 us)
  76664       SORT ORDER BY (cr=163 pr=176 pw=0 time=74771 us)
  76664        INDEX RANGE SCAN IND_T1_C3 (cr=163 pr=176 pw=0 time=30103 us)(object id 51683)
  76664   TABLE ACCESS FULL T2 (cr=47165 pr=38463 pw=0 time=1095520 us)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                    9487        0.00          0.00
  SQL*Net message from client                  9487        0.01          5.34
  db file scattered read                       4499        0.04          2.78
  db file sequential read                       207        0.01          0.05
  SQL*Net more data to client                 56908        0.00          1.18 

In the Standard Edition, we see that Oracle performed a full table scan of table T1 and T2, and joined those tables using a hash join.  Enterprise Edition was much more creative when generating the execution plan, allowing it to complete 1.35 seconds faster.  Are we seeing another bug on the second line of the Row Source Operation execution plan with the accounting of the consistent gets and physical reads?

——————–

Repeating the tests with the Standard Edition of 11.2.0.1 and the Enterprise Edition of 11.2.0.1.

Standard Edition:

SQL> SELECT /* FIND_ME */
  2    T1.C4
  3  FROM
  4    T1
  5  WHERE
  6    T1.C2='MONDAY'
  7    AND T1.C3 BETWEEN 200 AND 255;

10952 rows selected.

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      38680  consistent gets
      38658  physical reads
          0  redo size
     104990  bytes sent via SQL*Net to client
        629  bytes received via SQL*Net from client
         12  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      10952  rows processed 

Enterprise Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
       6874  consistent gets
       7700  physical reads
          0  redo size
     104990  bytes sent via SQL*Net to client
        630  bytes received via SQL*Net from client
         12  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      10952  rows processed 

Interesting, Enterprise Edition performed roughly 20% of the consistent gets and physical reads reported by Standard Edition. Taking a look at the output of TKPROF.

Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       12      0.34       2.87      38658      38680          0       10952
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       14      0.35       2.89      38658      38680          0       10952

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
  10952  TABLE ACCESS FULL T1 (cr=38680 pr=38658 pw=0 time=2879855 us cost=3041 size=234234 card=11154)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      12        0.00          0.00
  db file sequential read                         1        0.01          0.01
  db file scattered read                        319        0.04          2.55
  SQL*Net message from client                    12        0.00          0.00
  SQL*Net more data to client                    11        0.00          0.00 

Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       12      0.17       3.29       7700       6874          0       10952
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       14      0.18       3.31       7700       6874          0       10952

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
  10952  TABLE ACCESS BY INDEX ROWID T1 (cr=6874 pr=7700 pw=0 time=15073 us cost=2976 size=234234 card=11154)
  10952   BITMAP CONVERSION TO ROWIDS (cr=346 pr=376 pw=0 time=1417 us)
      2    BITMAP AND  (cr=346 pr=376 pw=0 time=31853 us)
     11     BITMAP CONVERSION FROM ROWIDS (cr=183 pr=200 pw=0 time=27060 us)
  71429      INDEX RANGE SCAN IND_T1_C2 (cr=183 pr=200 pw=0 time=11755 us cost=194 size=0 card=0)(object id 83186)
      3     BITMAP CONVERSION FROM ROWIDS (cr=163 pr=176 pw=0 time=10656 us)
  76664      SORT ORDER BY (cr=163 pr=176 pw=0 time=9598 us)
  76664       INDEX RANGE SCAN IND_T1_C3 (cr=163 pr=176 pw=0 time=8830 us cost=164 size=0 card=0)(object id 83187)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      12        0.00          0.00
  db file scattered read                        202        0.02          0.33
  SQL*Net message from client                    12        0.00          0.00
  db file parallel read                         274        0.05          2.78
  SQL*Net more data to client                    11        0.00          0.00
  db file sequential read                         1        0.00          0.00 

Are you ready to toss out the Enterprise Edition?  Even though Standard Edition perform 5 times as many physical block reads and 5 times as many consistent gets, it completed the query 0.42 seconds faster.  Spend some time comparing the Row Source Operation execution plan with that of 10.2.0.5 – which Enterprise Edition contains the bug in the reporting of physical block reads and/or consistent gets?  Continuing with the second SQL statement:

Standard Edition:

SQL> SELECT /* FIND_ME */
  2    T1.C4,
  3    T2.C4
  4  FROM
  5    T1,
  6    T2
  7  WHERE
  8    T1.C2='MONDAY'
  9    AND T1.C3 BETWEEN 200 AND 255
 10    AND T1.C1=T2.C1
 11    AND T1.C3=T2.C3;

9484744 rows selected.

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      85894  consistent gets
      77121  physical reads
          0  redo size
  125651186  bytes sent via SQL*Net to client
     104843  bytes received via SQL*Net from client
       9486  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
    9484744  rows processed 

Enterprise Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      54096  consistent gets
      46238  physical reads
          0  redo size
  125651186  bytes sent via SQL*Net to client
     104844  bytes received via SQL*Net from client
       9486  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
    9484744  rows processed 

Taking a look at the output of TKPROF.

Standard Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch     9486      4.11       7.24      77121      85894          0     9484744
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     9488      4.13       7.26      77121      85894          0     9484744

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
9484744  HASH JOIN  (cr=85894 pr=77121 pw=0 time=2663572 us cost=6087 size=2994849 card=76791)
  10952   TABLE ACCESS FULL T1 (cr=38670 pr=38658 pw=0 time=6680619 us cost=3041 size=267696 card=11154)
  76664   TABLE ACCESS FULL T2 (cr=47224 pr=38463 pw=0 time=1238145 us cost=3045 size=1171125 card=78075)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                    9486        0.00          0.00
  db file sequential read                         2        0.01          0.02
  db file scattered read                        637        0.04          2.82
  SQL*Net message from client                  9486        0.00         10.21
  SQL*Net more data to client                  9485        0.00          0.35
  asynch descriptor resize                        1        0.00          0.00 

Enterprise Edition:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch     9486      4.71       7.46      46238      54096          0     9484744
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     9488      4.72       7.48      46238      54096          0     9484744

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
9484744  HASH JOIN  (cr=54096 pr=46238 pw=0 time=2306193 us cost=6022 size=2994849 card=76791)
  10952   TABLE ACCESS BY INDEX ROWID T1 (cr=6870 pr=7775 pw=0 time=2895266 us cost=2976 size=267696 card=11154)
  10952    BITMAP CONVERSION TO ROWIDS (cr=345 pr=376 pw=0 time=2292 us)
      2     BITMAP AND  (cr=345 pr=376 pw=0 time=30695 us)
     11      BITMAP CONVERSION FROM ROWIDS (cr=182 pr=200 pw=0 time=25870 us)
  71429       INDEX RANGE SCAN IND_T1_C2 (cr=182 pr=200 pw=0 time=11883 us cost=194 size=0 card=0)(object id 83186)
      3      BITMAP CONVERSION FROM ROWIDS (cr=163 pr=176 pw=0 time=11066 us)
  76664       SORT ORDER BY (cr=163 pr=176 pw=0 time=12158 us)
  76664        INDEX RANGE SCAN IND_T1_C3 (cr=163 pr=176 pw=0 time=10878 us cost=164 size=0 card=0)(object id 83187)
  76664   TABLE ACCESS FULL T2 (cr=47226 pr=38463 pw=0 time=291011 us cost=3045 size=1171125 card=78075)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                    9486        0.00          0.00
  db file scattered read                        210        0.03          0.34
  db file parallel read                         274        0.04          2.69
  db file sequential read                         2        0.01          0.01
  direct path read                                9        0.01          0.04
  SQL*Net message from client                  9486        0.00         10.33
  SQL*Net more data to client                  9485        0.00          0.35
  asynch descriptor resize                        2        0.00          0.00 

Standard Edition again performed more consistent gets and physical reads than Enterprise Edition, yet it completed the execution 0.22 seconds faster than Enterprise Edition.  Compare the output of the Enterprise Edition of 11.2.0.1 with that of the Enterprise Edition of 10.2.0.5 – which release version is incorrectly reporting the number of physical reads and/or consistent gets?

——

Things to try:

  • Change some of the manually specified system (CPU) statistics, what statistic values will cause the Standard Edition to perform index range scans rather than full table scans?
  • Modify the SQL statements that join table T1 to table T2 so that instead of selecting from table T2, select from T1 aliased as T2 (create a self join).  How do the statistics generated by 10.2.0.5 differ from those generated by 11.2.0.1 when this change is made?
  • Change MONDAY to Monday in the SQL statements, and repeat the test - do the execution plans change when the test is repeated?
  • Change MONDAY to Monday in the SQL statements, generate histograms for the various column, and repeat the test  - do the execution plans change when the test is repeated?

Sample commands to generate histograms:

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',ESTIMATE_PERCENT=>NULL,METHOD_OPT=>'FOR ALL COLUMNS SIZE 254',NO_INVALIDATE=>FALSE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',ESTIMATE_PERCENT=>NULL,METHOD_OPT=>'FOR ALL COLUMNS SIZE 254',NO_INVALIDATE=>FALSE)

——

We might need another test script, one which joins several tables having primary and foreign keys, before we see any significant performance differences.  Yet, the results of the above script are interesting.





Different Performance from Standard Edition and Enterprise Edition? 2

21 11 2010

November 21, 2010

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

In the previous article in this series I compared the Standard Edition of Oracle 10.2.0.5 with the Enterprise Edition of Oracle 10.2.0.5 when a simple SQL statement was executed, looking for examples of different performances in the two editions.  This article repeats the tests from the previous article, this time with the Standard Edition of Oracle 11.2.0.1 and the Enterprise Edition of Oracle 11.2.0.1.  Once again, the following workload CPU (system) statistics will be set for both databases:

EXEC DBMS_STATS.SET_SYSTEM_STATS('MBRC',16)
EXEC DBMS_STATS.SET_SYSTEM_STATS('CPUSPEED',2664)
EXEC DBMS_STATS.SET_SYSTEM_STATS('SREADTIM',8)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MREADTIM',10)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MAXTHR',19181568)

The test table and its index are created:

CREATE TABLE T1 NOLOGGING AS
SELECT
  MOD(ROWNUM, 100000) ID,
  LPAD('A',100,'A') A
FROM
  DUAL
CONNECT BY
  LEVEL <= 1000000;

CREATE INDEX IND_T1_ID ON T1(ID) NOLOGGING;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',ESTIMATE_PERCENT=>NULL,METHOD_OPT=>'FOR ALL COLUMNS SIZE 1')

SELECT
  SEGMENT_NAME SEGMENT,
  COUNT(*) EXTENTS,
  BYTES/1024 EXT_SIZE_KB,
  (COUNT(*) * BYTES)/1048576 TOTAL_MB
FROM
  DBA_EXTENTS
WHERE
  OWNER=USER
  AND SEGMENT_NAME IN ('IND_T1_ID','T1')
GROUP BY
  SEGMENT_NAME,
  BYTES
ORDER BY
  SEGMENT_NAME,
  BYTES;

Just like in the earlier article, the table was created in an ASSM autoallocate tablespace, so the extents for the objects appeared as follows:

SEGMENT         EXTENTS EXT_SIZE_KB   TOTAL_MB
------------ ---------- ----------- ----------
IND_T1_ID            16          64          1
IND_T1_ID            17        1024         17
T1                   16          64          1
T1                   63        1024         63
T1                    8        8192         64 

If we execute the test script:

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ INDEX(T1) */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ INDEX(T1) IND */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

We see the following statistics output by the two editions (once again, only from the second half of the script):

Standard Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      90292  consistent gets
       1629  physical reads
          0  redo size
     503259  bytes sent via SQL*Net to client
       1509  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed 

Enterprise Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      90292  consistent gets
       1623  physical reads
          0  redo size
     503259  bytes sent via SQL*Net to client
       1510  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed 

Just as in the earlier article, we see that the Standard edition performed more physical block reads than the Enterprise edition.  Next, taking a look at the captured trace files using TKPROF.

Standard  Edition:

SELECT /*+ INDEX(T1) IND */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       92      0.15       0.45       1629      90292          0       90010
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       94      0.17       0.47       1629      90292          0       90010

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 51 

Rows     Row Source Operation
-------  ---------------------------------------------------
  90010  TABLE ACCESS BY INDEX ROWID T1 (cr=90292 pr=1629 pw=0 time=125858 us cost=90255 size=9542226 card=90021)
  90010   INDEX RANGE SCAN IND_T1_ID (cr=282 pr=216 pw=0 time=17668 us cost=203 size=0 card=90021)(object id 20276)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      92        0.00          0.00
  db file scattered read                         47        0.03          0.10
  SQL*Net message from client                    92        0.00          0.11
  db file parallel read                          24        0.03          0.03
  db file sequential read                      1222        0.02          0.11 

Enterprise Edition:

SELECT /*+ INDEX(T1) IND */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.01          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       92      0.15       0.69       1623      90292          0       90010
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       94      0.18       0.71       1623      90292          0       90010

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 194 

Rows     Row Source Operation
-------  ---------------------------------------------------
  90010  TABLE ACCESS BY INDEX ROWID T1 (cr=90292 pr=1623 pw=0 time=131236 us cost=90255 size=9542226 card=90021)
  90010   INDEX RANGE SCAN IND_T1_ID (cr=282 pr=216 pw=0 time=16516 us cost=203 size=0 card=90021)(object id 83180)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      92        0.00          0.00
  db file scattered read                         54        0.05          0.31
  SQL*Net message from client                    92        0.00          0.12
  db file parallel read                          18        0.04          0.04
  db file sequential read                      1214        0.00          0.11 

From the above, it appears that the Standard Edition of Oracle Database 11.2.0.1 has gained the ability to use db file parallel reads for this SQL statement – it performed 24 such reads, while the Enterprise Edition only performed 18.  The difference probably means that we will see some interesting differences in the generated trace files.

Once again, the only difference in the 10053 portion of the trace files was this line:

parallel_execution_enabled          = false   /* This is True in Enterprise Edition */ 

 Let’s take a look at the 10046 portion of the trace file, specifically the retrieval of the first 2,001 rows.

Standard Edition (obj# 20275 is the table T1, obj# 20276 is the index):

PARSE #2:c=15600,e=17980,p=0,cr=0,cu=0,mis=1,r=0,dep=0,og=1,plh=2892477391,tim=176265018485
EXEC #2:c=0,e=24,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=2892477391,tim=176265018563
WAIT #2: nam='SQL*Net message to client' ela= 2 driver id=1413697536 #bytes=1 p3=0 obj#=0 tim=176265018598
WAIT #2: nam='db file scattered read' ela= 76 file#=8 block#=8320 blocks=8 obj#=20276 tim=176265018735
WAIT #2: nam='db file scattered read' ela= 19381 file#=8 block#=8648 blocks=8 obj#=20276 tim=176265038168
WAIT #2: nam='db file scattered read' ela= 102 file#=8 block#=8344 blocks=8 obj#=20276 tim=176265038360
WAIT #2: nam='db file scattered read' ela= 98 file#=7 block#=3200 blocks=8 obj#=20275 tim=176265038517
FETCH #2:c=0,e=19935,p=32,cr=4,cu=0,mis=0,r=1,dep=0,og=1,plh=2892477391,tim=176265038551
WAIT #2: nam='SQL*Net message from client' ela= 284 driver id=1413697536 #bytes=1 p3=0 obj#=20275 tim=176265038872
WAIT #2: nam='db file parallel read' ela= 36748 files=2 blocks=9 requests=9 obj#=20275 tim=176265075691
WAIT #2: nam='db file scattered read' ela= 32752 file#=7 block#=3992 blocks=8 obj#=20275 tim=176265108569
WAIT #2: nam='SQL*Net message to client' ela= 2 driver id=1413697536 #bytes=1 p3=0 obj#=20275 tim=176265108641
WAIT #2: nam='db file sequential read' ela= 80 file#=8 block#=6462 blocks=1 obj#=20275 tim=176265108867
WAIT #2: nam='db file sequential read' ela= 67 file#=8 block#=948 blocks=1 obj#=20275 tim=176265109051
WAIT #2: nam='db file sequential read' ela= 62 file#=8 block#=2537 blocks=1 obj#=20275 tim=176265109286
WAIT #2: nam='db file sequential read' ela= 69 file#=7 block#=4000 blocks=1 obj#=20275 tim=176265109526
WAIT #2: nam='db file sequential read' ela= 29 file#=8 block#=5940 blocks=1 obj#=20275 tim=176265109709
WAIT #2: nam='db file sequential read' ela= 64 file#=8 block#=148 blocks=1 obj#=20275 tim=176265109901
WAIT #2: nam='db file sequential read' ela= 64 file#=7 block#=6981 blocks=1 obj#=20275 tim=176265110070
WAIT #2: nam='db file sequential read' ela= 62 file#=8 block#=1743 blocks=1 obj#=20275 tim=176265110247
WAIT #2: nam='db file sequential read' ela= 67 file#=7 block#=4398 blocks=1 obj#=20275 tim=176265110606
WAIT #2: nam='db file sequential read' ela= 65 file#=8 block#=6463 blocks=1 obj#=20275 tim=176265110842
WAIT #2: nam='db file sequential read' ela= 62 file#=8 block#=949 blocks=1 obj#=20275 tim=176265111020
WAIT #2: nam='db file sequential read' ela= 67 file#=8 block#=2538 blocks=1 obj#=20275 tim=176265111323
WAIT #2: nam='db file scattered read' ela= 101 file#=7 block#=4001 blocks=7 obj#=20275 tim=176265111656
FETCH #2:c=0,e=72863,p=36,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,plh=2892477391,tim=176265111762
WAIT #2: nam='SQL*Net message from client' ela= 1318 driver id=1413697536 #bytes=1 p3=0 obj#=20275 tim=176265113117
WAIT #2: nam='SQL*Net message to client' ela= 0 driver id=1413697536 #bytes=1 p3=0 obj#=20275 tim=176265113177
WAIT #2: nam='db file sequential read' ela= 67 file#=8 block#=5941 blocks=1 obj#=20275 tim=176265113282
WAIT #2: nam='db file sequential read' ela= 63 file#=8 block#=149 blocks=1 obj#=20275 tim=176265113449
WAIT #2: nam='db file sequential read' ela= 84 file#=7 block#=6982 blocks=1 obj#=20275 tim=176265113648
WAIT #2: nam='db file sequential read' ela= 53 file#=8 block#=1744 blocks=1 obj#=20275 tim=176265113797
WAIT #2: nam='db file sequential read' ela= 63 file#=7 block#=4399 blocks=1 obj#=20275 tim=176265114104
WAIT #2: nam='db file sequential read' ela= 63 file#=8 block#=6464 blocks=1 obj#=20275 tim=176265114305
WAIT #2: nam='db file sequential read' ela= 34 file#=8 block#=950 blocks=1 obj#=20275 tim=176265114420
WAIT #2: nam='db file sequential read' ela= 77 file#=8 block#=2539 blocks=1 obj#=20275 tim=176265114639
WAIT #2: nam='db file sequential read' ela= 65 file#=8 block#=5942 blocks=1 obj#=20275 tim=176265114953
WAIT #2: nam='db file sequential read' ela= 27 file#=8 block#=150 blocks=1 obj#=20275 tim=176265115064
WAIT #2: nam='db file sequential read' ela= 37 file#=7 block#=6983 blocks=1 obj#=20275 tim=176265115189
WAIT #2: nam='db file sequential read' ela= 66 file#=8 block#=1745 blocks=1 obj#=20275 tim=176265115337
WAIT #2: nam='db file sequential read' ela= 67 file#=7 block#=3208 blocks=1 obj#=20275 tim=176265115541
WAIT #2: nam='db file sequential read' ela= 49 file#=7 block#=4400 blocks=1 obj#=20275 tim=176265115721
FETCH #2:c=15600,e=2675,p=14,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,plh=2892477391,tim=176265115823 

Enterprise Edition (obj# 83179 is the table T1, obj# 83180 is the index):

PARSE #1:c=31200,e=18656,p=0,cr=0,cu=0,mis=1,r=0,dep=0,og=1,plh=2892477391,tim=176274491584
EXEC #1:c=0,e=28,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=2892477391,tim=176274491668
WAIT #1: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=0 tim=176274491707
WAIT #1: nam='db file scattered read' ela= 19945 file#=8 block#=170816 blocks=8 obj#=83180 tim=176274511716
WAIT #1: nam='db file scattered read' ela= 18407 file#=7 block#=1762512 blocks=8 obj#=83180 tim=176274530199
WAIT #1: nam='db file scattered read' ela= 20079 file#=7 block#=1638560 blocks=8 obj#=83180 tim=176274550345
WAIT #1: nam='db file scattered read' ela= 13687 file#=7 block#=1637552 blocks=8 obj#=83179 tim=176274564106
FETCH #1:c=0,e=72429,p=32,cr=4,cu=0,mis=0,r=1,dep=0,og=1,plh=2892477391,tim=176274564157
WAIT #1: nam='SQL*Net message from client' ela= 369 driver id=1413697536 #bytes=1 p3=0 obj#=83179 tim=176274564557
WAIT #1: nam='db file parallel read' ela= 48042 files=2 blocks=9 requests=9 obj#=83179 tim=176274612665
WAIT #1: nam='db file scattered read' ela= 20902 file#=7 block#=1638344 blocks=8 obj#=83179 tim=176274633689
WAIT #1: nam='SQL*Net message to client' ela= 2 driver id=1413697536 #bytes=1 p3=0 obj#=83179 tim=176274633751
WAIT #1: nam='db file sequential read' ela= 108 file#=7 block#=1760446 blocks=1 obj#=83179 tim=176274634001
WAIT #1: nam='db file sequential read' ela= 121 file#=7 block#=1639273 blocks=1 obj#=83179 tim=176274634381
WAIT #1: nam='db file sequential read' ela= 105 file#=8 block#=133664 blocks=1 obj#=83179 tim=176274634695
WAIT #1: nam='db file sequential read' ela= 103 file#=7 block#=1759924 blocks=1 obj#=83179 tim=176274634995
WAIT #1: nam='db file sequential read' ela= 103 file#=8 block#=170764 blocks=1 obj#=83179 tim=176274635264
WAIT #1: nam='db file sequential read' ela= 111 file#=8 block#=136645 blocks=1 obj#=83179 tim=176274635523
WAIT #1: nam='db file sequential read' ela= 111 file#=8 block#=132870 blocks=1 obj#=83179 tim=176274635889
WAIT #1: nam='db file sequential read' ela= 101 file#=8 block#=134062 blocks=1 obj#=83179 tim=176274636191
WAIT #1: nam='db file sequential read' ela= 109 file#=7 block#=1760447 blocks=1 obj#=83179 tim=176274636516
WAIT #1: nam='db file sequential read' ela= 104 file#=7 block#=1639274 blocks=1 obj#=83179 tim=176274636927
WAIT #1: nam='db file sequential read' ela= 104 file#=8 block#=133665 blocks=1 obj#=83179 tim=176274637262
FETCH #1:c=0,e=72866,p=28,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,plh=2892477391,tim=176274637445
WAIT #1: nam='SQL*Net message from client' ela= 1388 driver id=1413697536 #bytes=1 p3=0 obj#=83179 tim=176274638863
WAIT #1: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=83179 tim=176274638948
WAIT #1: nam='db file sequential read' ela= 117 file#=7 block#=1759925 blocks=1 obj#=83179 tim=176274639125
WAIT #1: nam='db file sequential read' ela= 103 file#=8 block#=170765 blocks=1 obj#=83179 tim=176274639381
WAIT #1: nam='db file sequential read' ela= 105 file#=8 block#=136646 blocks=1 obj#=83179 tim=176274639640
WAIT #1: nam='db file scattered read' ela= 1204 file#=7 block#=1638352 blocks=8 obj#=83179 tim=176274641051
WAIT #1: nam='db file sequential read' ela= 117 file#=8 block#=132871 blocks=1 obj#=83179 tim=176274641320
WAIT #1: nam='db file sequential read' ela= 105 file#=8 block#=134063 blocks=1 obj#=83179 tim=176274641630
WAIT #1: nam='db file sequential read' ela= 104 file#=7 block#=1760448 blocks=1 obj#=83179 tim=176274641938
WAIT #1: nam='db file sequential read' ela= 106 file#=7 block#=1639275 blocks=1 obj#=83179 tim=176274642303
WAIT #1: nam='db file sequential read' ela= 104 file#=8 block#=133666 blocks=1 obj#=83179 tim=176274642618
WAIT #1: nam='db file sequential read' ela= 101 file#=7 block#=1759926 blocks=1 obj#=83179 tim=176274642919
WAIT #1: nam='db file sequential read' ela= 106 file#=8 block#=170766 blocks=1 obj#=83179 tim=176274643172
WAIT #1: nam='db file sequential read' ela= 109 file#=8 block#=136647 blocks=1 obj#=83179 tim=176274643432
WAIT #1: nam='db file sequential read' ela= 104 file#=8 block#=132872 blocks=1 obj#=83179 tim=176274643787
WAIT #1: nam='db file sequential read' ela= 102 file#=8 block#=134064 blocks=1 obj#=83179 tim=176274644089
FETCH #1:c=0,e=5354,p=21,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,plh=2892477391,tim=176274644260 

Other than the location of the 7 block read using db file scattered read (before or after the second fetch), there is not much that apparently differentiates the two trace files.  Most of the blocks read in both trace files are read a single block at a time, with an occasional db file parallel read for two blocks or a db file scattered read for 7 or 8 blocks.

Forcing a full table scan produced the same statistics in both editions:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      15484  consistent gets
      15386  physical reads
          0  redo size
     826473  bytes sent via SQL*Net to client
       1509  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed  

What about the test that included the PARALLEL and FULL hints?

Standard Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      15484  consistent gets
      15386  physical reads
          0  redo size
     826473  bytes sent via SQL*Net to client
       1509  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed 

Enterprise Edition:

Statistics
---------------------------------------------------
         25  recursive calls
          0  db block gets
      15723  consistent gets
      15386  physical reads
          0  redo size
     826473  bytes sent via SQL*Net to client
       1510  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed 

Obviously, we should have expected some differences between the two editions when the PARALLEL hint was included, and we see a slight increase in the number of consistent gets, and 24 additional recursive calls.  Let’s take a look at the Row Source Operation execution plan from the raw trace file for the SQL statement with the PARALLEL hint.

Standard Edition:

STAT #3 id=1 cnt=90010 pid=0 pos=1 obj=20275 op='TABLE ACCESS FULL T1 (cr=15484 pr=15386 pw=0 time=23430 us cost=1231 size=9542226 card=90021)' 

Enterprise Edition:

STAT #8 id=1 cnt=90010 pid=0 pos=1 obj=0 op='PX COORDINATOR  (cr=5 pr=1 pw=0 time=14980 us)'
STAT #8 id=2 cnt=0 pid=1 pos=1 obj=0 op='PX SEND QC (RANDOM) :TQ10000 (cr=0 pr=0 pw=0 time=0 us cost=170 size=9542226 card=90021)'
STAT #8 id=3 cnt=0 pid=2 pos=1 obj=0 op='PX BLOCK ITERATOR (cr=0 pr=0 pw=0 time=0 us cost=170 size=9542226 card=90021)'
STAT #8 id=4 cnt=0 pid=3 pos=1 obj=83179 op='TABLE ACCESS FULL T1 (cr=0 pr=0 pw=0 time=0 us cost=170 size=9542226 card=90021)'  

———–

At least for the above simple test scripts, there is difference in the performance for the Standard Edition and the Enterprise Edition (as long as parallel execution is not attempted to be used).  The test case is, however, interesting as it illustrates potential differences in the performance when upgrading from Oracle Database 10.2.0.5 to Oracle Database 11.2.0.1.  We likely need a more complicated test case script to demonstrate the differences in performance for the two editions of Oracle Database 11.2.0.1.





Different Performance from Standard Edition and Enterprise Edition? 1

21 11 2010

November 21, 2010

(Forward to the Next Post in the Series)

As I am sure that quite a few people are aware, the Standard Edition of Oracle Database is likely to be suitable for many of the smaller databases that you might find in your organization, as long as the following are not needed:

  • Parallel execution
  • Bitmap indexes
  • Conversion of B*tree indexes to bitmap indexes in execution plans to permit bitmap index join operations
  • Partitioning (this is an extra cost option)
  • Diagnostic Pack, Tuning Pack, and the other extra cost license options
  • Streams
  • ???

Are there other differences, possibly related to optimizer or execution behavior?  I created a 10.2.0.5 database on the Standard Edition and Enterprise Edition, and then performed a couple of tests.  First, I specified the following CPU (system) statistics for both databases to help eliminate potential differences in the workload statistics:

EXEC DBMS_STATS.SET_SYSTEM_STATS('MBRC',16)
EXEC DBMS_STATS.SET_SYSTEM_STATS('CPUSPEED',2664)
EXEC DBMS_STATS.SET_SYSTEM_STATS('SREADTIM',8)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MREADTIM',10)
EXEC DBMS_STATS.SET_SYSTEM_STATS('MAXTHR',19181568)

Next, a simple table is created with an index in an ASSM autoallocate tablespace, the table and index statistics are collected at a 100% sample size without histograms, and then the table and index extent sizes are displayed:

CREATE TABLE T1 NOLOGGING AS
SELECT
  MOD(ROWNUM, 100000) ID,
  LPAD('A',100,'A') A
FROM
  DUAL
CONNECT BY
  LEVEL <= 1000000;

CREATE INDEX IND_T1_ID ON T1(ID) NOLOGGING;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T1',ESTIMATE_PERCENT=>NULL,METHOD_OPT=>'FOR ALL COLUMNS SIZE 1')

SELECT
  SEGMENT_NAME SEGMENT,
  COUNT(*) EXTENTS,
  BYTES/1024 EXT_SIZE_KB,
  (COUNT(*) * BYTES)/1048576 TOTAL_MB
FROM
  DBA_EXTENTS
WHERE
  OWNER=USER
  AND SEGMENT_NAME IN ('IND_T1_ID','T1')
GROUP BY
  SEGMENT_NAME,
  BYTES
ORDER BY
  SEGMENT_NAME,
  BYTES;

SEGMENT         EXTENTS EXT_SIZE_KB   TOTAL_MB
------------ ---------- ----------- ----------
IND_T1_ID            16          64          1
IND_T1_ID            17        1024         17
T1                   16          64          1
T1                   63        1024         63
T1                    8        8192         64

The output of the above query was identical for both databases.

Now the test script with a very simple SQL statement, where the test script is actually divided into two halves, the first of which will be thrown away so that physical reads from recursive SQL statements may be factored out.  In the test script:

  • The buffer cache is flushed twice to force physical reads
  • The fetch array size for SQL*Plus is set to 1,000 rows
  • Output of the rows to the screen is surpressed
  • The trace file is given a name, making it easy to find the trace file at a later time
  • A 10046 trace at level 8 (wait events), and a 10053 trace at level 1 (to permit seeing the query optimizer’s decisions) are enabled
  • The test query is executed with a hint to force an index access path, if one exists
  • The above steps are repeated a second time (only the results of the second execution are used).
ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ INDEX(T1) */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ INDEX(T1) IND */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

What are the statistics displayed by autotrace?

Standard Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      90292  consistent gets
       1669  physical reads
          0  redo size
     503244  bytes sent via SQL*Net to client
       1462  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed

Enterprise Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      90292  consistent gets
       1585  physical reads
          0  redo size
     503244  bytes sent via SQL*Net to client
       1482  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed

Notice in the above the difference in the number of blocks read by physical reads, the Standard Edition performed an additional 84 block reads (some of these might have been multi-block reads).  Why the difference?  Was it because the SQL*Plus client from 11.2.0.1 was connected to the Standard Edition, and the SQL*Plus client from 10.2.0.5 was connected to the Enterprise Edition?  Let’s take a look at the TKPROF summaries (processed by TKPROF from 10.2.0.5):

Standard Edition:

SELECT /*+ INDEX(T1) IND */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       92      0.14       1.28       1669      90292          0       90010
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       94      0.15       1.31       1669      90292          0       90010

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47 

Rows     Row Source Operation
-------  ---------------------------------------------------
  90010  TABLE ACCESS BY INDEX ROWID T1 (cr=90292 pr=1669 pw=0 time=157359 us)
  90010   INDEX RANGE SCAN IND_T1_ID (cr=282 pr=202 pw=0 time=48156 us)(object id 47848)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      92        0.00          0.00
  db file sequential read                         5        0.04          0.06
  db file scattered read                        208        0.03          1.06
  SQL*Net message from client                    92        0.00          0.09
  SQL*Net more data to client                   180        0.00          0.00

Enterprise Edition:

SELECT /*+ INDEX(T1) IND */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch       92      0.28       1.33       1585      90292          0       90010
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       94      0.29       1.36       1585      90292          0       90010

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 164 

Rows     Row Source Operation
-------  ---------------------------------------------------
  90010  TABLE ACCESS BY INDEX ROWID T1 (cr=90292 pr=1585 pw=0 time=128823 us)
  90010   INDEX RANGE SCAN IND_T1_ID (cr=282 pr=191 pw=0 time=33849 us)(object id 51663)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                      93        0.00          0.00
  SQL*Net message from client                    93        0.00          0.14
  db file sequential read                      1506        0.02          0.95
  db file parallel read                          36        0.02          0.08
  SQL*Net more data to client                   180        0.00          0.00

In the above, we see that physical reads only happened during the fetch, the Row Source Operation execution plans are identical, and yet the wait events are different.

Let’s look at the 10053 output in the raw trace file.

Standard Edition:

PARAMETERS USED BY THE OPTIMIZER
********************************
  *************************************
  PARAMETERS WITH ALTERED VALUES
  ******************************
  _pga_max_size                       = 368640 KB
  sqlstat_enabled                     = true
  *********************************
  Bug Fix Control Environment
  ***************************
  fix  4611850 = enabled
  fix  4663804 = enabled
...
  fix  8855396 = enabled
  *************************************
  PARAMETERS WITH DEFAULT VALUES
  ******************************
  optimizer_mode_hinted               = false
  optimizer_features_hinted           = 0.0.0
  parallel_execution_enabled          = false     /* This is the only difference */
  parallel_query_forced_dop           = 0
  parallel_dml_forced_dop             = 0
  parallel_ddl_forced_degree          = 0
  parallel_ddl_forced_instances       = 0
  _query_rewrite_fudge                = 90
  optimizer_features_enable           = 10.2.0.5
  _optimizer_search_limit             = 5
  cpu_count                           = 8
  active_instance_count               = 1
  parallel_threads_per_cpu            = 2
  hash_area_size                      = 131072
  bitmap_merge_area_size              = 1048576
  sort_area_size                      = 65536
  sort_area_retained_size             = 0
  _sort_elimination_cost_ratio        = 0
  _optimizer_block_size               = 8192
  _sort_multiblock_read_count         = 2
  _hash_multiblock_io_count           = 0
  _db_file_optimizer_read_count       = 8
  _optimizer_max_permutations         = 2000
  pga_aggregate_target                = 1843200 KB
  _query_rewrite_maxdisjunct          = 257
  _smm_auto_min_io_size               = 56 KB
  _smm_auto_max_io_size               = 248 KB
  _smm_min_size                       = 1024 KB
  _smm_max_size                       = 184320 KB
  _smm_px_max_size                    = 921600 KB
  _cpu_to_io                          = 0
  _optimizer_undo_cost_change         = 10.2.0.5
  parallel_query_mode                 = enabled
  parallel_dml_mode                   = disabled
  parallel_ddl_mode                   = enabled
  optimizer_mode                      = all_rows
...

Enterprise Edition:

PARAMETERS USED BY THE OPTIMIZER
********************************
  *************************************
  PARAMETERS WITH ALTERED VALUES
  ******************************
  _pga_max_size                       = 368640 KB
  sqlstat_enabled                     = true
  *********************************
  Bug Fix Control Environment
  ***************************
  fix  4611850 = enabled
  fix  4663804 = enabled
...
  fix  8855396 = enabled
  *************************************
  PARAMETERS WITH DEFAULT VALUES
  ******************************
  optimizer_mode_hinted               = false
  optimizer_features_hinted           = 0.0.0
  parallel_execution_enabled          = true      /* This is the only difference */
  parallel_query_forced_dop           = 0
  parallel_dml_forced_dop             = 0
  parallel_ddl_forced_degree          = 0
  parallel_ddl_forced_instances       = 0
  _query_rewrite_fudge                = 90
  optimizer_features_enable           = 10.2.0.5
  _optimizer_search_limit             = 5
  cpu_count                           = 8
  active_instance_count               = 1
  parallel_threads_per_cpu            = 2
  hash_area_size                      = 131072
  bitmap_merge_area_size              = 1048576
  sort_area_size                      = 65536
  sort_area_retained_size             = 0
  _sort_elimination_cost_ratio        = 0
  _optimizer_block_size               = 8192
  _sort_multiblock_read_count         = 2
  _hash_multiblock_io_count           = 0
  _db_file_optimizer_read_count       = 8
  _optimizer_max_permutations         = 2000
  pga_aggregate_target                = 1843200 KB
  _query_rewrite_maxdisjunct          = 257
  _smm_auto_min_io_size               = 56 KB
  _smm_auto_max_io_size               = 248 KB
  _smm_min_size                       = 1024 KB
  _smm_max_size                       = 184320 KB
  _smm_px_max_size                    = 921600 KB
  _cpu_to_io                          = 0
  _optimizer_undo_cost_change         = 10.2.0.5
  parallel_query_mode                 = enabled
  parallel_dml_mode                   = disabled
  parallel_ddl_mode                   = enabled
  optimizer_mode                      = all_rows
... 

Well, the 10053 portion of the trace file did not reveal much of a difference, other than parallel execution being disabled in Standard Edition, while it is enabled in Enterprise Edition.  Let’s take a look at the 10046 portion of the trace file, specifically the retrieval of the first 2,001 rows.

Standard Edition (obj# 47847 is the table T1, obj# 47848 is the index):

PARSE #20:c=15600,e=27480,p=0,cr=0,cu=0,mis=1,r=0,dep=0,og=1,tim=141267613561
EXEC #20:c=0,e=25,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,tim=141267613640
WAIT #20: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=141267613658
WAIT #20: nam='db file sequential read' ela= 19084 file#=8 block#=8204 blocks=1 obj#=47848 tim=141267632782
WAIT #20: nam='db file sequential read' ela= 7665 file#=8 block#=8535 blocks=1 obj#=47848 tim=141267640532
WAIT #20: nam='db file scattered read' ela= 21195 file#=8 block#=8225 blocks=8 obj#=47848 tim=141267661785
WAIT #20: nam='db file scattered read' ela= 19110 file#=7 block#=3081 blocks=8 obj#=47847 tim=141267680973
FETCH #20:c=0,e=67348,p=18,cr=4,cu=0,mis=0,r=1,dep=0,og=1,tim=141267681023
WAIT #20: nam='SQL*Net message from client' ela= 293 driver id=1413697536 #bytes=1 p3=0 obj#=47847 tim=141267681352
WAIT #20: nam='db file sequential read' ela= 41703 file#=7 block#=3880 blocks=1 obj#=47847 tim=141267723105
WAIT #20: nam='SQL*Net message to client' ela= 0 driver id=1413697536 #bytes=1 p3=0 obj#=47847 tim=141267723145
WAIT #20: nam='db file scattered read' ela= 18782 file#=7 block#=4273 blocks=8 obj#=47847 tim=141267741978
WAIT #20: nam='db file scattered read' ela= 16561 file#=7 block#=6857 blocks=8 obj#=47847 tim=141267758605
WAIT #20: nam='db file scattered read' ela= 32914 file#=8 block#=25 blocks=8 obj#=47847 tim=141267791584
WAIT #20: nam='db file scattered read' ela= 21405 file#=8 block#=825 blocks=8 obj#=47847 tim=141267813063
WAIT #20: nam='db file scattered read' ela= 16306 file#=8 block#=1617 blocks=8 obj#=47847 tim=141267829447
WAIT #20: nam='db file scattered read' ela= 11456 file#=8 block#=2417 blocks=8 obj#=47847 tim=141267840982
WAIT #20: nam='db file scattered read' ela= 17458 file#=8 block#=5817 blocks=8 obj#=47847 tim=141267858514
WAIT #20: nam='db file scattered read' ela= 6765 file#=8 block#=6337 blocks=8 obj#=47847 tim=141267865352
WAIT #20: nam='db file scattered read' ela= 21666 file#=7 block#=3881 blocks=8 obj#=47847 tim=141267887503
WAIT #20: nam='SQL*Net more data to client' ela= 33 driver id=1413697536 #bytes=2001 p3=0 obj#=47847 tim=141267887676
WAIT #20: nam='SQL*Net more data to client' ela= 18 driver id=1413697536 #bytes=2001 p3=0 obj#=47847 tim=141267888243
FETCH #20:c=0,e=207317,p=73,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,tim=141267888690
WAIT #20: nam='SQL*Net message from client' ela= 1209 driver id=1413697536 #bytes=1 p3=0 obj#=47847 tim=141267889922
WAIT #20: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=47847 tim=141267889993
WAIT #20: nam='db file scattered read' ela= 24491 file#=8 block#=1625 blocks=8 obj#=47847 tim=141267914777
WAIT #20: nam='SQL*Net more data to client' ela= 20 driver id=1413697536 #bytes=2001 p3=0 obj#=47847 tim=141267915146
WAIT #20: nam='db file scattered read' ela= 25155 file#=8 block#=6345 blocks=8 obj#=47847 tim=141267940465
WAIT #20: nam='SQL*Net more data to client' ela= 21 driver id=1413697536 #bytes=2001 p3=0 obj#=47847 tim=141267940964
WAIT #20: nam='db file scattered read' ela= 564 file#=7 block#=3089 blocks=8 obj#=47847 tim=141267941767
WAIT #20: nam='db file scattered read' ela= 17109 file#=7 block#=4281 blocks=8 obj#=47847 tim=141267959039
FETCH #20:c=0,e=69163,p=32,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,tim=141267959123 

From the above, we see that the Standard Edition reads blocks 8204 and 8535 of the index, and then reads 8 blocks (at this point, the extent size of the index segment was likely 64KB) of the index starting at block 8225.  Standard Edition then reads the table blocks using mostly db file scattered reads of 8 blocks each.

Enterprise Edition (obj# 51662 is the table T1, obj# 51663 is the index):

PARSE #42:c=15600,e=28517,p=0,cr=0,cu=0,mis=1,r=0,dep=0,og=1,tim=141264134068
EXEC #42:c=0,e=26,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,tim=141264134147
WAIT #42: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=141264134166
WAIT #42: nam='db file sequential read' ela= 14880 file#=7 block#=3131892 blocks=1 obj#=51663 tim=141264149083
WAIT #42: nam='db file sequential read' ela= 7090 file#=7 block#=3148754 blocks=1 obj#=51663 tim=141264156220
WAIT #42: nam='db file sequential read' ela= 11698 file#=7 block#=3148170 blocks=1 obj#=51663 tim=141264167995
WAIT #42: nam='db file sequential read' ela= 4910 file#=7 block#=3107460 blocks=1 obj#=51662 tim=141264172961
FETCH #42:c=0,e=38813,p=4,cr=4,cu=0,mis=0,r=1,dep=0,og=1,tim=141264172997
WAIT #42: nam='SQL*Net message from client' ela= 334 driver id=1413697536 #bytes=1 p3=0 obj#=51662 tim=141264173378
WAIT #42: nam='db file parallel read' ela= 22424 files=1 blocks=9 requests=9 obj#=51662 tim=141264195881
WAIT #42: nam='db file sequential read' ela= 3893 file#=7 block#=3133372 blocks=1 obj#=51662 tim=141264199834
WAIT #42: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=51662 tim=141264199867
WAIT #42: nam='db file sequential read' ela= 275 file#=7 block#=3148171 blocks=1 obj#=51663 tim=141264200254
WAIT #42: nam='db file sequential read' ela= 8689 file#=7 block#=3144263 blocks=1 obj#=51662 tim=141264208995
WAIT #42: nam='db file sequential read' ela= 286 file#=7 block#=3133373 blocks=1 obj#=51662 tim=141264209397
WAIT #42: nam='db file sequential read' ela= 9317 file#=7 block#=3136498 blocks=1 obj#=51662 tim=141264218889
WAIT #42: nam='db file sequential read' ela= 28310 file#=7 block#=3139625 blocks=1 obj#=51662 tim=141264247378
WAIT #42: nam='db file sequential read' ela= 6375 file#=7 block#=3142717 blocks=1 obj#=51662 tim=141264253979
WAIT #42: nam='SQL*Net more data to client' ela= 54 driver id=1413697536 #bytes=2001 p3=0 obj#=51662 tim=141264254135
WAIT #42: nam='db file sequential read' ela= 298 file#=7 block#=3107461 blocks=1 obj#=51662 tim=141264254547
WAIT #42: nam='db file sequential read' ela= 8215 file#=7 block#=3145806 blocks=1 obj#=51662 tim=141264262927
WAIT #42: nam='db file sequential read' ela= 9011 file#=7 block#=3134936 blocks=1 obj#=51662 tim=141264272106
WAIT #42: nam='db file sequential read' ela= 3218 file#=7 block#=3148172 blocks=1 obj#=51663 tim=141264275539
WAIT #42: nam='db file sequential read' ela= 331 file#=7 block#=3138063 blocks=1 obj#=51662 tim=141264275929
WAIT #42: nam='db file sequential read' ela= 314 file#=7 block#=3141175 blocks=1 obj#=51662 tim=141264276463
WAIT #42: nam='db file sequential read' ela= 298 file#=7 block#=3144264 blocks=1 obj#=51662 tim=141264276979
WAIT #42: nam='SQL*Net more data to client' ela= 34 driver id=1413697536 #bytes=2001 p3=0 obj#=51662 tim=141264277128
WAIT #42: nam='db file sequential read' ela= 299 file#=7 block#=3133374 blocks=1 obj#=51662 tim=141264277531
WAIT #42: nam='db file sequential read' ela= 351 file#=7 block#=3136499 blocks=1 obj#=51662 tim=141264278134
WAIT #42: nam='db file sequential read' ela= 302 file#=7 block#=3139626 blocks=1 obj#=51662 tim=141264278652
FETCH #42:c=0,e=105439,p=26,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,tim=141264278839
WAIT #42: nam='SQL*Net message from client' ela= 1528 driver id=1413697536 #bytes=1 p3=0 obj#=51662 tim=141264280396
WAIT #42: nam='SQL*Net message to client' ela= 1 driver id=1413697536 #bytes=1 p3=0 obj#=51662 tim=141264280492
WAIT #42: nam='db file sequential read' ela= 321 file#=7 block#=3148173 blocks=1 obj#=51663 tim=141264280856
WAIT #42: nam='db file parallel read' ela= 359 files=1 blocks=2 requests=2 obj#=51662 tim=141264281277
WAIT #42: nam='db file sequential read' ela= 332 file#=7 block#=3145807 blocks=1 obj#=51662 tim=141264281840
WAIT #42: nam='db file sequential read' ela= 332 file#=7 block#=3134937 blocks=1 obj#=51662 tim=141264282332
WAIT #42: nam='db file sequential read' ela= 289 file#=7 block#=3138064 blocks=1 obj#=51662 tim=141264282835
WAIT #42: nam='db file sequential read' ela= 288 file#=7 block#=3141176 blocks=1 obj#=51662 tim=141264283339
WAIT #42: nam='db file sequential read' ela= 325 file#=7 block#=3144265 blocks=1 obj#=51662 tim=141264283878
WAIT #42: nam='SQL*Net more data to client' ela= 32 driver id=1413697536 #bytes=2001 p3=0 obj#=51662 tim=141264283957
WAIT #42: nam='db file sequential read' ela= 276 file#=7 block#=3133375 blocks=1 obj#=51662 tim=141264284409
WAIT #42: nam='db file sequential read' ela= 284 file#=7 block#=3148174 blocks=1 obj#=51663 tim=141264284877
WAIT #42: nam='db file sequential read' ela= 274 file#=7 block#=3136500 blocks=1 obj#=51662 tim=141264285216
WAIT #42: nam='db file sequential read' ela= 321 file#=7 block#=3139627 blocks=1 obj#=51662 tim=141264285771
WAIT #42: nam='db file sequential read' ela= 330 file#=7 block#=3142719 blocks=1 obj#=51662 tim=141264286316
WAIT #42: nam='db file sequential read' ela= 339 file#=7 block#=3107463 blocks=1 obj#=51662 tim=141264286826
WAIT #42: nam='db file sequential read' ela= 292 file#=7 block#=3145808 blocks=1 obj#=51662 tim=141264287279
WAIT #42: nam='SQL*Net more data to client' ela= 32 driver id=1413697536 #bytes=2001 p3=0 obj#=51662 tim=141264287381
WAIT #42: nam='db file sequential read' ela= 238 file#=7 block#=3134938 blocks=1 obj#=51662 tim=141264287715
WAIT #42: nam='db file sequential read' ela= 319 file#=7 block#=3138065 blocks=1 obj#=51662 tim=141264288240
WAIT #42: nam='db file sequential read' ela= 3642 file#=7 block#=3141177 blocks=1 obj#=51662 tim=141264292099
FETCH #42:c=0,e=11849,p=18,cr=1003,cu=0,mis=0,r=1000,dep=0,og=1,tim=141264292285 

Interestingly, Enterprise Edition seems to be favoring single block reads for the index and table blocks, with an occasional db file parallel read wait to pick up non-adjacent blocks from the table (in all but one case throughout the trace file just two blocks were read at a time during the db file parallel read waits).

What happens if we try to force a full table scan in Standard Edition and Enterprise Edition?

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ FULL(T1) */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ FULL(T1) FULL */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

The statistics in both cases are identical:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      15484  consistent gets
      15386  physical reads
          0  redo size
     826458  bytes sent via SQL*Net to client
       1462  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed

If we try to force parallel execution (something not possible on Standard Edition):

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET ARRAYSIZE 1000
SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ FULL(T1) PARALLEL(T1 8 ) */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

ALTER SYSTEM FLUSH BUFFER_CACHE;
ALTER SYSTEM FLUSH BUFFER_CACHE;

SET AUTOTRACE TRACEONLY STATISTICS

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

SELECT /*+ FULL(T1) PARALLEL(T1 8 ) PFULL */
  *
FROM
  T1
WHERE
  ID BETWEEN 1000 AND 10000;

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

We see the following output.

Standard Edition:

Statistics
---------------------------------------------------
          1  recursive calls
          0  db block gets
      15484  consistent gets
      15386  physical reads
          0  redo size
     826458  bytes sent via SQL*Net to client
       1462  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      90010  rows processed

Enterprise Edition:

Statistics
---------------------------------------------------
         45  recursive calls
          4  db block gets
      16534  consistent gets
      15390  physical reads
        672  redo size
     826458  bytes sent via SQL*Net to client
       1482  bytes received via SQL*Net from client
         92  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      90010  rows processed 

The Row Source Operation execution plan, directly from the trace files.

Standard Edition:

STAT #20 id=1 cnt=90010 pid=0 pos=1 obj=47847 op='TABLE ACCESS FULL T1 (cr=15484 pr=15386 pw=0 time=50102 us)' 

Enterprise Edition:

STAT #26 id=1 cnt=90010 pid=0 pos=1 obj=0 op='PX COORDINATOR  (cr=4 pr=1 pw=0 time=76752 us)'
STAT #26 id=2 cnt=0 pid=1 pos=1 obj=0 op='PX SEND QC (RANDOM) :TQ10000 (cr=0 pr=0 pw=0 time=0 us)'
STAT #26 id=3 cnt=0 pid=2 pos=1 obj=0 op='PX BLOCK ITERATOR (cr=0 pr=0 pw=0 time=0 us)'
STAT #26 id=4 cnt=0 pid=3 pos=1 obj=51662 op='TABLE ACCESS FULL T1 (cr=0 pr=0 pw=0 time=0 us)'

———–

Suprisingly, in the above very simple test cases, very different behaviors are experienced between the Standard Edition of Oracle Database 10.2.0.5 and the Enterprise Edition of Oracle Database 10.2.0.5.  During the index range scan Standard Edition’s runtime engine preferred to perform multi-block reads of the index and table in batches of 8 blocks, while Enterprise Edition’s runtime engine primarily performed single block reads with an occasional read of two non-adjacent blocks.  Somewhat surprisingly, even though it primarily performed single block reads, according to the time reported in the Row Source Operation execution plan, Enterprise Edition completed the test slightly faster than Standard Edition (the difference could be due to placement of the datafiles; scattering of extents across the two datafiles – the Standard Edition database was set up with two datafiles in the DEFAULT TABLESPACE for the user, while Enterprise Edition had a single datafile; or file caching/read-ahead at the operating system or disk sub-system level).  Standard Edition could not implement the PARALLEL hint, and as a result completed that test in 65% of the time required by Enterprise Edition.

One might wonder what would happen with a more complicated example, or if the test cases were repeated in either 11.2.0.1 or 11.2.0.2.





Single Sign-On Security Issue in 11.2.0.2 Patchset

18 11 2010

November 18, 2010

I just browsed though Metalink (MOS) to see which operating system platforms are currently supported for Oracle Database 11.2.0.2.  I noticed that the 11.2.0.2 patchset for 64 bit Linux was updated yesterday, and more digging revealed that all of the 11.2.0.2 patches for the other supported operating systems were also recently updated.

Take a look at Metalink Doc ID 1179474.1 and 1266978.1 for more information to see if you should re-download the 4.7GB patchset.

————–

Edit November 18, 2010:

If you have some time, and you are planning to upgrade to Oracle Database 11.2.0.2, spend a little time reading on Metalink – it is interesting to see what is fixed in 12.1.0.1.  A couple of interesting articles that I found include:

  • Doc ID 10142788.8, Bug 10142788 – Natively compiled PL/SQL in 11.2.0.2 can result in ora-04030: out of process memory
  • Bug 10274128 – Compressing and moving a partition fails in 11.2.0.2
  • Bug 10297087 – NFS mount warning in 11.2.0.2
  • Bug 10294904 – Selecting the COUNT(*) from ALL_SYNONYMS requires an hour to complete in 11.2.0.2, but just a couple seconds in earlier releases
  • Bug 10297041 – Create synonym invalidates objects in 11.2.0.2
  • Bug 10188727 – Some SQL failing with ORA-3113 or ORA-7445 after upgrade to 11.2.0.2
  • Doc ID 1264550.1, Bug:8352378 – Wrong Results on 11.2.0.2 with Function-Based Index and OR Expansion
  • Doc ID 285586.1 – ORA-600 [kdsgrp1]
  • Doc ID 138554.1 – ORA-600 [17059]
  • Doc ID 284433.1 – ORA-600 [25027]
  • Doc ID 138428.1 – ORA-600 [15160]
  • Doc ID 300581.1 – ORA-600 [kddummy_blkchk]
  • Doc ID 300637.1 – ORA-600 [qertbfetchbyrowid]
  • Doc ID 567171.1 – _FIX_CONTROL
  • Doc ID 94036.1 – CURSOR_SHARING
  • Doc ID 62338.1 – _COMPLEX_VIEW_MERGING




Dynamic Sampling Changes

12 11 2010

November 12, 2010

I read a message thread on the Oracle-L list that caused me to pause for a moment…

If you display an execution plan and see a message stating “Dynamic sampling used”, you might be left wondering what caused the dynamic sampling.  From the Oracle Database 11.2 documentation, the various levels of dynamic sampling:

Level When the Optimizer Uses Dynamic Sampling Sample Size (Blocks)
0 Do not use dynamic sampling n/a
1 Use dynamic sampling for all tables that have not been analyzed, but only if the following criteria are met:

  • There is at least 1 unanalyzed, nonpartitioned table in the query.
  • This unanalyzed table has no indexes.
  • This unanalyzed table has more blocks than the number of blocks that would be used for dynamic sampling of this table.
32
2 Use dynamic sampling if least one table in the statement has no statistics. 64
3 Use dynamic sampling if any of the following conditions is true:

  • The statement meets level 2 criteria.
  • The statement has one or more expressions used in the where clause predicates, for example, WHERE SUBSTR(CUSTLASTNAME,1,3).
64
4 Use dynamic sampling if any of the following conditions is true:

  • The statement meets level 3 criteria.
  • The statement uses complex predicates (an OR or AND operator between multiple predicates on the same table).
64
5 Use dynamic sampling if the statement meets level 4 criteria. 128
6 Use dynamic sampling if the statement meets level 4 criteria. 256
7 Use dynamic sampling if the statement meets level 4 criteria. 512
8 Use dynamic sampling if the statement meets level 4 criteria. 1024
9 Use dynamic sampling if the statement meets level 4 criteria. 4086
10 Use dynamic sampling for all statements. All blocks

The same page in the documentation also states the following:

“You can disable the feature by setting the OPTIMIZER_FEATURES_ENABLE initialization parameter to 9.2.0 or by setting OPTIMIZER_DYNAMIC_SAMPLING=0.”

The above is an interesting quote, if we check the documentation for Oracle Database 9.2 we find that dynamic sampling is a new feature in Oracle Database 9.2:

“You control dynamic sampling with the OPTIMIZER_DYNAMIC_SAMPLING parameter, which can be set to a value from 0 to 10.

  • A value of 0 means dynamic sampling will not be done.
  • A value of 1 (the default) means dynamic sampling will be performed if all of the following conditions are true:
    • There is more than one table in the query.
    • Some table has not been analyzed and has no indexes.
    • The optimizer determines that a relatively expensive table scan would be required for this unanalyzed table.
  • Increasing the value of the parameter results in more aggressive application of dynamic sampling, in terms of both the type of tables sampled (analyzed or unanalyzed) and the amount of I/O spent on sampling.

Dynamic sampling is repeatable if no rows have been inserted, deleted, or updated in the table being sampled.

The parameter OPTIMIZER_FEATURES_ENABLE turns off dynamic sampling if set to a version prior to 9.0.2″

It appears that there is a little bit of disagreement between the documentation for the two Oracle Database releases regarding the value of OPTIMIZER_FEATURES_ENABLE that disables dynamic sampling.  But wait, it appears that there are even more differences between the two releases… and just about as many changes between 11.1.0.7 and 11.2.0.2.  A quick trip through Metalink (MOS) finds the following:

  • Dynamic sampling level used for a SQL statement is different from what is expected, Metalink ID 1102413.1.  See this blog article for an example of the dynamic sampling level being automatically adjusted from 2 to 5 for a query executed with a parallel degree (my article pre-dates the Metalink article by a couple of months – I remember posting somewhere early in 2010, that I was surprised to see the dynamic sampling level automatically incease from 2 to either 5 or 8 for a query).
  • Occasional wrong results in a RAC environment for parallel queries caused by dynamic sampling in Oracle Database 11.1.0.7 through 11.2.0.1, see Bug 9705349.
  • User statistics on columns ignored due to dynamic sampling in Oracle Database 11.2.0.1 and below, see Bug 9272549.
  • Dynamic sampling is not used for a query when the CURRENT_SCHEMA is set for a session in Oracle Database 11.1.0.7 and below, see Bug 5586604.
  • Dynamic sampling does not work for query blocks with OR expansion in Oracle Database 11.1.0.7 and below, see Bug 6956212.
  • Dynamic sampling causes poor join cardinality in Oracle Database 11.2.0.1 and below, see Bug 8767442.
  • Dynamic sampling causes poor cardinality estimates when multiple columns are used to join tables in Oracle Database 11.2.0.1 and below, see Bug 8784639
  • Dynamic sampling causes poor cardinaility estimates for indexes on partitioned tables in Oracle Database 11.2.0.1 and below, see Bug 6408301.

From the above short list, we see that there are a lot of potential changes to dynamic sampling behavior following an upgrade.  According to the documentation, setting OPTIMIZER_FEATURES_ENABLE to 9.2.0 in Oracle Database 11.2.0.1 and above will disable dynamic sampling, while the 9.2 documentation indicates that it should be enabled at level 1 (where level 1 apparently means something slightly different from what it means in 11.2.0.1, see the test scripts below to see what really happens).

Getting back to the Oracle-L thread, I modified one of my earlier test case scripts to not collect statistics for one of four tables:

CREATE TABLE T1 (
  C1 NUMBER,
  C2 NUMBER,
  C3 VARCHAR2(100),
  C4 VARCHAR2(500),
  PRIMARY KEY (C1));

INSERT INTO T1
SELECT
  ROWNUM,
  MOD(ROWNUM,100),
  RPAD('A',100,'A'),
  RPAD('A',500,'A')
FROM
  (SELECT
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=1000),
  (SELECT
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=1000);

CREATE TABLE T2 (
  C1 NUMBER,
  C2 NUMBER,
  C3 VARCHAR2(100),
  C4 VARCHAR2(500),
  PRIMARY KEY (C1));

INSERT INTO T2
SELECT
  ROWNUM,
  MOD(ROWNUM,100),
  RPAD('A',100,'A'),
  RPAD('A',500,'A')
FROM
  (SELECT
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=1000),
  (SELECT
    ROWNUM RN
  FROM
    DUAL
  CONNECT BY
    LEVEL<=1000);

CREATE TABLE T3 AS
SELECT
  ROWNUM C1
FROM
  DUAL
CONNECT BY
  LEVEL<=2;

CREATE TABLE T4 AS
SELECT
  ROWNUM C1
FROM
  DUAL
CONNECT BY
  LEVEL<=2;

EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T2',CASCADE=>TRUE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T3',CASCADE=>TRUE)
EXEC DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'T4',CASCADE=>TRUE)

In the above, notice that I did not collect statistics on table T1. Now, take a moment to imagine that instead of having the 4 tables above involved in a SQL statement, that there are 50 or more tables involved in a SQL statement.  It would be time consuming to check each table to see which one is missing statistics (in some cases it might not be desirable to have statistics on all tables).  Let’s try a quick test to see if we are able to determine which of the tables does not have statistics (on 11.2.0.1):

ALTER SESSION SET TRACEFILE_IDENTIFIER = 'T1_10053-TEST';
ALTER SESSION SET EVENTS '10053 TRACE NAME CONTEXT FOREVER, LEVEL 1';
SET AUTOTRACE TRACEONLY EXPLAIN
SET LINESIZE 140
SET PAGESIZE 1000
SET TRIMSPOOL ON

SELECT /*+ FIND_ME */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Execution Plan
----------------------------------------------------------
Plan hash value: 2884158292
-------------------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      | 10101 |  1903K| 11538  (60)| 00:00:02 |
|*  1 |  HASH JOIN RIGHT SEMI  |      | 10101 |  1903K| 11538  (60)| 00:00:02 |
|   2 |   TABLE ACCESS FULL    | T3   |     2 |     6 |     2   (0)| 00:00:01 |
|*  3 |   HASH JOIN            |      | 10101 |  1874K| 11532  (60)| 00:00:02 |
|*  4 |    HASH JOIN RIGHT SEMI|      | 10101 |  1104K|  5790  (60)| 00:00:01 |
|   5 |     TABLE ACCESS FULL  | T4   |     2 |     6 |     2   (0)| 00:00:01 |
|   6 |     TABLE ACCESS FULL  | T2   |  1000K|   103M|  5419  (57)| 00:00:01 |
|   7 |    TABLE ACCESS FULL   | T1   |   952K|    70M|  5385  (57)| 00:00:01 |
-------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C2"="C1")
   3 - access("T1"."C1"="T2"."C1")
   4 - access("T2"."C2"="C1")

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

Note that the execution plan shows that dynamic sampling was used at level 2, which is the default starting with Oracle Database 10.1.  Now let’s try a couple of experiments.  First, enabling parallel:

SELECT /*+ FIND_ME PARALLEL(8) */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Plan hash value: 1390077178

-----------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                       | Name         | Rows  | Bytes | Cost (%CPU)| Time     |    TQ  |IN-OUT| PQ Distrib |
-----------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                |              | 10101 |  1903K| 26185   (1)| 00:00:03 |        |      |            |
|   1 |  PX COORDINATOR                 |              |       |       |            |          |        |      |            |
|   2 |   PX SEND QC (RANDOM)           | :TQ10002     | 10101 |  1903K| 26185   (1)| 00:00:03 |  Q1,02 | P->S | QC (RAND)  |
|*  3 |    HASH JOIN RIGHT SEMI         |              | 10101 |  1903K| 26185   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|   4 |     PX RECEIVE                  |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |
|   5 |      PX SEND BROADCAST          | :TQ10000     |     2 |     6 |     2   (0)| 00:00:01 |  Q1,00 | P->P | BROADCAST  |
|   6 |       PX BLOCK ITERATOR         |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,00 | PCWC |            |
|   7 |        TABLE ACCESS FULL        | T3           |     2 |     6 |     2   (0)| 00:00:01 |  Q1,00 | PCWP |            |
|   8 |     NESTED LOOPS                |              |       |       |            |          |  Q1,02 | PCWP |            |
|   9 |      NESTED LOOPS               |              | 10101 |  1874K| 26182   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|* 10 |       HASH JOIN RIGHT SEMI      |              | 10101 |  1104K| 24800   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|  11 |        PX RECEIVE               |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |
|  12 |         PX SEND BROADCAST       | :TQ10001     |     2 |     6 |     2   (0)| 00:00:01 |  Q1,01 | P->P | BROADCAST  |
|  13 |          PX BLOCK ITERATOR      |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,01 | PCWC |            |
|  14 |           TABLE ACCESS FULL     | T4           |     2 |     6 |     2   (0)| 00:00:01 |  Q1,01 | PCWP |            |
|  15 |        PX BLOCK ITERATOR        |              |  1000K|   103M| 24751   (1)| 00:00:03 |  Q1,02 | PCWC |            |
|  16 |         TABLE ACCESS FULL       | T2           |  1000K|   103M| 24751   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|* 17 |       INDEX UNIQUE SCAN         | SYS_C0024756 |     1 |       |     0   (0)| 00:00:01 |  Q1,02 | PCWP |            |
|  18 |      TABLE ACCESS BY INDEX ROWID| T1           |     1 |    78 |     0   (0)| 00:00:01 |  Q1,02 | PCWP |            |
-----------------------------------------------------------------------------------------------------------------------------

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

Note
-----
   - dynamic sampling used for this statement (level=4)
   - Degree of Parallelism is 8 because of hint

Interesting, the dynamic sampling level was changed from the default of 2 to 4 for this SQL statement. I wonder which tables were affected – we will check later, first a couple of more tests:

SELECT /*+ FIND_ME OPTIMIZER_FEATURES_ENABLE('9.0.1') */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Plan hash value: 3748566283

-----------------------------------------------------------------------------------------------
| Id  | Operation                      | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT               |              |     2 |   386 |   175   (5)| 00:00:01 |
|*  1 |  HASH JOIN SEMI                |              |     2 |   386 |   175   (5)| 00:00:01 |
|*  2 |   HASH JOIN SEMI               |              |     2 |   380 |   174   (5)| 00:00:01 |
|   3 |    NESTED LOOPS                |              |    82 | 15334 |   172   (5)| 00:00:01 |
|   4 |     TABLE ACCESS FULL          | T1           |    82 |  6396 |     2  (50)| 00:00:01 |
|   5 |     TABLE ACCESS BY INDEX ROWID| T2           |     1 |   109 |     3  (34)| 00:00:01 |
|*  6 |      INDEX UNIQUE SCAN         | SYS_C0024757 |     1 |       |     2  (50)| 00:00:01 |
|   7 |    TABLE ACCESS FULL           | T4           |     2 |     6 |     2  (50)| 00:00:01 |
|   8 |   TABLE ACCESS FULL            | T3           |     2 |     6 |     2  (50)| 00:00:01 |
-----------------------------------------------------------------------------------------------

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

No note about dynamic sampling with OPTIMIZER_FEATURES_ENABLE at 9.0.1, let’s try 9.2.0:

SELECT /*+ FIND_ME OPTIMIZER_FEATURES_ENABLE('9.2.0') */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Plan hash value: 2710410714

---------------------------------------------------------------------------------------------
| Id  | Operation                    | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |              |     1 |   193 |    15  (20)| 00:00:01 |
|   1 |  NESTED LOOPS                |              |     1 |   193 |    15  (20)| 00:00:01 |
|*  2 |   HASH JOIN SEMI             |              |     2 |   168 |    11  (28)| 00:00:01 |
|   3 |    MERGE JOIN CARTESIAN      |              |     2 |   162 |     9  (34)| 00:00:01 |
|   4 |     TABLE ACCESS FULL        | T1           |    82 |  6396 |     3  (34)| 00:00:01 |
|   5 |     BUFFER SORT              |              |     2 |     6 |            |          |
|   6 |      SORT UNIQUE             |              |     2 |     6 |     1   (0)| 00:00:01 |
|   7 |       TABLE ACCESS FULL      | T4           |     2 |     6 |     1   (0)| 00:00:01 |
|   8 |    TABLE ACCESS FULL         | T3           |     2 |     6 |     3  (34)| 00:00:01 |
|*  9 |   TABLE ACCESS BY INDEX ROWID| T2           |     1 |   109 |     3  (34)| 00:00:01 |
|* 10 |    INDEX UNIQUE SCAN         | SYS_C0024757 |     1 |       |     2  (50)| 00:00:01 |
---------------------------------------------------------------------------------------------

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

Still no note about dynamic sampling, but now we see a Cartesian join in the execution plan (note that this may not be a bad/inappropriate Cartesian join).  Let’ s jump up to 10.1.0:

SELECT /*+ FIND_ME OPTIMIZER_FEATURES_ENABLE('10.1.0') */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Plan hash value: 888444315

---------------------------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      | 20000 |  3769K|       | 13001  (57)| 00:00:02 |
|*  1 |  HASH JOIN             |      | 20000 |  3769K|  4968K| 13001  (57)| 00:00:02 |
|*  2 |   HASH JOIN RIGHT SEMI |      | 40000 |  4492K|       |  5940  (61)| 00:00:01 |
|   3 |    TABLE ACCESS FULL   | T4   |     2 |     6 |       |     2   (0)| 00:00:01 |
|   4 |    MERGE JOIN CARTESIAN|      |  2000K|   213M|       |  5200  (56)| 00:00:01 |
|   5 |     SORT UNIQUE        |      |     2 |     6 |       |     2   (0)| 00:00:01 |
|   6 |      TABLE ACCESS FULL | T3   |     2 |     6 |       |     2   (0)| 00:00:01 |
|   7 |     BUFFER SORT        |      |  1000K|   103M|       |  5198  (56)| 00:00:01 |
|   8 |      TABLE ACCESS FULL | T2   |  1000K|   103M|       |  5197  (56)| 00:00:01 |
|   9 |   TABLE ACCESS FULL    | T1   |   952K|    70M|       |  5175  (55)| 00:00:01 |
---------------------------------------------------------------------------------------

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

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

The dynamic sampling note has returned, and we still have a Cartesian join (just with a different set of tables).  Trying again at 10.2.0.1:

SELECT /*+ FIND_ME OPTIMIZER_FEATURES_ENABLE('10.2.0.1') */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Plan hash value: 2884158292

-------------------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      | 10101 |  1903K| 11538  (60)| 00:00:02 |
|*  1 |  HASH JOIN RIGHT SEMI  |      | 10101 |  1903K| 11538  (60)| 00:00:02 |
|   2 |   TABLE ACCESS FULL    | T3   |     2 |     6 |     2   (0)| 00:00:01 |
|*  3 |   HASH JOIN            |      | 10101 |  1874K| 11532  (60)| 00:00:02 |
|*  4 |    HASH JOIN RIGHT SEMI|      | 10101 |  1104K|  5790  (60)| 00:00:01 |
|   5 |     TABLE ACCESS FULL  | T4   |     2 |     6 |     2   (0)| 00:00:01 |
|   6 |     TABLE ACCESS FULL  | T2   |  1000K|   103M|  5419  (57)| 00:00:01 |
|   7 |    TABLE ACCESS FULL   | T1   |   952K|    70M|  5385  (57)| 00:00:01 |
-------------------------------------------------------------------------------

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

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

We are still seeing the dynamic sampling note, and the Cartesian join is no longer present.  One more test at 11.1.0.7:

Plan hash value: 2884158292
-------------------------------------------------------------------------------
| Id  | Operation              | Name | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |      | 10101 |  1903K| 11538  (60)| 00:00:02 |
|*  1 |  HASH JOIN RIGHT SEMI  |      | 10101 |  1903K| 11538  (60)| 00:00:02 |
|   2 |   TABLE ACCESS FULL    | T3   |     2 |     6 |     2   (0)| 00:00:01 |
|*  3 |   HASH JOIN            |      | 10101 |  1874K| 11532  (60)| 00:00:02 |
|*  4 |    HASH JOIN RIGHT SEMI|      | 10101 |  1104K|  5790  (60)| 00:00:01 |
|   5 |     TABLE ACCESS FULL  | T4   |     2 |     6 |     2   (0)| 00:00:01 |
|   6 |     TABLE ACCESS FULL  | T2   |  1000K|   103M|  5419  (57)| 00:00:01 |
|   7 |    TABLE ACCESS FULL   | T1   |   952K|    70M|  5385  (57)| 00:00:01 |
-------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
   1 - access("T1"."C2"="C1")
   3 - access("T1"."C1"="T2"."C1")
   4 - access("T2"."C2"="C1")
Note
-----
   - dynamic sampling used for this statement (level=2)

The above did not change from the test at 10.2.0.1.  For comparision with the parallel test that was near the start, with a hinted OPTIMIZER_FEATURES_ENABLE set to 11.1.0.7:

SELECT /*+ FIND_ME OPTIMIZER_FEATURES_ENABLE('11.1.0.7') PARALLEL(8) */
  T1.C1,
  T2.C1,
  T1.C3,1,10 T1_C3,
  T2.C3 T2_C3
FROM
  T1,
  T2
WHERE
  T1.C1=T2.C1
  AND T1.C2 IN (
    SELECT
      C1
    FROM
      T3)
  AND T2.C2 IN (
    SELECT
      C1
    FROM
      T4);

Plan hash value: 1390077178

-----------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                       | Name         | Rows  | Bytes | Cost (%CPU)| Time     |    TQ  |IN-OUT| PQ Distrib |
-----------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                |              | 10101 |  1903K| 26185   (1)| 00:00:03 |        |      |            |
|   1 |  PX COORDINATOR                 |              |       |       |            |          |        |      |            |
|   2 |   PX SEND QC (RANDOM)           | :TQ10002     | 10101 |  1903K| 26185   (1)| 00:00:03 |  Q1,02 | P->S | QC (RAND)  |
|*  3 |    HASH JOIN RIGHT SEMI         |              | 10101 |  1903K| 26185   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|   4 |     PX RECEIVE                  |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |
|   5 |      PX SEND BROADCAST          | :TQ10000     |     2 |     6 |     2   (0)| 00:00:01 |  Q1,00 | P->P | BROADCAST  |
|   6 |       PX BLOCK ITERATOR         |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,00 | PCWC |            |
|   7 |        TABLE ACCESS FULL        | T3           |     2 |     6 |     2   (0)| 00:00:01 |  Q1,00 | PCWP |            |
|   8 |     NESTED LOOPS                |              |       |       |            |          |  Q1,02 | PCWP |            |
|   9 |      NESTED LOOPS               |              | 10101 |  1874K| 26182   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|* 10 |       HASH JOIN RIGHT SEMI      |              | 10101 |  1104K| 24800   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|  11 |        PX RECEIVE               |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,02 | PCWP |            |
|  12 |         PX SEND BROADCAST       | :TQ10001     |     2 |     6 |     2   (0)| 00:00:01 |  Q1,01 | P->P | BROADCAST  |
|  13 |          PX BLOCK ITERATOR      |              |     2 |     6 |     2   (0)| 00:00:01 |  Q1,01 | PCWC |            |
|  14 |           TABLE ACCESS FULL     | T4           |     2 |     6 |     2   (0)| 00:00:01 |  Q1,01 | PCWP |            |
|  15 |        PX BLOCK ITERATOR        |              |  1000K|   103M| 24751   (1)| 00:00:03 |  Q1,02 | PCWC |            |
|  16 |         TABLE ACCESS FULL       | T2           |  1000K|   103M| 24751   (1)| 00:00:03 |  Q1,02 | PCWP |            |
|* 17 |       INDEX UNIQUE SCAN         | SYS_C0024756 |     1 |       |     0   (0)| 00:00:01 |  Q1,02 | PCWP |            |
|  18 |      TABLE ACCESS BY INDEX ROWID| T1           |     1 |    78 |     0   (0)| 00:00:01 |  Q1,02 | PCWP |            |
-----------------------------------------------------------------------------------------------------------------------------

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

Note
-----
   - dynamic sampling used for this statement (level=2)
   - Degree of Parallelism is 8 because of hint

This time, instead of the dynamic sampling level automatically adjusting to a value of 4, it remained at a value of 2.  In this case, the change did not affect the execution plan.

Let’s take a look inside the 10053 trace file for the first execution on 11.2.0.1 to see if we are able to determine which tables were affected by dynamic sampling, searching the trace file for dynamic sampling, we find the following: 

SINGLE TABLE ACCESS PATH
  Single Table Cardinality Estimation for T1[T1]

*** 2010-11-12 10:43:30.507
** Performing dynamic sampling initial checks. **
** Dynamic sampling initial checks returning TRUE (level = 2).
** Dynamic sampling updated index stats.: SYS_C0024756, blocks=1881
** Dynamic sampling updated table stats.: blocks=90911

*** 2010-11-12 10:43:30.507
** Generated dynamic sampling query:
    query text :
SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB) opt_param('parallel_execution_enabled', 'false')
   NO_PARALLEL_INDEX(SAMPLESUB) NO_SQL_TUNE */ NVL(SUM(C1),0), NVL(SUM(C2),0), COUNT(DISTINCT C3), NVL(SUM(CASE WHEN C3 IS NULL
     THEN 1 ELSE 0 END),0) FROM (SELECT /*+ NO_PARALLEL("T1") FULL("T1") NO_PARALLEL_INDEX("T1") */ 1 AS C1, 1 AS C2, "T1"."C1" AS C3
   FROM "T1" SAMPLE BLOCK (0.069299 , 1) SEED (1) "T1") SAMPLESUB

*** 2010-11-12 10:43:30.522
** Executed dynamic sampling query:
    level : 2
    sample pct. : 0.069299
    actual sample size : 660
    filtered sample card. : 660
    orig. card. : 82
    block cnt. table stat. : 90911
    block cnt. for sampling: 90911
    max. sample block cnt. : 64
    sample block cnt. : 63
    ndv C3 : 660
        scaled : 952400.00
    nulls C4 : 0
        scaled : 0.00
    min. sel. est. : -1.00000000
** Dynamic sampling col. stats.:
  Column (#1): C1(  Part#: 0
    AvgLen: 22 NDV: 952400 Nulls: 0 Density: 0.000001
** Using dynamic sampling NULLs estimates.
** Using dynamic sampling NDV estimates.
   Scaled NDVs using cardinality = 952401.
** Using dynamic sampling card. : 952401
** Dynamic sampling updated table card.
  Table: T1  Alias: T1
    Card: Original: 952400.952381  Rounded: 952401  Computed: 952400.95  Non Adjusted: 952400.95
  Access Path: TableScan
    Cost:  5385.22  Resp: 5385.22  Degree: 0
      Cost_io: 2333.00  Cost_cpu: 828373422
      Resp_io: 2333.00  Resp_cpu: 828373422
  Best:: AccessPath: TableScan
         Cost: 5385.22  Degree: 1  Resp: 5385.22  Card: 952400.95  Bytes: 0

Access path analysis for T2
***************************************
SINGLE TABLE ACCESS PATH
  Single Table Cardinality Estimation for T2[T2]
  Table: T2  Alias: T2

    Card: Original: 1000000.000000  Rounded: 1000000  Computed: 1000000.00  Non Adjusted: 1000000.00
  Access Path: TableScan
    Cost:  5418.55  Resp: 5418.55  Degree: 0
      Cost_io: 2333.00  Cost_cpu: 837417232
      Resp_io: 2333.00  Resp_cpu: 837417232
  Best:: AccessPath: TableScan
         Cost: 5418.55  Degree: 1  Resp: 5418.55  Card: 1000000.00  Bytes: 0

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

In the above, we are able to see that dynamic sampling was performed for table T1, but not for table T2.  Let’s check the 10053 trace for the first parallel execution:

SINGLE TABLE ACCESS PATH
  Single Table Cardinality Estimation for T4[T4]

*** 2010-11-12 10:45:01.533
** Performing dynamic sampling initial checks. **
** Dynamic sampling initial checks returning FALSE.
  Table: T4  Alias: T4
    Card: Original: 2.000000  Rounded: 2  Computed: 2.00  Non Adjusted: 2.00
  Access Path: TableScan
    Cost:  2.00  Resp: 2.00  Degree: 0
      Cost_io: 2.00  Cost_cpu: 300
      Resp_io: 2.00  Resp_cpu: 42
  Best:: AccessPath: TableScan
         Cost: 2.00  Degree: 8  Resp: 2.00  Card: 2.00  Bytes: 0

Access path analysis for T3
***************************************
SINGLE TABLE ACCESS PATH
  Single Table Cardinality Estimation for T3[T3]

*** 2010-11-12 10:45:01.533
** Performing dynamic sampling initial checks. **
** Dynamic sampling initial checks returning FALSE.
  Table: T3  Alias: T3
    Card: Original: 2.000000  Rounded: 2  Computed: 2.00  Non Adjusted: 2.00
  Access Path: TableScan
    Cost:  2.00  Resp: 2.00  Degree: 0
      Cost_io: 2.00  Cost_cpu: 300
      Resp_io: 2.00  Resp_cpu: 42
  Best:: AccessPath: TableScan
         Cost: 2.00  Degree: 8  Resp: 2.00  Card: 2.00  Bytes: 0

Access path analysis for T1
***************************************
SINGLE TABLE ACCESS PATH
  Single Table Cardinality Estimation for T1[T1]

*** 2010-11-12 10:45:01.533
** Performing dynamic sampling initial checks. **
** Dynamic sampling initial checks returning TRUE (level = 4).
** Dynamic sampling updated index stats.: SYS_C0024756, blocks=1881
** Dynamic sampling updated table stats.: blocks=90911

*** 2010-11-12 10:45:01.533
** Generated dynamic sampling query:
    query text :
SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB) opt_param('parallel_execution_enabled', 'false')
    NO_PARALLEL_INDEX(SAMPLESUB) NO_SQL_TUNE */ NVL(SUM(C1),0), NVL(SUM(C2),0), COUNT(DISTINCT C3), NVL(SUM(CASE WHEN C3 IS NULL
     THEN 1 ELSE 0 END),0) FROM (SELECT /*+ NO_PARALLEL("T1") FULL("T1") NO_PARALLEL_INDEX("T1") */ 1 AS C1, 1 AS C2, "T1"."C1" AS C3
  FROM "T1" SAMPLE BLOCK (0.069299 , 1) SEED (1) "T1") SAMPLESUB
*** 2010-11-12 10:45:01.533
** Executed dynamic sampling query:
    level : 4
    sample pct. : 0.069299
    actual sample size : 660
    filtered sample card. : 660
    orig. card. : 82
    block cnt. table stat. : 90911
    block cnt. for sampling: 90911
    max. sample block cnt. : 64
    sample block cnt. : 63
    ndv C3 : 660
        scaled : 952400.00
    nulls C4 : 0
        scaled : 0.00
    min. sel. est. : -1.00000000
** Dynamic sampling col. stats.:
  Column (#1): C1(  Part#: 0
    AvgLen: 22 NDV: 952400 Nulls: 0 Density: 0.000001
** Using dynamic sampling NULLs estimates.
** Using dynamic sampling NDV estimates.
   Scaled NDVs using cardinality = 952401.
** Using dynamic sampling card. : 952401
** Dynamic sampling updated table card.
  Table: T1  Alias: T1
    Card: Original: 952400.952381  Rounded: 952401  Computed: 952400.95  Non Adjusted: 952400.95
  Access Path: TableScan
    Cost:  2999.75  Resp: 24746.43  Degree: 0
      Cost_io: 2333.00  Cost_cpu: 180956190
      Resp_io: 24653.83  Resp_cpu: 25132804
  Best:: AccessPath: TableScan
         Cost: 24746.43  Degree: 8  Resp: 24746.43  Card: 952400.95  Bytes: 0

Access path analysis for T2
***************************************
SINGLE TABLE ACCESS PATH
  Single Table Cardinality Estimation for T2[T2]

*** 2010-11-12 10:45:01.533
** Performing dynamic sampling initial checks. **
** Dynamic sampling initial checks returning FALSE.
  Table: T2  Alias: T2
    Card: Original: 1000000.000000  Rounded: 1000000  Computed: 1000000.00  Non Adjusted: 1000000.00
  Access Path: TableScan
    Cost:  3033.07  Resp: 24751.06  Degree: 0
      Cost_io: 2333.00  Cost_cpu: 190000000
      Resp_io: 24653.83  Resp_cpu: 26388889
  Best:: AccessPath: TableScan
         Cost: 24751.06  Degree: 8  Resp: 24751.06  Card: 1000000.00  Bytes: 0

Again, we see that dynamic sampling was performed only for table T1 (at level 4).  The potentially useful bit from this exercise is this:

** Generated dynamic sampling query:
    query text :
SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB)...

We could check the library cache to find all similar SQL statements to determine on which tables dynamic sampling was performed:

SELECT
  SQL_TEXT
FROM
  V$SQL
WHERE
  SQL_TEXT LIKE 'SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE %';

SQL_TEXT
--------------------------------------------------------------------------------------------------------------------------------------------
SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB) opt_param('parallel_execution_enabled', 'false') NO_PARALL
EL_INDEX(SAMPLESUB) NO_SQL_TUNE */ NVL(SUM(C1),:"SYS_B_0"), NVL(SUM(C2),:"SYS_B_1") FROM (SELECT /*+ NO_PARALLEL("Q") FULL("Q") NO_PARALLEL_
INDEX("Q") */ :"SYS_B_2" AS C1, :"SYS_B_3" AS C2 FROM "MGMT_TASK_QTABLE" "Q") SAMPLESUB

SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB) opt_param('parallel_execution_enabled', 'false') NO_PARALL
EL_INDEX(SAMPLESUB) NO_SQL_TUNE */ NVL(SUM(C1),:"SYS_B_0"), NVL(SUM(C2),:"SYS_B_1"), COUNT(DISTINCT C3), NVL(SUM(CASE WHEN C3 IS NULL THEN :
"SYS_B_2" ELSE :"SYS_B_3" END),:"SYS_B_4") FROM (SELECT /*+ IGNORE_WHERE_CLAUSE NO_PARALLEL("QT") FULL("QT") NO_PARALLEL_INDEX("QT") */ :"SY
S_B_5" AS C1, CASE WHEN "QT"."STATE"<>:"SYS_B_6" OR "QT"."STATE"<>:"SYS_B_7" THEN :"SYS_B_8" ELSE :"SYS_B_9" END AS C2, "QT"."MSGID" AS C3 F
ROM SYSMAN."MGMT_NOTIFY_QTABLE" "QT") SAMPLESUB

SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB) opt_param('parallel_execution_enabled', 'false') NO_PARALL
EL_INDEX(SAMPLESUB) NO_SQL_TUNE */ NVL(SUM(C1),:"SYS_B_0"), NVL(SUM(C2),:"SYS_B_1"), COUNT(DISTINCT C3), NVL(SUM(CASE WHEN C3 IS NULL THEN :
"SYS_B_2" ELSE :"SYS_B_3" END),:"SYS_B_4") FROM (SELECT /*+ NO_PARALLEL("T1") FULL("T1") NO_PARALLEL_INDEX("T1") */ :"SYS_B_5" AS C1, :"SYS_
B_6" AS C2, "T1"."C1" AS C3 FROM "T1" SAMPLE BLOCK (:"SYS_B_7" , :"SYS_B_8") SEED (:"SYS_B_9") "T1") SAMPLESUB

SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE NO_PARALLEL(SAMPLESUB) opt_param('parallel_execution_enabled', 'false') NO_PARALL
EL_INDEX(SAMPLESUB) NO_SQL_TUNE */ NVL(SUM(C1),0), NVL(SUM(C2),0), COUNT(DISTINCT C3), NVL(SUM(CASE WHEN C3 IS NULL THEN 1 ELSE 0 END),0) FR
OM (SELECT /*+ IGNORE_WHERE_CLAUSE NO_PARALLEL("QT") FULL("QT") NO_PARALLEL_INDEX("QT") */ 1 AS C1, CASE WHEN "QT"."Q_NAME"=:B1 AND "QT"."ST
ATE"=:B2 THEN 1 ELSE 0 END AS C2, "QT"."Q_NAME" AS C3 FROM SYSMAN."MGMT_TASK_QTABLE" "QT") SAMPLESUB

The above is a little hard to read, so we might try something like this to pick out just the table names:

SELECT
  SUBSTR(TAB,1,INSTR(TAB,' ')-1) TAB
FROM
  (SELECT
    SUBSTR(SQL_TEXT,INSTR(SQL_TEXT,'FROM ',1,2)+5) TAB
  FROM
    V$SQL
  WHERE
    SQL_TEXT LIKE 'SELECT /* OPT_DYN_SAMP */ /*+ ALL_ROWS IGNORE_WHERE_CLAUSE %');

TAB
---------------------------
"MGMT_TASK_QTABLE"
SYSMAN."MGMT_NOTIFY_QTABLE"
"T1"
SYSMAN."MGMT_TASK_QTABLE"

So, with the above, we are able to see on which tables dynamic sampling was performed, but we do not see the full picture of why, and at what level (was the dynamic sampling level 1 or 10 – the OTHER_XML column will indicate the sampling level for a single query, as seen below), without a 10053 trace enabled.  From the 10053 trace file:

Content of other_xml column
===========================
  dop_reason     : hint
  dop            : 8
  db_version     : 11.2.0.1
  parse_schema   : TESTUSER
  dynamic_sampling: 2
  plan_hash      : 1390077178
  plan_hash_2    : 1881449145
  Outline Data:
  /*+
    BEGIN_OUTLINE_DATA
      IGNORE_OPTIM_EMBEDDED_HINTS
      OPTIMIZER_FEATURES_ENABLE('11.1.0.7')
      DB_VERSION('11.2.0.1')
      ALL_ROWS
      SHARED(8)
      OUTLINE_LEAF(@"SEL$CC7EC59E")
      UNNEST(@"SEL$2")
      UNNEST(@"SEL$3")
      OUTLINE(@"SEL$1")
      OUTLINE(@"SEL$2")
      OUTLINE(@"SEL$3")
      FULL(@"SEL$CC7EC59E" "T2"@"SEL$1")
      FULL(@"SEL$CC7EC59E" "T4"@"SEL$3")
      INDEX(@"SEL$CC7EC59E" "T1"@"SEL$1" ("T1"."C1"))
      FULL(@"SEL$CC7EC59E" "T3"@"SEL$2")
      LEADING(@"SEL$CC7EC59E" "T2"@"SEL$1" "T4"@"SEL$3" "T1"@"SEL$1" "T3"@"SEL$2")
      USE_HASH(@"SEL$CC7EC59E" "T4"@"SEL$3")
      USE_NL(@"SEL$CC7EC59E" "T1"@"SEL$1")
      NLJ_BATCHING(@"SEL$CC7EC59E" "T1"@"SEL$1")
      USE_HASH(@"SEL$CC7EC59E" "T3"@"SEL$2")
      PQ_DISTRIBUTE(@"SEL$CC7EC59E" "T4"@"SEL$3" NONE BROADCAST)
      PQ_DISTRIBUTE(@"SEL$CC7EC59E" "T1"@"SEL$1" NONE BROADCAST)
      PQ_DISTRIBUTE(@"SEL$CC7EC59E" "T3"@"SEL$2" NONE BROADCAST)
      SWAP_JOIN_INPUTS(@"SEL$CC7EC59E" "T4"@"SEL$3")
      SWAP_JOIN_INPUTS(@"SEL$CC7EC59E" "T3"@"SEL$2")
    END_OUTLINE_DATA
  */

Perhaps there is another database view that exposes such information?

More resources:





Book Review: Oracle Tuning: The Definitive Reference Second Edition

7 11 2010

November 7, 2010 (Updated November 9, 2010, November 28, 2010, December 8, 2010, February 28, 2011, March 9, 2011)

1,100 Page True-False Quiz, “Definitive” is Left as an Exercise for the Student
http://www.amazon.com/Oracle-Tuning-Definitive-Reference-Focus/dp/0979795192/ref=dp_ob_title_bk

(Edit November 28, 2010: Amazon.com permitted me to submit a review for the book, but only for the first 85 or so pages.  Much more detail has been added to this review since the last update.)

Based on feedback that this book’s author provided in a comment attached to one of my other (thirteen) Amazon Oracle Database related book reviews, I decided to add a couple of comments at the start of this review.  Last year I contributed to a book that was written by a total of sixteen people, co-authoring two of the chapters in that book.  While that book contained “Oracle” in its title, and the two chapters that I co-authored were Oracle performance related, the book as a whole is not a competitor of the “Oracle Tuning: The Definitive Reference” book.  I am an IT Manager and Oracle DBA, so I am not a competing author or a competing Oracle consultant.  Additionally, I only review books that I have purchased using a portion of my paycheck, so my reviews also take into account whether or not I feel that I have received my money’s worth from a book – does the book deliver on the promises of its front cover and its description.

The author of the “Oracle Tuning: The Definitive Reference” book is described as having authored more than 30 books, is “one of the world’s top Oracle Database experts with more than 25 years of full-time DBA experience,” operates an Oracle consulting/training company, is the Editor-in-Chief at Rampant TechPress, participates in Oracle related discussion forums (including one operated by his consulting company), and produces articles for a non-Oracle specific blog.

Why did I buy the “Oracle Tuning: The Definitive Reference” book?  Put simply, I was curious.  I participated in several discussions with Mr. Burleson on Oracle’s OTN forums where his articles and sections of his previous books were discussed.  I brought to his attention a couple of what I felt to be errors and/or omissions from articles and book sections that were linked in the OTN threads.  More knowledgeable contributors to the OTN threads admittedly provided more thorough feedback to Mr. Burleson.  So, I was curious to know whether or not some or all of those corrections and suggestions became a part of the second edition of this book. The second edition of this book is the first book that I purchased that was published by Rampant TechPress, and the first book that I purchased which was written by Mr. Burleson.  I initially ordered the book from Amazon at the end of May 2010 (it was expected to be in stock the first week of June 2010), and when it had not shipped by the end of August, my curiosity subsided due to the delay (and various other reasons) and I cancelled the original order.  Near the end of October 2010 my curiosity peaked again, so I placed a new order for the book (at that time the book was expected to be in stock the first week of November 2010).  While waiting for the book to arrive, I started reading portions of the first and second editions of the book through the Google books library.

Considering that the word “definitive” appears on this book’s front cover, and the book publisher’s website states the following, I expected to see information that went well beyond showing long listings followed by a sentence or two: “This is not a book for beginners. Targeted at the senior Oracle DBA, this comprehensive book gives you all of the knowledge you need to be successful in tuning even the most complex Oracle database.”  So, how well did the book meet the level of expectation that was set by its front cover and publisher’s description?

The first and second editions of this book are partially viewable through Google books, and I suggest that anyone considering the purchase of this book should first read a couple of pages of the book at a local bookstore or through the Google books interface.  In comparing the first 30 pages of the first edition with the first 250 pages of the second edition, it is apparent that a much more reasonable font size was selected for the second edition of the book.  Several logic, spelling, and grammar errors that are present in the first edition were corrected or removed from the second edition.

Now, moving on to the problems that prevented this book from receiving a five out of five star rating.  Internet searches of phrases from the book identified several paragraphs that were directly copied and pasted from other books (most published by Rampant TechPress), other articles, the official Oracle documentation, and in at least one case part of the contents of a script found in the RDBMS/ADMIN directory of the Oracle Database home – the original sources of the material were not mentioned.  The book repeatedly emphasizes the goal of changing/flipping initialization parameters, using a scheduling utility, periodically throughout the week (or even throughout the day) in anticipation of workload changes.  Unfortunately, a number of the scripts that the author provides to help the reader with monitoring the workload, so that the reader knows when to automatically flip the initialization parameters, do not provide the information claimed in the book.  Repeated advertisements of the author’s Ion tool are unnecessary distractions throughout the book.  Most importantly, the number of errors and lack of sufficient detail prevent the book from meeting my expectations of a book that is advertised as comprehensive and targeted at the senior Oracle DBA; for example, showing the output of DESC V$SYS_TIME_MODEL and a simple listing of the statistics names in that view cannot be described as comprehensive, or as targeted at the senior Oracle DBA.

This review is roughly 24 typewritten pages in length, several times longer than any of my previous Oracle related book reviews.  The significant number of specific errors, omissions, and distractions far exceeds the problems per page count of any other Oracle related book that I have read to date, and the listed items below likely miss less easily identified problems that a senior Oracle DBA with 25 years of experience or an Oracle Certified Master/Oracle Ace should be able to identify.  I am a bit disappointed that most of the errors that I previously pointed out to the book author, as well as those errors identified by others, were reprinted, or even added to the second edition of this book.  This book truly is not targeted at beginners, but it makes for a spirited true/false quiz or even an essay exam for someone who has a bit more Oracle Database knowledge by having read portions of the official Oracle Database documentation as well as other books.  Those DBAs who enjoy hourly parameter modification, running their databases with multiple block sizes, and performing frequent index rebuilds might find value in this book if those DBAs are able to over-look the sometimes ragged joins of sections of multiple books being copied into this book and the scripts that do not work as designed.

Specific errors, omissions, and distractions in order for the first 200 or so pages followed by random selections from other parts of the book (the detail behind the rating assigned to the book) (edit November 11, 2010 ~ 111110: Google Books preview for the book):

  • Page 1 contains an advertisement for the author’s Ion product and some sort of a script library that can be purchased.
  • Page 6 states that the author “wrote five of the officially authorized Oracle Press books.”  Books with the “Oracle Press” logo are not officially authorized by Oracle Corporation.  “Oracle Press” is simply a marketing label applied to books published by McGraw Hill.
  • Each chapter opens with a cartoon drawing that is typically one half to two-thirds as tall as the page.
  • Page 8 states “This tuning approach is concerned with delivering data to the end-users quickly, even if it means that the database will consume additional resources.  This approach is associated with the SQL optimizer goal of first_rows_n.”  This statement is a bit sloppy.  The intention of the OPTIMIZER_MODE parameter’s value FIRST_ROWS_n (where n is one of 1, 10, 100, or 1000) is to return the first n rows as quickly as is possible, with the assumption that the remaining rows in the resultset will not be retrieved.  The statement in the book seems to imply that setting the OPTIMIZER_MODE to a value of FIRST_ROWS_n will allow retrieval of ALL of the rows from the database as quickly as possible, with the tradeoff being an increase in resource usage.  Technically, it is not the database that is consuming the resources, but instead the instance’s processes.
  • Page 10, starting to notice several paragraphs that are a single sentence in length, and this formatting continues throughout the book.  SQL code listings also seem to be formatted to consume as much vertical space on a page as is possible.
  • Page 10, confusing sentence/paragraph, “The Oracle 11g SQL tuning advisors are a fully automatic SQL tuning approach and that they use a reactive tool approach, waiting watching for problems to occur.”
  • Page 10, after stating on the previous page that “reactive tuning deals with the present, commonly using v$ views and Active Session History (ASH),” the book states on page 10, “in reactive tuning, the Oracle DBA fights the symptoms, not the disease… Reactive tuning is also problematic because we wait until end-users have been inconvenienced.”  The book author is advocating the use of what he terms “proactive tuning”, which the author describes as attempting to determine the best combination of database parameters and tablespace/table options for each SQL workload.  Confusingly, the author also states that his “proactive tuning” method uses Active Session History, Statspack, and the Automated Workload Repository.  In my opinion, reacting to what is found in ASH, AWR, Statspack reports, most V$ views, and 10046 trace files should be termed as “reactive tuning”, where the DBA responds to an actual identified problem experienced by the end-users.  What the author describes as “proactive tuning” appears to be more along the lines of initialization parameter flipping while end-users are not complaining.
  • Page 11 states “For example, if the AWR shows that the demands on the shared pool become very high between 1:00 pm and 2:00 pm, the DBA might trigger a dynamic decrease of db_cache_size and a corresponding increase of the shared_pool_size parameter during this time period.”  If Oracle’s buffer cache is using the memory specified by the DB_CACHE_SIZE, the size value specified for DB_CACHE_SIZE cannot be decreased without first manually flushing the buffer cache – flushing the buffer cache to allow the shared pool to grow for an hour is a bad idea.  It is important to keep in mind that when the SGA_TARGET parameter is specified, the values for DB_CACHE_SIZE and SHARED_POOL_SIZE specify the minimum values for the parameters.
  • Page 12, when describing examples of poor schema design, suggests that databases using extensive data normalization to minimize data redundancy is a poor design because it forces Oracle to perform unnecessary table joins.
  • Page 12 states, “If poorly designed PL/SQL is encountered, users may be able to tune the database by using array processing such as bulk collect, forall and ref cursors…”  As of Oracle Database 10g, Oracle automatically array fetches 100 rows at a time in cursor FOR loops, which might make it much less likely/necessary that a ‘user’ will re-write the PL/SQL to take advantage of bulk collection’s slightly better performance, assuming that the ‘user’ is not synonymous with ‘end-user’ (reference).
  • Page 15 a confusing sentence, “In these cases, we need to adjust the instance parameters need to change, depending on the time-of-day and day-of-week.”
  • Page 17, the timeline states, “1990s: Oracle is developed and relational databases dominate the IT market.”  This timeline statement, giving consideration to the lack of mention about databases prior to 1990, seems to indicate that Oracle Database version 2 did not exist in 1979.
  • Page 17 states, “RAM speed has not improved since the 1970s while CPU speeds get faster every year.”  This is an inaccurate statement about memory speed not improving.
  • Page 19, figure 1.2, which is described as “The Intel CPU Architecture of the Early 21st Century” seems to be terribly out of place in this section of the book, the acronyms contained within the figure are not explained, and the figure fills half of the page.
  • Page 21, figure 1.3, which is described as, “The Changing Dynamics of Human and Hardware Costs” simply shows the intersection of an ascending line labeled as People Costs and a descending curve labeled as Hardware Costs.  It might have been helpful to provide some sort of numbers on the illustration to indicate a timeline and monetary figures – at what point did hardware costs and DBA costs equalize?
  • Page 22 states, “The number one cause of poor performance is the over-normalization of Oracle tables.”  Interesting.
  • Page 22 states, “All SQL should use bind variables, preferably in the code or via cursor_sharing=force, to make SQL reusable within the library cache.”  In general, most SQL statements should use bind variables, but of course there are occasions where the use of bind variables should not be used.  “All” is too strong of a recommendation, and failure to use bind variables does not automatically make the already hard parsed SQL statement unavailable for reuse.
  • Page 22 states, “Failure to set pga_aggregate_target to allow the CBO to choose hash joins can result in very slow SQL performance.”  It is unclear from this section in the book if the PGA_AGGREGATE_TARGET must just be set to a non-zero value, or if there is some other value that it must be set to in order for Oracle’s optimizer to consider using hash joins.  Considering that the optimizer may select to use a hash join when the PGA_AGGREGATE_TARGET parameter is set to a value of zero, and also when that parameter is set to a small value, this statement found in the book is vague.
  • Page 25 states “The first tasks when tuning a database are to identify the external bottleneck conditions, which may include: CPU Bottleneck,… RAM Bottleneck,…  Network Bottleneck, … and Disk Bottleneck.”  While it is important to check these items, I suggest that these probably would not be the first items to check when tuning the database instance’s performance.  Yes, checking whether or not the CPUs are overloaded (or heavily loaded) is important, but maybe it would be better to determine if the overload is causing a measurable negative impact on performance by first checking the delta values of the various wait events, system statistics, and system time model statistics before deciding to check, for instance, whether there are network bottlenecks.
  • Page 25 states, “When the number of run queue waits exceeds the number of CPUs on the server, the server is experiencing a CPU shortage… Note that a 10% CPU level is not always a concern as modern servers are designed to keep the processors as busy as possible.”  The first question is how would someone measure the number of run queue waits.  Is this a measurement over a period of time, or is it an instantaneous measurement of the number of processes waiting to run on the CPUs, or is it an instantaneous measurement of the number of processes currently running on the CPUs plus the number of processes waiting to run on the CPUs?  The second question is whether or not the system can be considered to be CPU bound before the run queue length matches the number of CPUs in the server; for example, previous pages in the book suggested setting the processor affinity or using VMWare to confine the instance (or its processes) to a subset of the CPUs, or to use the Unix nice command to alter the dispatching priority of processes.  The third question is why was 10% selected, and not 50%, 75%, 90%, or 100%?  The first edition of the book did not include the word “wait” in the quoted sentence, and I believe that word causes additional confusion in this edition of the book.
  • Page 25 states that “Large amounts of Oracle*Net traffic contribute to slow SQL performance.”  The book does not describe what is considered “large amounts”, nor what to do about addressing the network bottleneck.
  • Page 25 under the heading of disk bottlenecks the only issue identified is “using RAID5 for high update systems.”  The adjective “high” is never clarified.
  • Page 25 states, while discussing potential solutions for over-allocation of the server’s RAM, that the options for “excessive swapping is to add more RAM, reduce the size of Oracle’s SGAs, or turn on Oracle’s Shared Server.”  Are these the only options, or could more suggestions be recommended?  For example, “size of Oracle’s SGAs” implies that more than one instance is running on the server – would it make sense to reduce the number of instances on the server (suggesting so would, of course, disagree with an earlier suggestion of moving most/all of the instances to a single high-end internally redundant server)?  Are there any reasons not to implement a shared server configuration?  What about tuning the SQL, analyze excessive PGA utilization, etc.?
  • Page 26, the author appears to misuse the term “network latency”, or at least stretch the meaning of latency as it applies to a network.
  • Page 26 and 27 include half page advertisements for the author’s Ion tool.  Pages 42, 46, 60, 62, 68, 71, 73, and 89 also include an advertisement for the tool.
  • Page 27 states “In a disk-bound database, the majority of the wait time is spent accessing data blocks.”  It is quite possible in a non-disk-bound, well performing database instance that the majority of wait time could very well be spent reading data blocks.  In fact, these events should be among the top 5 wait events, otherwise there probably is a significant performance problem.  It is also quite possible that the system could be disk-bound when the majority of wait time is spent _writing_ to the redo logs, archiving redo logs, and updating data/undo/temp/control files.
  • Page 27, the Top 5 Timed Events that are described as demonstrating a disk constrained database, shows 44 waits for the CPU.  Waits for the CPU cannot be reported in the Top 5 Timed Events – this data in the report is bogus.  The report also shows that the average single block read time is 2.75 seconds, while the average multi-block read time is 0.127 seconds (127ms) – this data in the report is also likely bogus.  The report also shows that 1,363 seconds were lost in 673 waits (average of 2.03 seconds) to the “library cache load lock” wait – if that wait appeared in the top 5 report, even in a report showing the single block read time is 2.75 seconds, I think it would be a good idea to start with the “library cache load lock” wait since that is one of the waits that indicates a severe problem if it appears in the top 5 wait events.
  • Page 28 states “CPU enqueues can be observed when the CPU run queue exceeds the number of CPUs on the database server. This can be seen by… If the system is already optimized, having CPU time as a top wait event is a positive because the addition of faster CPUs or more CPUs will relieve the bottleneck.”  The effects of CPU over-load may be observed long before the CPU run queue exceeds the number of CPUs in the server, whether it be longer average waits for the log file sync wait event, increased waits for latches, increased wait time for single block or multi-block reads, or any number of statistics in the system time model (V$SYS_TIME_MODEL, V$SESS_TIME_MODEL).  Additionally, upgrading and/or adding CPUs is not a cheap option from a licensing standpoint, and is not guaranteed to remove CPU time from the top five “wait” event list (it might even become more prominent as more processes may then simultaneously spin while trying to acquire a latch).
  • Page 28 shows the Top 5 Timed Events portion of an AWR report that includes 4,851 waits for CPU time – a Top 5 report cannot show the number of waits for the CPU – this data in the report is bogus.  Second, the CPU is a limited “wait” resource with an upper utilization limit equal to the number of CPUs in the server multiplied by the elapsed number of seconds, while the other foreground wait events, for the most part, have an upper limit of the average number of sessions (plus parallel related additional processes) connected to the instance multiplied by the elapsed number of seconds.  It is quite possible that a server experiencing excessive CPU usage may not cause the “CPU time” to appear in the top 5 timed events.  Third, we do not know how many CPUs are in the server – would it make a difference if there was only a single CPU compared to 96 CPUs?  Fourth, we have no concept of the elapsed time represented by the report – what if the elapsed time for the report is eight hours (the total reported CPU time is 4,042 seconds)?  Fifth, if the single block read time averages more than a second, shouldn’t the investigation start with the IO system?  Sixth, the most that can be determined from the top 5 timed events is the average utilization, number of waits, and number of timeouts – why are the number of timeouts not shown in the book?  From the top 5 timed events it is difficult, if not impossible, to determine if there wasn’t a brief period of intensive activity, followed by a long period of almost no activity – or if the average activity levels were fairly constant in the time period.
  • Page 28, the Top 5 Wait Events portion of an AWR report (what caused the switch from Top 5 _Timed_ Events as shown in the previous example) is labeled as a mockup – probably a good idea that this is labeled as such because the report shows 94,754 seconds where the server was waiting to send data across the network while single block and multi-block reads totaled only 85.75 seconds.  That is why you do not use a satellite link for the network backbone.
  • Page 29 states “Individual Program Global Areas (PGAs) for each session are a set of running programs that do work for the instance and are referred to as processes.”  To put it simply, PGA is much closer to a concept of “an allocated block of memory”, than it is to “a set of running programs” (reference).
  • Page 30 describes the DB_CACHE_SIZE parameter as “the number of data buffers to allocate for the instance.”  The parameter does not specify the number of data buffers (blocks?), it specifies the amount of memory in bytes to allocate to the DEFAULT buffer cache (or the minimum amount in the event the SGA_TARGET is specified).
  • Page 30, a self-conflicting sentence that seems to make no sense. “The most important parameters for instance tuning are those that are immutable because they cannot be changed without starting and stopping the instance or using alter session commands or SQL hints.”
  • Page 30, the DB_FILE_MULTIBLOCK_READ_COUNT parameter is listed among the parameters that cannot be changed without bouncing the database – that is not correct.  When workload CPU costing is in use, the value of the DB_FILE_MULTIBLOCK_READ_COUNT parameter also has no effect in costing of multi-block reads, in stark contrast to the statement made by the book that it is (implied always) used in optimizer costing calculations.
  • Page 30 states “parallel_automatic_tuning:… since parallel full-table scans are very fast, the CBO will give a higher cost-to-index access and be friendlier to full-table scans.”  This is simply incorrect.  The optimizer does not increase the cost of index access paths when costing parallel access paths that use full table scans – it lowers the cost of the full table scan relative to the parallel degree.  Second, parallel full table scans are not automatically very fast, especially if the IO subsystem is bottlenecked.
  • Page 30, the description of the OPTIMIZER_INDEX_COST_ADJ parameter is very weak, “this parameter controls the relative costs of full-table scans versus index scans.”  It would be much better to state that the parameter specifies the percentage of the index access cost to be retained.  Setting the value to a very low value could cause the optimizer to select not only an index access path rather than a full table scan, but to select the wrong index due to cost rounding problems as the value of the OPTIMIZER_INDEX_COST_ADJ parameter approaches 1.  Ideally, since at least Oracle Database 10.1 (and possibly as early as 9.0.1) this parameter should be left at the default value of 100 due to the Oracle optimizer’s use of system (CPU) statistics by default (the default behavior of system statistics usage changed in 10.1).
  • Page 30, the description of the OPTIMIZER_INDEX_CACHING parameter is vague – the book doesn’t indicate when the value of the parameter is used in cost calculations, and when it is not used.
  • By page 30 the book has recommended the use of SQL Performance Analyzer, SQL Tuning Advisor, AWR, ASH, accessing the various DBA_HIST views, and accessing the various performance views in Enterprise Manager without mentioning the various extra cost licenses required to use those features.  For example, the book should have mentioned that the Diagnostic Pack must be licensed for access to AWR information, and the Diagnostic and Tuning Packs must be licensed for access to the SQL Tuning Advisor, long before any mention of needing to purchase additional licenses on page 31.
  • Page 33, the half-page SQL script printed in the book and in the source code depot is Oracle Database’s DBA_FEATURE_USAGE_STATISTICS view definition found in the  catdbfus.sql file located in the RDBMS/ADMIN directory of the Oracle home.  For some reason this script is marked as “Copyright © 2005 by Rampant TechPress” in the script library for the book, while the original version found in the Oracle home is marked “Copyright (c) 2002, 2005, Oracle. All rights reserved.”  No effort is made in the book to interpret the meaning of the columns returned by this view.
  • Page 34 states “Starting in Oracle 10g, statistics collections are automated, but users may still need to selectively add histograms and other specialized optimizer statistics.”  The book does not state what triggers the statistics collection for a specific object, at what time the statistics are collected, that histograms (maybe excessively) are automatically generated, nor the potential problems that might be encountered after the statistics collection.
  • Page 34 indicates that table compression is introduced in Oracle 11g.  That feature was actually introduced in Oracle 9i R2 (reference).
  • Page 35 states “In Oracle 11g we have SQL profiles and the SQL Access Advisor to help identify sub-optimal SQL statements. Once identified, the SQL profile utility will allow changes to execution plans without adding hints.”  This is untrue – a SQL profile is a series of hints that are automatically generated and applied to the SQL statement during cost-based optimization.
  • Page 36 mentions that Oracle 10g will sometimes automatically rewrite a SQL statement into a more efficient form, but does not provide much, if any, detail describing why this is done, how to see that it has happened, or what to do if the rewritten form is not more efficient (Oracle 9i’s cost-based optimizer was also able to rewrite SQL statements).
  • Page 39, frequently uses the term “Oracle” to mean both Oracle Corporation and Oracle Database, even in the same sentence, and that makes it a bit difficult to comprehend the intention of some of the passages in the book.  For example, “Oracle first addressed this problem by developing special advisory utilities in Oracle.”
  • Page 39, the text at the bottom of the page appears to be a copy and paste of text that appeared in a book titled, “High Performance Data Warehousing” which was originally copyrighted in 1997.
  • Pages 40, 90 is the large Trumpet of Doom graphic useful?
  • Page 46, the bottom half of this page is largely a direct copy and paste of pages 8 and 9 of an article titled “Metric Baselines: Detecting Unusual Performance Events Using System-Level Metrics in EM 10GR2” that was written by John Beresniewicz at Oracle Corporation.  The article is marked Copyright 2005 by Oracle Corporation (reference which was hosted by permission of the author).
  • Page 47 states, “When the data buffer hit ratio falls below a predefined threshold, it might be useful to add RAM to the data buffer cache.”  It is not a good idea to tune databases based on the buffer cache hit ratio, a ratio that started falling out of favor by the mid to late 1990s (reference).
  • Page 49 states that when the buffer cache hit ratio drops below 70%, the DBA should set up the system to dynamically adjust the buffer cache.
  • Page 51, the text in the last section of the page is largely a copy and paste of page 36 of the book “Oracle Silver Bullets: Real-World Performance Secrets”.
  • Page 52, it would have been helpful if the book briefly described why each of the statistics that were listed are the most commonly used statistics for Oracle exception reporting.
  • Page 53, the SQL statement lacks an ORDER BY clause, which possibly means that the SQL*Plus BREAK ON command will add extra line breaks in unexpected positions in the output.
  • Page 56, table 2.2 is almost an exact copy and paste, ignoring slight formatting differences, of the Oracle Database Reference documentation from Oracle Corporation for DBA_HIST_TEMPSTATXS (reference).
  • Page 57, the SQL statement does not work as described for a variety of reasons, including the cumulative nature of the statistic values, with no attempt to calculate the delta values of the statistics.  This is one of the SQL statements that the book suggests for trend identification with the goal of scheduling the automatic changing of initialization parameters.
  • Page 58, the SQL statement does not work as described for a variety of reasons, including the cumulative nature of the statistic values with no attempt to calculate the delta values of the statistics.
  • Page 61, the SQL statement does not work as described for a variety of reasons, including the cumulative nature of the statistic values with no attempt to calculate the delta values of the statistics.
  • Page 65 simply shows a DESC for V$SYS_TIME_MODEL and V$SESS_TIME_MODEL, and includes a list of the STAT_NAME values found in those views without attempting to describe the meaning of the STAT_NAME values.
  • Page 67, the author does not explain the parent-child relationships of the statistics from V$SESS_TIME_MODEL, rather the query just sorts the statistics in descending order by time.
  • Page 69, the SQL statement does not take into account that some of the sessions may have been connected for more than a year, while other sessions may have been connected for only a couple of minutes.  Consider how a check of the db time statistic for the two sessions might show similar values for the two sessions – which of the two sessions represents more of a potential impact on system-wide performance?
  • Page 70, the first SQL statement querying AWR data that compares two snapshots, unfortunately the script header in the book does not match the script header in the script library for the book, making it difficult to locate the script.  Matching scripts listed in the book with those in the script library is difficult for many of the scripts due to the scripts being labeled differently in the book and script library.
  • Page 74, the book states that AWR and Statspack reports show time model statistics, and then proceeds to show operating system statistics from an Oracle Database 10.1 report which shows statistics ending with _TICKS, rather than _TIME which became standard starting with Oracle Database 10.2.  It would have been helpful if this section of the book were updated to show the _TIME statistics, or at least mention that the reader will likely see _TIME statistics rather than _TICKS statistics.
  • Pages 81 through 83, the discussion of Oracle Data Miner and decision support systems seems to be off topic for this book.
  • Page 85 states, “this can be plotted as a 1/x function and the exact optimal point computed as the second derivative of the function 1/x as shown in Figure 4.1.”  Many fancy words in this sentence, but no example is provided that shows how to translate the displayed statistics into the graph, how to calculate the second derivative of the 1/x function, or exactly what x is.  Quite often the data contained in the V$DB_CACHE_ADVICE view does not conform to any kind of curve that is represented by figure 4.1.
  • Page 87, the SQL statement does not work as described for a variety of reasons, including the cumulative nature of the statistic values with no attempt to calculate the delta values of the statistics.  This is one of the SQL statements that the book suggests for trend identification with the goal of scheduling the automatic changing of initialization parameters.
  • Page 91, the cumulative nature of the AWR data seems to imply that the author’s database is bounced late every Sunday night – other than that, the chart’s information is nearly useless because the delta values of the AWR statistics were not calculated.
  • Page 92, table 4.2 appears to be a direct copy and paste of the Oracle documentation library for DBA_HIST_ACTIVE_SESS_HISTORY (reference).
  • Page 93, the SQL statement does not work as described for a variety of reasons, including the cumulative nature of the statistic values with no attempt to calculate the delta values of the statistics.  One might wonder how this SQL statement would behave in a RAC environment.
  • Page 95, table 4.3 appears to be a direct copy and paste of the Oracle documentation library for DBA_HIST_FILESTATXS (reference).
  • Page 96, it is interesting that the script output on page 96 matches the script output on page 57.  The SQL statement does not work as described for a variety of reasons, including the cumulative nature of the statistic values with no attempt to calculate the delta values of the statistics.
  • Page 100 contains what is essentially a full-page advertisement for the author’s remote DBA consulting company.
  • Page 102, two unnecessary cartoon drawings, one apparently depicting an upset IT manager, and another depicting a person wearing a ski mask while working on a computer.
  • Page 103, the case study suggests that changing the OPTIMIZER_MODE from the default of ALL_ROWS to FIRST_ROWS_100, followed by restarting the database instance corrects performance in OLTP type databases.  “Their DBA did not understand the difference between the optimizer goal of all_rows, which minimizes computing resources and favors full-tale [sic] scans and the first_rows_n optimizer which sacrifices fast throughput in favor of fast access via indexes.”  First problem with this advice: bouncing the database is not necessary when changing the OPTIMIZER_MODE parameter’s value – simply changing the parameter value will automatically force a hard parse of each SQL statement the next time that SQL statement is executed – the client experienced an unnecessary system outage when the database was bounced, as well as losing the performance benefits derived from the blocks already residing in the buffer cache.  Second problem with this advice: it might simply be the case that due to the presence of histograms, some of the execution plans were less than optimal due to the specification of uncommon (or very common) bind variable values on the initial hard parse as a result of the optimizer peeking at the initial bind variable values to generate an optimal execution plan for those values.  Adaptive cursor sharing, introduced in 11.1, reduces the risks associated with the combination of bind variable peeking and histograms on columns (this was not mentioned).  By changing a global setting, such as the OPTIMIZER_MODE parameter, rather than spending a couple of minutes enabling a 10046 trace for a slow session, or examining an AWR or Statspack report to identify resource intensive SQL statements, the author possibly caused other performance problems for any SQL statement that, for example, might exist in a report which typically returns more than 100 rows.  If a query is expected to return 100 or fewer rows, the execution plans should be identical when the OPTIMIZER_MODE parameter is set to ALL_ROWS and when it is set to FIRST_ROWS_100 (this value tells the optimizer to assume that all rows after the first 100 will be discarded) which probably describes most of the queries that are commonly executed in OLTP databases (with the exception of a few).  Third problem with this advice: the author did not describe why FIRST_ROWS_100 was selected rather than FIRST_ROWS_1, FIRST_ROWS_10, or FIRST_ROWS_1000 (or actually even provide a good explanation why ALL_ROWS was the wrong setting).
  • Page 104 states, “in this emergency, an Oracle9i shop called complaining about a serious degradation in SQL performance right after implementing a partitioned tablespace.”  I was not aware that a tablespace could be partitioned, and a search of the Oracle documentation library found nothing on this topic.  The author provided a DBMS_STATS.GATHER_SCHEMA_STATS command with several parameters.  Only the DEGREE parameter was explained, stating that it allowed collecting the statistics using 15 parallel processes.  I wonder if the author reset the parallel degree of the indexes belonging to the schema from the resulting value of 15 to the normal value of 1?
  • Page 104, the author references output generated by his plan9i.sql script, and indicated that the output showed unnecessary full table scans of large tables.  We really do not know if this database had been online for a couple of hours, or a couple of years based on the output.  In examining the contents of the plan9i.sql script, there are a couple of problems with the script.  First, it queries V$SQLAREA rather than V$SQL, so it is completely blind to the possibility that multiple child cursors might exist for the same SQL statement, each with different execution plans.  Second, the script reports on all SQL statements that are still in the library cache when the sum of the executions of those SQL statements is ten or greater when grouped by the table’s name – this sum becomes the NBR_FTS column.  Therefore, the NBR_FTS column does not take into account the fact that a full table scan of a table may be performed more than once per execution of the SQL statement, and fails to count the full table scans that happened for SQL statements already aged out of the library cache.  Third, the case study did not discuss how to examine whether or not the full table scans were more efficient than an available index access paths, or how it was found that a common WHERE clause in the query contained a bind variable name that was wrapped in single quotes.  Fourth, how did creating a single index fix the five tables in the output, yield a 50 fold performance improvement, and reduce disk I/O by 600%?
  • Page 105, how did creating a single function based index fix the five tables in the output and result in a five-fold performance improvement?
  • Page 105, the silver bullet tip to change the CURSOR_SHARING parameter to FORCE did not warn of any of the possible side-effects, which may include poor performance when cursors that should not be shared because uneven data distributions may cause the optimizer to generate execution plans that are inappropriate for other literal values, or bugs related to CURSOR_SHARING that either result in wrong data being returned, or instance stability problems.  It would be interesting to see how the 75% performance improvement was achieved by changing this parameter.
  • Page 106, as mentioned previously, the author’s plan9i.sql script shows something other than what is described, so the output presented in the book may or may not be useful.  Additionally, the author did not state whether the database had been online for an hour when the report was generated, or three years.  The author’s buf_blocks.sql script, mentioned in this section of the book, is a bit interesting.  The script builds a normal table T1 by selecting a count(distinct file# || block#) of the blocks in the buffer cache, joined to DBA_OBJECTS, when grouping on the OWNER, OBJECT_NAME, SUBOBJECT_NAME, and OBJECT_TYPE.  The script then joins the T1 table to DBA_SEGMENTS in order to calculate the percentage of the object’s blocks that are currently in the buffer cache for all objects with at least 11 blocks in the buffer cache.  Why does the script’s output, that is printed in the book, show six tables with seven or fewer blocks in the buffer cache.  Additionally, if these table blocks really were accessed frequently, wouldn’t Oracle automatically keep the blocks in the buffer cache by promoting the blocks closer to the MRU end.  The author’s buf_keep_pool.sql script is also a bit interesting, as it generates SQL statements to alter all objects that have more than 80% of their blocks in the buffer cache, so that the objects will reside in the KEEP buffer cache (if not already in the KEEP buffer cache).  This seems slightly counter-intuitive to move these objects out of the DEFAULT or RECYCLE buffer cache and into what is likely a smaller KEEP buffer cache.  Additionally, this script could not have been used as described in the book because all of those tables listed in the book had less than 0.45% of their blocks in the buffer cache.
  • Page 107, technically, the 2GB per process limit on 32 bit Windows can be raised to almost 3GB (Metalink recommends lowering the maximum from 3GB) by adding the /3GB parameter to the boot.ini file (reference).
  • Page 107, Figure 5.1 is described as showing the output of the author’s plan9i.sql script.  Figure 5.1 actually shows a “Top 5 Timed Events” report, possibly from Statspack.  The book states that the database was crippled by db file scattered read wait events, yet the “Top 5 Timed Events” printed in the book shows a much more sinister problem.  While 3,246 seconds were spent on the db file scattered read wait event (average wait time 0.010 seconds), 1,363 seconds were spent on the library cache load lock wait event (average wait time 0.29 seconds), and 7,146 seconds were spent on the db file sequential read wait event (average wait time 0.013 seconds).  If I was presented with the same “Top 5 Timed Events”, I probably would have been focusing on the time lost to the library cache load lock wait, rather than trying to create a materialized view.  It is rather amazing, considering the “Top 5 Timed Events”, that the three materialized views reduced disk I/O by more than 2,000 percent and improved database performance 30 fold.
  • Page 108, the case study that suggests implementing bitmap indexes seems to be flawed.  An AskTom thread detailed the flaws better than I am able to do so (reference).
  • Page 108, the adding freelists case study lacks sufficient detail for a person to be able to use that case study to help solve a problem experienced by the reader.  For example, the book does not describe how the author was able to examine V$SQL and discover that “virtually all” of the DML statement were inserts into the CUSTOMER_ORDER table – what in V$SQL did the author examine?  Were there no SELECT statements (those are considered DML also)?  The author stated “the top timed event was buffer busy waits and it was clear that there were enqueues on the segment header blocks for the table and its indexes.”  The author does not describe how the transition from “virtually all” DML were inserts into a single table (I wonder if the header detail and order line detail were both contained in the same CUSTOMER_ORDER table) was made to stating that the buffer busy wait problem was in fact indicating a problem with waits for the segment header blocks for the CUSTOMER_ORDER table and its indexes.  Was it just coincidence because the two seemed to be happening at the same time, and was therefore a lucky guess?  The author’s website stated that this was a 9.2.0.4 database (reference), so how did the author determine that the buffer busy waits where not caused by the same action that is reported as the read by other session wait in 10g?  Did the author check V$WAITSTAT, V$SESSION_WAIT, generate a 10046 trace, or do something else?  Setting the freelists for the CUSTOMER_ORDER table and an index named CUST_PK to a value of 5 immediately saved the client $500 per minute?  Finally, what conditions would have to be present for a buffer busy wait to last 30 seconds, was someone playing with bitmap indexes (assuming that some of the sessions were also waiting in enqueue waits), and would that problem be fixed by altering the freelists?  (Edit: December 9, 2010: this $500 per minute fix is also described on page 697, but in this case the book mentions that the Oracle Database release version is in fact 9.2.0.4).
  • Page 110 states, “with the Internet, there is a wealth of information about Oracle troubleshooting and some of it is good, while most of it is absolute garbage.  Every self-anointed Oracle expert is touting their own methodology for Oracle troubleshooting, and some are absolute zealots in proclaiming their approach as the ‘best’ method.”  I am having a little trouble translating these two sentences.  Is the author stating that the Oracle experts who smear themselves with perfumed oil will refuse to believe any other method is better?  Or is the author stating that some people who self-proclaimed that they are one of the best Oracle experts in the world, have a tendency to game the Internet search engines?  Either way, the two sentences should be rewritten to clarify the author’s intention.
  • Page 111, the quote printed in the book from the documentation appears to have been re-worded in the 11g documentation, however I am not sure that the quote indicates that Oracle Corporation recommends the use of the buffer cache hit ratio for much of anything.
  • Page 112, the book describes how in a well-tuned database the buffer cache hit ratio metric is useful.  Half of page 112 is devoted to showing a buffer pool advisory for an instance with a 52MB buffer cache.
  • Page 115, the script printed in the book for calculating the buffer cache hit ratio accesses SYS.V_SYSSTAT, rather than the more common view synonym V$SYSSTAT.  The printed script also does not match the buffratio.sql script from the book’s script library, where the book specifies the “db block gets”, while the script from the script library specifies “physical reads direct (lob)”; the book specifies “consistent gets”, while the script from the script library specifies “session logical reads”.  Worse yet, neither formula matches the formula printed in the Oracle Performance Tuning Guide, which is part of the official Oracle Database documentation (reference).
  • Page 117 states, “by default, this [TIMED_STATISTICS] parameter is set to false, which disallows the collection of wait times for each wait event defined in the Oracle engine.”  This statement is incorrect as of the release of Oracle 10.1.  The TIMED_STATISTICS parameter defaults to TRUE when the STATISTICS_LEVEL parameter is set to either the default value of TYPICAL, or the value of ALL (reference).
  • Pages 117-118 lists several wait event names that the author states “provides no real value to a DBA who is trying to figure out where a database bottleneck exists.”  The lists includes: lock element cleanup, SQL*Net message from client, SQL*Net more data to client, and PL/SQL lock timer.  The first of these wait events does not exist in an Oracle 10.2 database, and might have been made deprecated around the time of Oracle 8i. The SQL*Net message from client wait event, at the session level, will tell the DBA when the bottleneck is not in the database, and that could be extremely valuable information.  The SQL*Net more data to client wait event was highlighted on page 28 of this book as identifying a “Network Constrained Database”. (reference)
  • Pages 118-119, while the script does execute, it probably should be updated to use analytic functions to eliminate the need of joining two inline views that both query SYS.V_SYSTEM_EVENT.  Additionally, it would probably be helpful if the script also eliminated most of the idle wait events introduced since Oracle 10.1, for example: jobq slave wait, DIAG idle wait, shared server idle wait, reliable message, etc.  Additionally, the script in the script library will not remove most of the idle wait events that are listed in the script because a blank space appears before the closing single quote for each of those wait events: ‘pmon timer ‘, ‘rdbms ipc message ‘, ‘smon timer ‘, etc.  The book did almost nothing with the script, other than to display the results in some sort of graphical query tool (most of the previous query results used SQL*Plus to show the results).
  • Pages 120-121, the sesswaits.sql script does not appear to be in the script library for the book.  The script in the book has an obvious typo near the beginning: “a.a.total_waits,”.  Like some of the other SQL statements, this SQL statement does not use the more common (those that are in the Oracle documentation) synonym names, but instead lists row source names such as SYS.V$_SESSION_EVENT.  A minor improvement would be to use meaningful aliases for row sources, rather than generic aliases such as A, B, and C.  This script attempts to remove some potentially helpful idle wait events, while not excluding some of the more recently introduced idle wait events.  The book did almost nothing with the script, other than to display the results in some sort of graphical query tool (most of the previous query results used SQL*Plus to show the results).
  • Pages 121-122, the csesswaits.sql script does not appear to be in the script library for the book.  This script attempts to remove some potentially helpful idle wait events, while not excluding some of the more recently introduced idle wait events.  The book did almost nothing with the script, other than to display the results in some sort of graphical query tool (most of the previous query results used SQL*Plus to show the results).  It is a bit disappointing that the author made little attempt to explain the columns returned from V$SESSION_WAIT (sys.v_$session_wait in the script).
  • Pages 122-123, the objwaits.sql script does not appear to be in the script library for the book.  The book states that the script may be used if enqueue waits are present in V$SESSION_WAIT to determine which object and datafile are “the holdup.”  The objwaits.sql script is not specific to enqueue type waits, and in some cases the ROW_WAIT_OBJ# from V$SESSION may not contain information about the object (showing a value of -1), while V$LOCK might expose the OBJECT_ID in the ID2 column during an enqueue wait.
  • Page 124, sentence uses the word “undo” rather than “undue”, “… to quickly pinpoint resource-intensive SQL code that is causing undo strain on the database.”
  • Pages 124-125 state that the number one Oracle Performance Myth is that, “eighty percent of a database’s overall performance is derived from the code that is written against it.”  An Internet search for this sentence finds essentially the same set of supporting paragraphs in a couple of other books (“High-Performance SQL Server DBA”, “Oracle Performance Troubleshooting with Dictionary Internals SQL & Tuning Scripts”).  Oddly, the publisher’s website’s description for the book “Oracle Performance Troubleshooting with Dictionary Internals SQL & Tuning Scripts Second Edition” uses essentially the same sentence as justification for its chapter 8 contents (reference reference2).
  • Pages 126-134 appear to be a copy and paste of pages 406-421 of the book “Oracle Tuning Power Tuning Scripts” with a small number of modifications.  It might be interesting to note that the script outputs in this section of the book also use a graphical screen capture from some program, rather than the raw SQL*Plus style output seen in the earlier portions of the book.
  • Page 126 recommends that temporary tablespaces be set to autoextend.  Run-away queries with missing join conditions can cause a lot of problems if temporary tablespaces are in fact set to autoextend with the maximum size set to unlimited (32GB for an 8KB block size database when a single file is used).
  • Page 126-127, the spacesum.sql script does not appear to be in the script library for the book.  How the script operates is not well described, and the top half of the UNION ALL returns a VARCHAR2 in the last column position, while the bottom half of the UNION ALL returns a NUMBER in the last column position.  It is not clear whether or not the query works as intended.
  • Page 128, the datafileae.sql script does not appear to be in the script library for the book.  This query joins SYS.DBA_DATA_FILES to SYS.FILEXT$ to determine which datafiles are configured to extend automatically.  It appears that the join to SYS.FILEXT$ is unnecessary as DBA_DATA_FILES contains the column AUTOEXTENSIBLE.
  • Page 129, the tsfrag.sql script does not appear to be in the script library for the book.  It is possibly interesting that the script calculates the square root of the square root of the COUNT of a column in DBA_FREESPACE when grouped by the tablespace name.
  • Page 130, the dffrag.sql script does not appear to be in the script library for the book.  This query joins SYS.DBA_DATA_FILES to SYS.FILEXT$ to determine which datafiles are configured to extend automatically.  It appears that the join to SYS.FILEXT$ is unnecessary as DBA_DATA_FILES contains the column AUTOEXTENSIBLE.
  • Page 131, the odd formatting were a single sentence becomes a paragraph has essentially changed the meaning of the second paragraph on the page such that it could be misunderstood.  The fragmentation terms honeycomb and bubble were used, but never defined.
  • Page 131, the tsmap.sql script does not appear to be in the script library for the book.  One might be curious to determine if any of these scripts for detecting fragmentation that examine extents in datafiles, if they work as described, are useful since the introduction of locally managed tablespaces in Oracle Database 8i roughly a decade ago (reference).
  • Page 132 states, “as a result of repeated insert and delete activity, tables can become internally fragmented and contain a lot of wasted space.”  I suspect that this is a confusing sentence, it seems that the book implies that when a row is deleted, the space previously occupied by the row cannot be reused – this is simply not true.  The book continues with, “In the same way, indexes can become fragmented so that their depth reaches unacceptable levels.”  The second quote also seems to imply that when an index entry is deleted, that the space cannot be reused.  Additionally, is this the definition of fragmented indexes that the author uses occasionally?
  • Page 132-133, the maxext.sql script does not appear to be in the script library for the book.  This script appears to be very similar to one that appears on page 144 in the book “Oracle Performance Troubleshooting: With Dictionary Internals SQL & Tuning Scripts” (even the graphical version of the query output matches), and for some reason the SQL statement excludes the SEGMENT_TYPE of CACHE, but not any of the other segment types (referencereference2)
  • Pages 129-144 appear to be copied and pasted, with minor changes, from pages 131-170 of the book “Oracle Performance Troubleshooting: With Dictionary Internals SQL & Tuning Scripts” (even the graphical version of the query output matches reference).
  • Page 133, the objdef.sql script does not appear to be in the script library for the book.
  • Page 134, potentially confusing sentence, “Sometimes, however, this is not the case, and the table suddenly finds itself containing chained or migrated rows, which are rows that span more than one data block.”
  • Pages 134-136, the tabreorg.sql script does not appear to be in the script library for the book.  This script uses the RULE hint, which according to the Oracle documentation is no longer supported as of Oracle Database 10.1 (reference).
  • Pages 137-138, the tabreorg.sql script does not appear to be in the script library for the book.  This script uses the RULE hint, which according to the Oracle documentation is no longer supported as of Oracle Database 10.1.
  • Page 138, a sentence seems to imply that a high clustering factor, or having the BLEVEL greater than four may be a reason to either reorganize (rebuild) an index or drop it.  Drop – maybe, rebuild – no.  Changing the clustering factor for an index requires changing the order of the rows in the table, although the clustering factor calculation can be thrown off if the statistics collection sampling percent is too low.
  • Page 140, the sgasize.sql script does not appear to be in the script library for the book.
  • Pages 143-144, the memsnap.sql script does not appear to be in the script library for the book.
  • Page 145, the poolhit.sql script does not appear to be in the script library for the book.  Page 145 also states, “However, when properly computed, the buffer cache hit ratio is an excellent indicator…”  The formula provided for calculating the buffer cache hit ratio appears to be incorrect, according to the formula that appears in the 11g R2 Performance Tuning Guide from the Oracle documentation library.
  • Page 145-146, the sesshitrate.sql script does not appear to be in the script library for the book.
  • Page 147, the sqlhitrate.sql script does not appear to be in the script library for the book.  Considering that it is possible for a SQL statement to have more than one execution plan, if this SQL statement is producing useful information it probably would have been a better idea to query V$SQL rather than V$SQLAREA.
  • Pages 148-156 appear to be copied and pasted, with minor changes, from pages 182-196 of the book “Oracle Performance Troubleshooting: With Dictionary Internals SQL & Tuning Scripts” (reference) .
  • Page 148, the explain plan format pre-dates the release of Oracle 10.1, and shows the use of the OPTIMIZER_MODE CHOOSE which became deprecated with the release of Oracle 10.1.  The book calls a listing “runtime statistics”, but does not explain how the statistics were generated (likely the output of SQL*Plus’ AUTOTRACE functionality).
  • Page 149 states, “The amount of logical reads has been cut in half simply by using the new 16K tablespace and accompanying 16K data cache.”  It has been demonstrated to the book author multiple times why this test case is flawed (reference reference2 reference3 reference4).
  • Page 149, the cacheobjcnt.sql script does not appear to be in the script library for the book.
  • Page 150, the buffutl.sql script does not appear to be in the script library for the book.  The query joins SYS.X$BH to SYS.TS$ four times, rather than performing the join a single time with either a DECODE or CASE statement to differentiate the different values for the STATE column.
  • Page 152, the libdet.sql script does not appear to be in the script library for the book.
  • Page 153, the libwait.sql script does not appear to be in the script library for the book.
  • Page 153, the libobj.sql script does not appear to be in the script library for the book.
  • Page 155, the dictdet.sql script does not appear to be in the script library for the book.
  • Page 156-157, the text at the bottom portion of page 156 through the middle of page 157 appears to be copied and pasted from page 306 of the book “Oracle Tuning Power Scripts” (reference).
  • Page 157-158, the bottom half of page 157 through the top half of page 158 are supposed to demonstrate the wait events and statistics that will be present when the LOG_BUFFER parameter is undersized.  As of Oracle Database 10.2 the LOG_BUFFER parameter is automatically set to a value that is slightly smaller than the granule size, so having a value for that parameter not specified is not a significant risk starting with 10.2.  Page 158 has been addressed by other contributors on the Oracle OTN forums (reference reference2) .
  • Pages 158-195, the bottom of page 158 through page 195 appears to be copied and pasted (with minor modifications) from page 197-275 of the book “Oracle Performance Troubleshooting: With Dictionary Internals SQL & Tuning Scripts” (reference).
  • Page 159, the memhog.sql script does not appear to be in the script library for the book.
  • Page 160, the first paragraph on this page probably should have appeared on page 147, shortly after the script mentioned in the paragraph appeared in the book, rather than in a section of the book that describes session memory usage.
  • Page 161, which appears to be describing Oracle Database 8i and earlier, states, “if the memory sort ratio falls below 90%, increasing the parameters devoted to memory sorts, sort_area_size and sort_area_retained_size, may help.”  The first question someone might ask is why 90%, and not 99% or 50%?  It would probably be a better idea to determine which queries are causing the sorts to disk.  Maybe increasing the SORT_AREA_SIZE to 1000 times it original value will still not cause the memory sort ratio (which the book’s script calculates since the last bounce of the database) will not allow the ratio to increase to 90% – then what.  The second question someone might ask is what do these parameters do – if the reader sets the parameters to 500M to try to get the memory sort ratio to 90%, what kinds of problems might happen?
  • Page 161 seems to indicate that the PGA_AGGREGATE_TARGET will not be used for shared server connections.  While that was correct for Oracle Database 9i R1 and 9i R2, it is not the case starting with Oracle Database 10g R1 (reference).
  • Page 161 recommends that on a Unix server the PGA_AGGREGATE_TARGET be set to 90% of the memory remaining in the server after the database instance starts.  There are a variety of reasons why this is a bad idea, the fact that the PGA_AGGREGATE_TARGET is not a hard upper limit for PGA memory consumption is just one of those reasons.
  • Page 162, the term “one-pass memory” is mentioned but never defined.  The use of the term seems to imply that a workarea execution is either optimal or one-pass – are multi-pass workarea executions never a possibility?
  • Page 162, the bufobjwaits.sql script does not appear to be in the script library for the book.  Additionally, the script does not appear to be RAC aware as the statistic “gc buffer busy” was ignored and the query did not select from  GV$SEGMENT_STATISTICS.
  • Page 163, the latchdet.sql script does not appear to be in the script library for the book.  I suspect that it could be debatable whether or not the author’s specification that a 1% latch miss ratio indicates that further investigation is required – a better approach would probably start by seeing if a specific type of latching is contributing a significant amount of time to the wait events between a known start and end time.
  • Page 164, the currlwaits.sql script does not appear to be in the script library for the book.  This script uses SYS.V_$ view names rather than the officially documented synonym names, and uses alias “a”, “b”, and “c” rather than meaningful aliases for each of the views.  The query also contains an unnecessary subquery that queries SYS.V_$EVENT_NAME.
  • Page 165, while the globiostats.sql script is found in the script library, the statistic values that are requested seem to omit those statistics that are introduced in Oracle Database 10.1, and provide statistics values since the last open of the database.  I suspect that nightly backups, statistics collection, or scheduled index rebuilds might distort the statistics retrieved by the script.  Nothing is done with the script in the book – the book immediately led into another script.
  • Page 166, while the script syswaits.sql is in the script library for the book, the script printed in the book differs from what is found in the script library.  Additionally, the script in the script library includes an extra space before the closing single quote that follows each wait event name that should be excluded from the report.
  • Page 167, the advice about the “latch free” and “enqueue” waits predates the release of Oracle Database 10.1.  The advice about the “db file scattered read” wait event could cause unnecessary concern – that wait event should be one of the top wait events in a healthy database instance.
  • Page 168, the globaccpatt.sql script does not appear to be in the script library for the book.  The book makes no attempt to interpret the statistic values returned by the script, nor the meaning of the statistics.  The book does state that “large-table full-table scans can indicate sub-optimal SQL and/or missing indexes, cases where the SQL needlessly reads all blocks in the table.”  The book does not state which of the statistics indicate a “large-table full-table scan” – is it the “table scans (long tables)” statistic?  It is also quite possible that full table scans of long (large) tables may just indicate that everything is working as it should due to the data requirements, indexes with poor clustering factors, or maybe the database is simply a data warehouse.  For clarity, it is not the SQL that needlessly reads all of the blocks in the table.
  • Page 168 contains an advertisement for the author’s ION program.
  • Page 169 states that “if standard DBA practices have been followed and indexes are placed in their own tablespace, the I/O statistics for that tablespace can be examined to determine if the indexes are actually being used.”  Is it really a standard DBA practice to separate indexes from their tables by placing each into a different tablespace?  How would seeing the I/O statistics for a tablespace (more correctly the datafiles for the tablespace) really indicate if an index were used – an index may be used by Oracle Database’s optimizer without actually being used for query execution.
  • Page 169, the fileio.sql script found in the book differs significantly from the script by the same name found in the script library for the book.  The script found in the book seems to unnecessarily join several objects owned by the SYS user when a much more simple query could be written using the documented synonym names V$FILESTAT, V$TABLESPACE, V$DATAFILE, and V$TEMPFILE.
  • Page 170, the term “hub tables” is used without defining the term.
  • Page 170-171, the purpose of the toptables.sql script does not seem to be well defined, and might contain one or more errors.  The script returned no rows when tested.
  • Page 172, the largescan.sql script, identified as largescan9i.sql in the script library, fails to recognize that a table referenced in an execution plan and identified as experiencing a full table scan may actually be full table scanned many times when the SQL statement is executed once, even if the table is listed only once in the execution plan.
  • Page 172, a “large table” is defined within the script as a table that is more than 1MB in size.  If we associate this definition with the term “large-table” found on page 168, the reader might be a bit confused.
  • Page 173 states “one rule of thumb is that if any session is currently consuming 50% or more of the total I/O, that session and its SQL need to be investigated further to determine what activity it is engaged in.”  Why 50%?  Would it make a difference if there are 2 or 2,000 sessions connected?  Would it matter how many sessions are actively executing SQL statements?  Over what period would the DBA examine to see if a session meets the 50% criteria?  The provided script, physpctio.sql, bases the time period on the length of time that the session has been connected to the database.
  • Page 174, the totpctio.sql script is nearly identical to the physpctio.sql script from the previous page, and suffers from the same time scoping problem.
  • Pages 175-176, the topiousers.sql script is certainly long, and aside from renaming some of the statistic names from SYS.V_$STATNAME, really does not introduce any new information that was not provided by the earlier scripts.  The script has time scoping problems, and no effort is made to explain the meaning of the statistics returned by the script.
  • Page 177, the bgact.sql script is apparently not found in the book’s script library.  The script is described as “providing a handle on DBWR and LGWR activity,” yet the script retrieves the “dirty buffers inspected” foreground statistic and a “write requests” statistic that does not seem to be a valid statistic name (reference).
  • Page 178 states, “seeing non-zero values for the DBWR summed dirty queue length typically indicates that buffers are being left in the write queue after a write request.”  The “DBWR summed dirty queue length” statistic is apparently not an Oracle Database statistic, so seeing non-zero values might mean that something else is wrong.
  • Page 178 states, “non-zero values for the redo log space wait requests and redo log space wait time statistics could indicate the log buffer setting is too low.”  There is no statistic named “redo log space wait requests” – the actual statistic name is “redo log space requests”.  These statistics are not associated with the redo log buffer size, but instead the size of the redo log files in relation to the amount of redo information that needs to be written to the log files (reference).
  • Page 178, the archhist.sql script does not appear to be in the script library for the book.  The script summarizes by day, rather than a smaller time period such as an hour.  This might provide misleading information if on average 4 redo logs are archived per hour, but during busy time periods during the day archived redo logs are archived at a rate of once per minute – the average over 24 hours will hide important information about a problem.
  • Page 179, the rolldet.sql script does not appear to be in the script library for the book.  The script does not permit time scoping, uses the non-documented object names in the SYS schema rather than the public synonyms, and uses generic alias names for the objects.
  • Page 180, a sentence which makes no sense, “an overall contention ratio of 1% or higher is an indicator of too few rollbacks as well.”  First, the sentence is missing at least one word.  Second, the method to calculate the overall contention ratio is not described.  Third, why 1% and not 10% or some other number?
  • Page 181, the totuserspace.sql script does not appear to be in the script library for the book.
  • Page 182, the sortusage.sql script does not appear to be in the script library for the book.
  • Page 182, the sortdet.sql script does not appear to be in the script library for the book.
  • Page 183-185, the topsess.sql script does not appear to be in the script library for the book.  After using three pages for the script, it probably would have been wise to use more than a small paragraph to explain what to do with the output of the script.
  • Page 186 states, “a rule of thumb is that no session should consume more than 25-50% of the overall resources in a particular category.”  Why 25% to 50%?  It would seem that the percentage might make a difference if there was a single session connected or 1,000 sessions.
  • Pages 186-187, the topsessdet.sql script does not appear to be in the script library for the book.  The script’s output is cumulative since the session connected, so it could easily generate invalid results if one session had been connected to 2 months, while a session consuming significant resources has been connected for 30 minutes.  The query does not use the time model statistics, so it is possible for the statistics displayed to be inaccurate for actively executing sessions – for example if a session has been on the CPU for the last 60 minutes performing logical IO.
  • Pages 188-189, the userscans.sql script does not appear to be in the script library for the book.  The script is interesting in that it retrieves the “table scans (long tables)” statistic for each session.  According to the Oracle documentation, a table is considered long if the table is not cached and its high water mark is more than 5 blocks, and the statistic is impacted by the CACHE and NOCACHE hints – based on that description, the query is not behaving as described in the book (reference).
  • Page 189, the scatwait.sql script does not appear to be in the script library for the book.  The query is not time scoped, so a session that has been connected for months may unfairly be sorted to the top of the output.
  • Page 189, the book states that the “db file scattered read” wait event “is generally thought to be an indicator of table scan activity.”  It probably would have been wise to state that the “db file scattered read” wait event also appears during index fast full scans, and in some cases index range scans.  As of Oracle Database 11.1 it is quite common for the “direct path read” wait event to appear when full table scans are performed, but the book made no mention of that fact.
  • Page 190, the large_scanusers.sql script does not appear to be in the script library for the book.  The script suffers from the same errors as the scripts earlier in the book when it attempts to determine how many full table scans users have performed based on querying SYS.V_$SQL_PLAN – a table that appears a single time in an execution plan may be full table scanned multiple times during a single execution.
  • Page 190 states that the “table scans (long tables)” statistic indicates full table scans of tables that are five or more blocks in size.  That is almost what the Oracle 10.2 documentation states, but that raises the question regarding the script on page 188 and 189 – is there a problem with performing a couple of full table scans on a table with 10 blocks under its high water mark, and is this as severe as performing a couple of full table scans of tables with 10 million blocks under its high water mark?
  • Page 191, the lockcnt.sql script does not appear to be in the script library for the book.  The script appears to have an incomplete join to the SYS.V_$LOCKED_OBJECT view.
  • Page 192, the curriosql.sql script does not appear to be in the script library for the book.  This SQL statement has time scoping problems, directly comparing a session that has been connected to the database for months with one that has been connected for a couple of minutes.
  • Page 193, the cartsession.sql script does not appear to be in the script library for the book.  The script joins SYS.V_$SQL to SYS.V_$SQL_PLAN using just the HASH_VALUE, and there are certainly risks in doing that.  Not all Cartesian joins are bad – the optimizer may (frequently) use a Cartesian join when the statistics for one of the row sources indicates that a single row, or a very small number of rows, will be joined to the second row source.
  • Pages 193-194, the cartsql.sql script does not appear to be in the script library for the book.
  • Page 195, the list of optimizer modes probably should indicate that the FIRST_ROWS optimizer mode has been deprecated for quite a while and/or not list it as one of the two optimizer modes.  The book states of the first rows optimizer mode, “first rows: Fetches the desired rows with a minimum amount of block touches (favors indexes).”  This, of course, raises the question, what if the desired number of rows is all or nearly all of the rows – is this still a true statement?  Do the non-deprecated FIRST_ROWS_1, FIRST_ROWS_10, FIRST_ROWS_100, and FIRST_ROWS_1000 also favor indexes – this section of the book does not mention those optimizer modes.  This page also incorrectly states that the ALL_ROWS optimizer mode favors full scans, such a statement is misleading at best.
  • Pages 196-197, the topsql.sql script does not appear to be in the script library for the book.  It appears that the script is designed for Oracle Database 9i (query retrieves HASH_VALUE rather than SQL_ID), queries SYS.V_$SQLAREA rather than the more common (and documented) V$SQLAREA, unnecessarily groups all child cursors of the same SQL statement together (should have queried V$SQL instead) which can be quite misleading especially in 11.1 with the introduction of adaptive cursor sharing and 11.2 with the introduction of cardinality feedback (two items that are apparently not mentioned in this book).  Additionally, the starting time point of the query is the database open time, rather than a more meaningful examination of the delta statistics for a shorter time period such as an hour or a day – a query that is executed once a month that causes a lot of physical reads might not be a problem, while a query that executed many times in the last hour might be much more of a cause for concern.
  • Page 198 appears to be copied and pasted (with minor modifications) from pages 279-280 of the book “Oracle Performance Troubleshooting: With Dictionary Internals SQL & Tuning Scripts”
  • Page 198, the book is states, “the first query in the result set has accumulated almost five seconds of total execution time and runs for about two and a half seconds each time it is executed.”  While the query might have an *average* execution time of 1.5 seconds, it very well could have required 4.99 seconds for the first execution and 0.01 seconds for the second execution.  Considering that this data that the author is commenting about is drawn from V$SQLAREA, it very well could be the case that the first execution and the second execution have entirely different execution plans.  The effects of block caching could also mean that the time for each execution is not nearly the same as the average execution time.
  • Page 198 states, “this can be accomplished by noting the hash_value for each SQL statement and then issuing the fullsql.sql script to obtain the full SQL statement.”  This statement causes confusion because the fullsql.sql script printed in the book appears to request the SQL_ID, and not the HASH_VALUE as described, which was returned by the earlier SQL statement.
  • Pages 199-201 appear to be copied and pasted (with minor modifications) from pages 347-350 of the book “Oracle Tuning Power Scripts” (reference).
  • Page 199, the cartcount.sql script does not appear to be in the script library for the book.  Not all Cartesian joins are bad – the optimizer may (frequently) use a Cartesian join when the statistics for one of the row sources indicates that a single row, or a very small number of rows, will be joined to the second row source.
  • Page 199, the same cartsql.sql script that appeared on pages 193-194 is pasted on this page also.
  • Page 200, the tabscan.sql script does not appear to be in the script library for the book.  
  • Page 200 appears to be copied and pasted (with minor modifications) from page 284 of the book “Oracle Performance Troubleshooting: With Dictionary Internals SQL & Tuning Scripts”
  • Page 204-205 appear to be copied and pasted (with minor modifications) from page 61-64 of the book “Oracle9i High Performance Tuning with Statspack” (reference).
  • Pages 213-217 appear to be copied and pasted (with minor modifications) from pages 158-162 of the book “Oracle Tuning Power Scripts” (reference).
  • Pages 224-225 appear to be copied and pasted (with minor modifications) from pages 147-149 of the book “Oracle Tuning Power Scripts” (reference).
  • Page 226 appears to be copied and pasted (with minor modifications) from page 146 of the book “Oracle Tuning Power Scripts”
  • Page 229 appears to be copied and pasted (with minor modifications) from page 139 of the book “Easy Oracle Automation: Oracle 10g Automatic Storage, Memory and Diagnostic Features” (reference).
  • Pages 229-234 appear to be copied and pasted (with minor modifications) from pages 150-160 of the book “Oracle Tuning Power Scripts” (reference).
  •  

Jumping to mostly random pages:

  • Page 235 appears to be copied and pasted (with minor modifications) from pages 252-253 of the book “Oracle Tuning Power Scripts” (reference).
  • Pages 243-247 appear to be copied and pasted (with minor modifications) from pages 112-115 of the book “Easy Oracle Automation” (reference).
  • Page 249 appears to be copied and pasted (with minor modifications) from pages 47-48 of the book “Oracle 9i High-Performance Tuning with Statspack” (reference).
  • Pages 250, 309, 311, and 318 contain an advertisement for the author’s ION product.
  • Page 280 states, “Oracle does not run in a vacuum, and it’s critical to search outside the box and see what is happening with your CPU, RAM, network, and disk I/O subsystems.”  While this quote might raise a couple of questions, I would like to know why Oracle (assuming Database) was not designed to function correctly inside a vacuum, and why would the server’s CPU be outside the box?
  • Pages 313-315 are nearly identical word for word with Metalink (MOS) Doc ID 884046.1 “Understand each field of AWR” as well as pages 22 through 25 of a document that is marked as copyright 2010 by IBM Corp. (reference).
  • Page 325 states, “The reason that CPU drives to 10% utilization is because the UNIX internal dispatchers will always attempt to keep the CPU’s as busy as possible. This maximizes task throughput, but it can be misleading for a neophyte. Remember, it is not a cause for concern when the user + system CPU values approach 100 percent.”  Why 10%?  Page 325 of the book makes the same errors as are found on page 25 of the book (reference).
  • Page 355 provides no real help with decoding the time model statistics, not even a suggestion to arrange the statistics into a logical hierarchy.  All that is stated is, “in the sample output of the AWR Time Model Statistics Report shown above, it can be seen that the system spends the most processing time on actual SQL execution but not on parsing.  This is very good for a production system.”  This is at least the second case in the book where the time model statistics were introduced were no information was provided to indicate what to do with the statistics.
  • Page 355-356, other than telling the reader that the operating system statistics are important, and providing what appears to be output from Oracle Database 10.1, the book does not indicate what to do with the statistics. 
  • Pages 516-519 appear to be copied and pasted (with minor modifications) from pages 212-216 of the book “Oracle 9i high-performance tuning with Statspack” (reference).
  • Page 520 states, “for example, tuning an SQL statement to remove full-table scans makes the query run faster because of the direct reduction in the amount of data blocks that are read from disk.”  This is simply too broad and too inaccurate of a statement to be true, as it seems to imply that all full table scans are automatically worse than an index access path.  It can be quite easily demonstrated that even when selecting 0.06% of a table, a full table scan may be significantly faster than an index access path to the same data (reference).
  • Page 521 includes a statement that does not seem to make sense, “Prior to Oracle, Oracle Professionals noticed that by moving the entire database to a larger blocksize, they reduce disk I/O and improve performance of the entire system.”  Were there Oracle DBAs before Oracle Corporation was formed, or is this sentence stating something else?
  • Page 521 states, “there is no question that a large blocksize for indexes is going to reduce I/O, and therefore improve the overall performance of the entire database.”  There have been several well written articles that question whether using a larger block size for indexes will do either of reduce I/O or improve the overall performance.  For example, what happens in a multi-user database when more index entries are packed into a larger index leaf block and multiple sessions concurrently insert into the table to which the index belongs? This is essentially a repeat of the same logic error as is found on page 149 of the book (reference http://richardfoote.wordpress.com/2009/02/23/larger-block-tablespace-for-indexes-revisted-part-ii-money/).   
  • Page 522 states, “Oracle has codified the benefits of different blocksizes, and the Oracle 11g Performance Tuning Guide notes that multiple block sizes are indeed beneficial…”  The author then quoted the portion of the Oracle Database documentation which describes the KEEP and RECYCLE buffer pools.  The KEEP and RECYCLE buffer pools can only use the same block size as is the default block size for the database – the quote from the documentation does not describe the benefits of different block sizes.  I pointed this error out to the author in the Oracle OTN forums in 2008 after a couple other people previously mentioned the same error (reference).
  • Page 522 states, “for example, insert-intensive databases will perform less write I/O (via the DBWR process) with larger block sizes.  This is because more logical inserts can take place within the data buffer before the block becomes full and requires writing it back to disk.”  This is an extremely weak argument.  DBWR batches block writes, it does not write a block to disk as soon as it becomes full.  Second, what kinds of problems may happen when multiple sessions are concurrently performing the inserts into leaf blocks?  Third, what about all of the bugs that are related to having multiple block sizes in a single database such as bug ID 4940513 (undo related), bug ID 5496041 (index corruption), and doc ID 844497.1 (RMAN skips non-default block size tablespaces).
  • Pages 523-528, the author attempts to argue for the use of multiple block sizes in a single database using arguments that were discussed in several forum threads.  A lot of convincing evidence was provided in those threads that strongly recommended against the practice that is suggested by the author.
  • Page 529, Oracle Database 10.2 and above also considers the value of the SESSIONS parameter when automatically setting the DB_FILE_MULTIBLOCK_READ_COUNT parameter value (reference).
  • Page 535, the same flawed comparison of indexes in an 8KB and 16KB block size which is found on page 149 is repeated.
  • Page 537 describes a case where a customer was using a 16KB block size database that experienced performance problems where updating roughly 850,000 rows in a table required roughly 45 minutes, and that time decreased to just 2.2 minutes by recreating the database with a 4KB block size.  This magic performance increase was discussed on the Oracle OTN forums and several blogs.  Jonathan Lewis create a test case that identified the cause as an ASSM bug that appears in tablespaces created with block sizes larger than 8KB.  A bug was filed with Oracle Corp. related to the problem, and the author of this book as well as the field technician who spotted the error were notified that the cause of the problem was identified and a patch is being developed.  I am not sure why the book states, “I was able to get the update down to 1.5 minutes” – I distinctly recall the field technician (also the technical editor of this book) reported fixing the problem, and not the book author (reference  reference2  reference3  reference4).
  • Page 726 states to check Metalink (MOS) Doc ID 122008.1 for “the officially authorized script to detect indexes that benefit from rebuilding.”  That Metalink article states that the criteria is not valid and the script has been revised to meet “current standards and functionality.”  That means that the suggested criteria for rebuilding that is printed in the book regarding 20% or more of deleted index entries or a depth of more than 4 levels is invalid, as had previously been pointed out to the book author as invalid in a couple of OTN discussion threads (reference  reference2  reference3).
  • Page 726 suggests to check Metalink Doc ID 77574.1 for Oracle’s index rebuilding guidelines – that Doc ID does not exist on Metalink (MOS).
  • Page 726 states, “However, when large numbers of adjacent rows are deleted, it is highly unlikely that Oracle will have an opportunity to reuse the deleted leaf rows, and these represent wasted space in the index.”  The first question is why can the space not be reused.  The second question is if it matters whether the index is a primary key b*tree index, and index on another column, or a different type of index altogether.  The third question is how are the adjacent rows deleted – if this is a heap organized table, how does one make sure that physically adjacent rows in the table blocks are deleted?
  • Page 727 appears to be at least partially copied from page 412 of the book “Oracle 9i High-Performance Tuning” (reference  reference2).
  • Page 727 states, “Hence, an Oracle index may have four levels, but only in those areas of the index tree where the massive inserts have occurred.  Oracle indexes can support many millions of entries in three levels, and any index that has four or more levels would benefit from rebuilding.”  The first sentence is clearly not true, and was communicated to the book’s author by members of the Oracle community in early 2003 (as well as several times since 2003).  The second sentence leads into a bit of a problem area – what happens if after rebuilding an index it is still four or more levels – do you rebuild it again? (reference  reference2)
  • Page 727 states, “Gets per index access: The number of gets per access refers to the amount of logical I/O that is required to fetch a row with the index.”  This attempted description of the BLKS_GETS_PER_ACCESS column of INDEX_STATS seems to be inaccurate, and likely is not a good metric for deciding if an index should be rebuilt – the author suggests that it might be appropriate to rebuild the index when the value of this statistic is more than five (reference).
  • Page 727 suggests using “ANALYZE INDEX VALIDATE STRUCTURE” for all indexes to determine which are candidates for a rebuild.  The book then states, “After analyzing the report above, the DBA may want to consider rebuilding any index where the height is more than three levels…”  The author does not mention that the tables to which the indexes belong will be locked for the entire duration of the ANALYZE INDEX command – this problem was brought to the attention of the book author in 2007 by members of the Oracle community.  For the second of the two quoted sentences, the book does not include a report above the sentence quoted from the book, so it is unclear what the reader should be reviewing (reference).
  • Pages 728-732 contain a lot of faulty facts about the safeness and cheapness of index rebuilds, and how “many” databases see a huge benefit from periodic index rebuilding.  Many of these faulty facts are discussed in detail in Richard Foote’s blog and in various Internet forums.

(Section added December 8, 2010): Related blog articles that discuss the contents of this book:

(Section added February 28, 2011): Attempted Purchases of the “Oracle Tuning: The Definitive Reference Second Edition” Book:

On February 2, 2011 I added the following comment to my review of this book on Amazon.com:

In my review of the book I stated the following:
“I initially ordered the book from Amazon at the end of May 2010 (it was expected to be in stock the first week of June 2010), and when it had not shipped by the end of August, my curiosity subsided due to the delay (and various other reasons) and I cancelled the original order. Near the end of October 2010 my curiosity peaked again, so I placed a new order for the book (at that time the book was expected to be in stock the first week of November 2010). While waiting for the book to arrive, I started reading portions of the first and second editions of the book through the Google books library.”

The order that I placed for the book at the end of October 2010 still has not shipped, more than three months after I placed the order. It is somewhat interesting to see that the publisher’s website offers this book for seven dollars less than Amazon’s current price for the same book, while the publisher apparently cannot supply Amazon with a sufficient number of copies of this book to fill the existing orders. I have no intention of cancelling this order, even if it does not ship for another three to six months. Best of luck to others who have waited six months (three months for the first order before cancelling and three months for the second order) to obtain the book.

This was the status of the first attempt to acquire the book, as shown on Amazon.com August 26, 2010 – that order was cancelled shortly after making this screen capture:

This screen capture shows the current status of the second attempt to acquire the book, as shown on Amazon.com February 28, 2011 – I do not intend to cancel this order:

This is certainly an interesting situation.  Why publish a book, and then not provide the book vendors with a sufficient number of copies to satisfy the apparent demand?  There is probably a good explanation for the delay, but not one that I am able to understand.

(Section added March 9, 2011): Attempted Purchases of the “Oracle Tuning: The Definitive Reference Second Edition” Book, Part 2:

Amazon cancelled my second order and sent the following email:

I noticed a couple of days ago that Rampant was selling the book through Amazon.com.  Currently there is only a single seller listed on Amazon.com, and that seller is asking $976.98 for a used copy of the book: 





Interviewed for the November 2010 NoCOUG Journal

4 11 2010

November 4, 2010

Almost two months ago I was interviewed for an article that was to appear in an upcoming NoCOUG Jornal newsletter.  It was a great opportunity to participate in the interview, and Chen (Gwen) Shapira provided to me a great set of thought provoking questions.  The interview went a bit long, so some of the questions and answers had to be trimmed from the printed NoCOUG Jornal newsletter article (Iggy Fernandez, Chen, and the other responsible parties did a fantastic job of picking the best answers for inclusion).  The picture used in the article… let’s just say that of the 50 or so pictures that I reviewed for submission, it was the only one that effectively hid my gray hair, where I did not show either a distressed (or puzzled) expression or appear that I had just spent eight hours writing a critical book review (is that a hint that another book review is in the process of being put together?).

I have decided to post a couple of the questions and answers that had to be trimmed due to space constraints (with the exception of the war story from my experience, which drifted a bit too far off topic, and involved some rather gruesome gutting of computer internals).

———————————

You use Excel as an automation and visualization tool. You definitely have more Excel expertise than most Oracle DBAs? How did you get into the Excel business? Do you have some tricks to share with our readers?

Among other things, I was a computer/technology instructor prior to working for K&M Machine-Fabricating, Inc., and one of the topics that I taught was using Microsoft Excel for data analysis and data visualization.  Excel has a full featured macro language that is quite similar to Microsoft Visual Basic 6.0 (and also the 2.0 version of Visual Basic), and is somewhat similar to the much simplified VBScript that is integrated into some ERP packages (Infor’s Visual Manufacturing for example), some engineering applications (AutoCAD, at least for a period of time, supported VBScript), classic ASP web pages, and even the Windows operating system.  It is the macro automation, either from within Excel or another program (whether a Microsoft Office component, custom developed program, or even an operating system script), that provides the most useful features in Excel for a DBA.

In June 2009 I delivered a presentation to a regional ERP user’s group that among other things showed how to leverage Microsoft Excel as a query and reporting tool for ERP data.  The Excel portion of the presentation required roughly 90 minutes and showed how to tap into the ERP data for reporting and visualization, as well as querying flat files, Windows event logs, and the WMI database that is built into all Windows operating systems since Windows 2000 was released.  It took about three months to prepare for that presentation, and the preparation involved reading three books about Microsoft Excel programming:  “Professional Excel Development”, “Excel Power Programming with VBA”, and “Pro Excel 2007 VBA”.  The first two books are great references but also are easily readable from start to end.  The third book really does not introduce anything that could not be discovered by a couple of hours of experimentation and Excel help documentation reading (the help file in Excel 2007 is much better than earlier versions and was improved again in Excel 2010. 

As for tricks, turn on the macro recorder in Excel, make a couple of changes or set up a Microsoft Query that accesses an Oracle Database, and then examine the resulting macro.  This method of generating macros is a great starting point, as long as you keep in mind that the generated code is not necessarily the most efficient approach to producing the intended results, and there is a small chance that the generated code will not work as expected when it is later executed.  If you see an unusual command, click in the middle of the command and press the F1 key for additional information about the command.

Tell us about your favorite network tools. When do you recommend bringing out network tracing? What about other operating system knowledge, do you feel that DBAs would benefit from looking at more low-level tracing and measuring?

For the rare times when I need to perform network analysis, I typically reach for ping, tnsping, or tracert (traceroute) first.  If I am working on a computer running Windows I might also run either nbtstat or netstat with various parameters.  One of the little known key network tools is actually the event log found in a managed network switch, which might provide a clue about misconfigured switch or server settings, failing hardware or failing network links, faulty wiring, and a number of other problems.  For automated network monitoring it is hard to find a better free tool than Nagious.  For a DBA, network monitoring with a packet capture tool such as Wireshark (available on Windows, Unix/Linux with an X Window environment, and Mac) or tcpdump probably should only be attempted when a 10046 trace at level 8 or 12 finds that only a small percentage of processing time is confirmed to be server-side database related activity, essentially when most of the elapsed time is in SQL*Net type wait events.  By time sequencing a Wireshark capture with a 10046 trace file, it might be possible to determine why, for example, every time the client submits a specific SQL statement and a FETCH call is found in the 10046 trace file there is a two second delay before the next entry in the 10046 trace file – essentially answering if there was a problem/slowness in the network communication, or if the client was busy using the retrieved data.  If the Wireshark capture shows that a problem was not found in the 2 second problematic interval, then a switch to client-side tracing with Wireshark and/or another tool such as Micosoft’s Process Monitor, Microsoft’s Spy++, SQL*Net tracing, or other client-side tracing utility might help.

———————————

I hope that you enjoy reading the interview questions and answers; there are several other great articles in the November 2010 NoCOUG Journal.





11.2.0.1 ODBC Update Problem

2 11 2010

November 2, 2010 (Updated November 3, 2010)

An interesting ODBC problem was brought to my attention yesterday regarding the Microsoft Access 2010 program and the Oracle Database 11.2.0.1 ODBC client.  What is the problem?  The person reported that they were trying to update a table in a 10.2.0.4 Oracle Database using values from a database table that resides in an Microsoft Access 2010 database - Microsoft Access was supposed to magically update the Oracle table when the user issued a simple UPDATE statement.

I put together a test case using a 11.2.0.1 Oracle Database to simulate the problem, picking a table named PART in the Oracle Database and creating a table named  UPDATE_TABLE in Microsoft Access 2010.  I then constructed the following SQL statement:

UPDATE
  PART
SET
  WHSALE_UNIT_COST = (
    SELECT
      UPDATE_TABLE.WHSALE_UNIT_COST
    FROM
      UPDATE_TABLE
    WHERE
      UPDATE_TABLE.PART_ID = PART.ID)
WHERE
  PART.ID IN (
    SELECT
      PART_ID
    FROM
      UPDATE_TABLE);

Nifty, except that the above SQL statement generated an error message:

Operation must use an updatable query (Error 3073)

OK, let’s try this crazy looking SQL statement instead:

UPDATE DISTINCTROW
  PART
INNER JOIN
  UPDATE_TABLE
ON
  PART.ID = UPDATE_TABLE.PART_ID
SET
  PART.WHSALE_UNIT_COST = UPDATE_TABLE.WHSALE_UNIT_COST; 

No error 3073 this time, so the above must be a valid SQL statement.  I put 4 test rows into the UPDATE_TABLE table and let the update run:

Great, its going to work…  Hey, why did I receive a warning that 3 records could not be updated due to lock violations?  Darn Microsoft bugs!

Let’s try to execute the SQL statement again:

LONGs?  The PART.ID column is defined as VARCHAR2(30), the PART.WHSALE_UNIT_COST is defined as NUMBER(20,6).  Maybe it is the Access table’s fault.  The UPDATE_TABLE.PART_ID column is defined as TEXT(30), and it does not matter if the UPDATE_TABLE.WHSALE_UNIT_COST column is defined as DECIMAL, SINGLE, or DOUBLE.

For fun, let’s create a trigger to enable a 10046 trace at level 12 whenever the Microsoft Access program connects to the database.  The trigger at the top of this blog article will work without modification.  Now let’s take a look at part of the 10046 trace file after trying the update SQL statement again:

PARSING IN CURSOR #4 len=64 dep=0 uid=287 oct=6 lid=287 tim=20065405443 hv=655341070 ad='4696fd8f0' sqlid='gwux0ysmhzdhf'
UPDATE "TESTUSER"."PART" SET "WHSALE_UNIT_COST"=:1 WHERE "ID" = :2
END OF STMT
PARSE #4:c=0,e=32,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=1148805963,tim=20065405443
BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f284498  bln=2000  avl=07  flg=05
  value="123.122"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f29f060  bln=4000  avl=09  flg=05
  value=".250-A572"
EXEC #4:c=0,e=264,p=0,cr=3,cu=4,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=20065405739

The above kind of works, even though the number value is passed in as a VARCHAR2 rather than as a NUMBER.  The WHSALE_UNIT_COST will be set to 123.122 for part ID .250-A572.
 
Now the next set of bind variables:

BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f284498  bln=2000  avl=07  flg=05
  value="4554.44"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f29f060  bln=4000  avl=00  flg=05
EXEC #4:c=0,e=115,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=1148805963,tim=20065407265

Notice in the above that the bind variable value for the PART.ID column was left as NULL – that can’t work if we are trying to update rows.
 
The next set of bind variables:

BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f284498  bln=2000  avl=07  flg=05
  value="45.1¿¿"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f29f060  bln=4000  avl=00  flg=05
EXEC #4:c=0,e=92,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=1148805963,tim=20065408596

Notice in the above that the bind variable value for the PART.ID column was left NULL, and the value passed in for the WHSALE_UNIT_COST is 45.1¿¿ – I am pretty sure that is an invalid number.
 
The final set of bind variables:

BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f284498  bln=2000  avl=07  flg=05
  value="665"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f29f060  bln=4000  avl=00  flg=05
EXEC #4:c=0,e=158,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=1148805963,tim=20065410013

Notice in the above that the bind variable value for the PART.ID column was left as NULL – that can’t work if we are trying to update rows.
 
So, I guess that explains why 3 of the 4 updates failed.  Darn Microsoft bugs!  But wait, here is an interesting thread on a Microsoft site that suggests the problem is with the 11.2.0.1 client’s ODBC dll named sqora32.dll.  Someone in the thread suggested just borrowing the sqora32.dll file from a 11.1.0.7 client install.  I was suspicious about the advice, so I borrowed the sqora32.dll file from a 10.2.0.1 client install.  I have seen this before, Yes.

And then… nothing.  The 10046 logon trigger was still enabled, let’s check the trace file:

PARSING IN CURSOR #4 len=64 dep=0 uid=287 oct=6 lid=287 tim=28794270809 hv=655341070 ad='4696fd8f0' sqlid='gwux0ysmhzdhf'
UPDATE "TESTUSER"."PART" SET "WHSALE_UNIT_COST"=:1 WHERE "ID" = :2
END OF STMT
PARSE #4:c=0,e=17,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=1148805963,tim=28794270808
BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f2af830  bln=2000  avl=10  flg=05
  value="123.122001"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f2ae850  bln=4000  avl=09  flg=05
  value=".250-A572"
EXEC #4:c=0,e=324,p=0,cr=3,cu=4,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=28794271179
...
BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f2abb40  bln=2000  avl=11  flg=05
  value="4554.443847"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f2af060  bln=4000  avl=09  flg=05
  value=".250X.750"
EXEC #4:c=0,e=181,p=0,cr=3,cu=2,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=28794292695
...
BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f2abb40  bln=2000  avl=09  flg=05
  value="45.099998"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f2af060  bln=4000  avl=07  flg=05
  value=".50-A36"
EXEC #4:c=0,e=198,p=0,cr=3,cu=2,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=28794312262
...
BINDS #4:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=1f2abb40  bln=2000  avl=03  flg=05
  value="665"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=1f2af060  bln=4000  avl=08  flg=05
  value="00045364"
EXEC #4:c=0,e=217,p=0,cr=3,cu=2,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=28794333188
WAIT #4: nam='SQL*Net message to client' ela= 0 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=28794333220

*** 2010-11-02 14:02:01.661
WAIT #4: nam='SQL*Net message from client' ela= 2750115 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=28797083349
XCTEND rlbk=0, rd_only=0, tim=28797083480

It worked!  The last line indicates that the changes were committed, and all bind variables were passed in.  So, I tested again with the sqora32.dll file from a 11.1.0.7 client – it still worked.  I then went back to the sqora32.dll file from the 11.2.0.1 client, and the failure messages returned.  OK, maybe the problem is with the 11.2.0.1 Oracle Database?  Pointing Access 2010 at a 10.2.0.4 Oracle Database with the sqora32.dll file from the 11.2.0.1 client returned the same silly error messages that I saw earlier.

What do you know, it is not a Microsoft Bug 2010 after all.

——————-

Edit: November 3, 2010

A search of Metalink (MOS) revealed that Patch 7 for Oracle Database/Client 11.2.0.1 on the Windows platform included a fix for the ODBC problem – this fix is not included in Patch 6 for 11.2.0.1.  Metalink indicated that patch number 10155837 is Patch 7 for Oracle 11.2.0.1, but that is only for the 32 bit Oracle binaries on Windows.  A patch search found patch number 10155838 which appears to include the same fix for the 64 bit Oracle binaries on Windows.  Initial testing of the 32 bit patch (10155837) on a 32 bit client home residing on a 64 bit Windows client seems to show that the problem is fixed by patch 10155837.  From the 10046 trace file:

PARSING IN CURSOR #7 len=64 dep=0 uid=287 oct=6 lid=287 tim=7180612054 hv=655341070 ad='4697fba58' sqlid='gwux0ysmhzdhf'
UPDATE "TESTUSER"."PART" SET "WHSALE_UNIT_COST"=:1 WHERE "ID" = :2
END OF STMT
PARSE #7:c=0,e=85,p=0,cr=0,cu=0,mis=1,r=0,dep=0,og=1,plh=0,tim=7180612053
...
BINDS #7:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=203f0bc8  bln=2000  avl=10  flg=05
  value="123.122001"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=203f1ab0  bln=4000  avl=09  flg=05
  value=".250-A572"
...
EXEC #7:c=31200,e=45322,p=17,cr=628,cu=4,mis=1,r=1,dep=0,og=1,plh=1148805963,tim=7180657412
...
BINDS #7:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=203f0fe0  bln=2000  avl=11  flg=05
  value="4554.443847"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=203f84e8  bln=4000  avl=09  flg=05
  value=".250X.750"
EXEC #7:c=0,e=247,p=0,cr=3,cu=2,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=7180678947
...
BINDS #7:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=203f0fe0  bln=2000  avl=09  flg=05
  value="45.099998"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=203f1ab0  bln=4000  avl=07  flg=05
  value=".50-A36"
EXEC #7:c=0,e=173,p=0,cr=3,cu=2,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=7180699090
...

BINDS #7:
 Bind#0
  oacdty=01 mxl=2000(2000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=2000 off=0
  kxsbbbfp=203f0fe0  bln=2000  avl=03  flg=05
  value="665"
 Bind#1
  oacdty=01 mxl=4000(4000) mxlc=00 mal=00 scl=00 pre=00
  oacflg=07 fl2=1000010 frm=01 csi=178 siz=4000 off=0
  kxsbbbfp=203f84e8  bln=4000  avl=08  flg=05
  value="00045364"
EXEC #7:c=0,e=164,p=0,cr=3,cu=2,mis=0,r=1,dep=0,og=1,plh=1148805963,tim=7180720112
WAIT #7: nam='SQL*Net message to client' ela= 0 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=7180720145

*** 2010-11-03 08:03:08.775
WAIT #7: nam='SQL*Net message from client' ela= 2522305 driver id=1413697536 #bytes=1 p3=0 obj#=-1 tim=7183242464
XCTEND rlbk=0, rd_only=0, tim=7183242564

The 10046 trace file show four complete sets of bind variables and a successful COMMIT at the end.








Follow

Get every new post delivered to your Inbox.

Join 137 other followers