Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re:CBO and cartesian product

Re:CBO and cartesian product

From: Dilip <dilip7772002_at_indiatimes.com>
Date: Mon, 13 Oct 2003 21:54:25 -0800
Message-ID: <F001.005D2F77.20031013215425@fatcity.com>


Hi Tim/John,

Thanks a lot for such detailed reply. Tim, As you said, I verified the relationship between the tables. Its two parent and one child table relationship.

John, thanks for referring that metalink note. For time being, I can use RULE hint and make it work.

PS: Tim, 'CUT TO THE CHASE...' part of your paper is great. It will take me a little while to read whole paper but still I got the story. (Difficult to attend whole day trainings and then work)...

Thanks a lot again,

~Dilip     

ORACLE-L_at_fatcity.com wrote:

Tim/Dilip,

Unfortunately, as this is an 'Apps' instance, the parameters DB_FILE_MULTIBLOCK_READ_COUNT should be set to 8 and the OPTIMIZER_INDEX_CACHING parameter should *not* be set (letting it default)... This is as per ML Note 216205.1 - non compliance = "not supported".

Since this is a customized report though, you *may* be able to get away with setting them within the program (or reverting to RULE as a quick fix)....

John Kanagaraj
DB Soft Inc
Phone: 408-970-7002 (W)

Listen to great, commercial-free christian music 24x7x365 at http://www.klove.com

&gt;-----Original Message-----
&gt;From: Tim Gorman [mailto:tim_at_sagelogix.com]
&gt;Sent: Saturday, October 11, 2003 11:14 AM
&gt;To: Multiple recipients of list ORACLE-L
&gt;Subject: Re: CBO and cartesian product
&gt;
&gt;
&gt;Here is the short answer:
&gt;=========================
&gt;
&gt; * Set OPTIMIZER_INDEX_CACHING to 90
&gt; * Make sure that DB_FILE_MULTIBLOCK_READ_COUNT is not overly high
&gt; * Also, consider gathering column-level statistics on some of the
&gt; indexed columns involved, especially if the query in question
&gt; uses literal data values on them
&gt;
&gt;Here is the long answer:
&gt;========================
&gt;
&gt;Starting in the 8i timeframe, the CBO started borrowing some
&gt;techniques from
&gt;data warehouse STAR joins when confronted with any type of query that
&gt;traversed two different entity-relationship heirarchies
&gt;starting from the
&gt;same table.
&gt;
&gt;Say you have three tables (to keep it simple). One table is a "child"
&gt;entity to the other two tables, which are both "parent" entities in ERD
&gt;terms. The CBO detects that both "parent" tables are much
&gt;smaller than the
&gt;"child" table.
&gt;
&gt;OK, so there is no relationship between the two parent tables
&gt;-- they are
&gt;both "related" only through the large child table.
&gt;
&gt;Now, think about what traditional join methods are possible:
&gt;
&gt; 1) start with one of the parent tables as the "driving table", do a
&gt; indexed nested-loop range-scan during the join to the
&gt;child table,
&gt; and then perform indexed nested-loop unique-scan during
&gt;the final
&gt; join to the other parent table
&gt; 2) reverse the order of option #1. Start with the other parent
&gt; table, join to the child, and then join up to the
&gt;remaining parent
&gt; 3) start with the child table and join up (via indexed
&gt;unique-scans)
&gt; to the two parent tables
&gt;
&gt;The weak point of both of these options is probably the access
&gt;of the child
&gt;table. Plain and simple, it is difficult to efficiently get
&gt;rows from it.
&gt;It is likely that the index supporting the foreign-key
&gt;relationship from
&gt;either parent table is not very efficient by itself, resulting
&gt;in a very
&gt;expensive range-scan, requiring a massive number of logical
&gt;I/Os and "cost"
&gt;calculated by the CBO.
&gt;
&gt;So, the CBO in 8i started utilizing another option, which
&gt;initially blew my
&gt;mind first time I saw it happen. It was the point which I
&gt;realized that the
&gt;CBO was _way_ smarter than humans...
&gt;
&gt;This additional option is to perform a "cartesian join" between the two
&gt;parent tables, to come up with one result set. Then, using
&gt;the filtered
&gt;cartesian result set from that join, the CBO probes into the
&gt;large child
&gt;table using the _combined_ keys from both parent tables!
&gt;
&gt;Rather brilliant choice, in most cases. The cartesian join, despite
&gt;everybody's visceral fear of it, is actually rather
&gt;insignificant if the two
&gt;parent tables are small. And it is even smaller if there are good
&gt;"filtering" predicates on those tables in the WHERE clause.
&gt;
&gt;So, instead of having to retrieve rows from the large child
&gt;table using one
&gt;or the other of the relatively ineffective indexes supporting
&gt;each foreign
&gt;key, the CBO merges and uses both keys, resulting in a far
&gt;more effective
&gt;access method into the child table.
&gt;
&gt;So, chances are good that this is the situation you are
&gt;facing. Is this
&gt;correct? Can you verify the basic relationships between the tables
&gt;involved?
&gt;
&gt;So, now the question is: why did the CBO make the wrong choice?
&gt;
&gt;First, the default setting of the OPTIMIZER_INDEX_CACHING
&gt;parameter (i.e.
&gt;"0") represents a flaw in the basic costing algorithm used by the CBO.
&gt;Setting the parameter to 90 or so fixes this flaw. For a more detailed
&gt;explanation, please feel free to view my paper "Search for
&gt;Intelligent Life
&gt;in the CBO", available online at "http://www.EvDBT.com/papers.htm".
&gt;
&gt;Changing that alone may cause the CBO to rethink its decision
&gt;to go with the
&gt;derived STAR-join scheme involving a cartesian join, and
&gt;instead choose the
&gt;indexed nested-loops scheme which is the __only__ possible
&gt;choice by the
&gt;RBO. By discounting the cost of index-based access methods,
&gt;the CBO (which
&gt;considers _all_ possible access methods and chooses the one
&gt;with the lowest
&gt;cost) may now choose the index-based plan. Once again, the RBO only
&gt;considered the one plan, which in this case turned into a bit
&gt;of luck for
&gt;the RBO, making it look good.
&gt;
&gt;You can experiment with this parameter change using ALTER
&gt;SESSION, if you
&gt;like. This is one of the _few_ occasions on which changing a parameter
&gt;actually has an impact on performance.
&gt;
&gt;There are some other parameter settings which may impact how
&gt;the CBO costs
&gt;this query. For example, if DB_FILE_MULTIBLOCK_READ_COUNT is
&gt;set higher
&gt;than its default value of 8 or 16, then the CBO will think
&gt;that access plans
&gt;involving FULL table scans are cheaper than they are.
&gt;
&gt;Another possible cause for the CBO's bad decision is it's
&gt;default assumption
&gt;that data values in a column are evenly distributed.
&gt;Gathering stats for
&gt;indexed columns only gathers the number of distinct keys and
&gt;the low/high
&gt;values, by default. Therefore, the CBO has no choice except
&gt;to assume an
&gt;even distribution of data, that each distinct data value is
&gt;used by an equal
&gt;number of rows. Gathering column-level statistics creates
&gt;"histograms" in
&gt;the data dictionary that help the CBO recognize which data values would
&gt;benefit from indexed access and which data values would
&gt;benefit from a FULL
&gt;table scan or another index.
&gt;
&gt;Anyway, I'm getting writer's cramp. Plus, it's a beautiful
&gt;Saturday morning
&gt;and I've been traveling for two straight weeks...
&gt;
&gt;Hope this helps?
&gt;
&gt;-Tim
&gt;
&gt;
&gt;
&gt;on 10/11/03 5:49 AM, Dilip at dilip7772002_at_indiatimes.com wrote:
&gt;
&gt;&gt; Hi List,
&gt;&gt;
&gt;&gt; DB version - 8174. (Oracle Apps 11.5.4).
&gt;&gt;
&gt;&gt; One of the customized report started running very slowly.
&gt;One query was taking
&gt;&gt; more than 3 GB of TEMP tablespace for 'HASH' type segment
&gt;and erroring out
&gt;&gt; after 2 hours for a lack of space in TEMP.
&gt;&gt;
&gt;&gt; Tkprof showed that it is doing Cartesian Sort Merge Join.
&gt;&gt; After running the same report under RBO, it is using Nested
&gt;loops and report
&gt;&gt; is completing in just 5 minutes.
&gt;&gt; The stats were collected last week-end. I couldn't find any
&gt;reason for this
&gt;&gt; CBO's behavior ? Has anybody experienced this before ?
&gt;&gt;
&gt;&gt; Thanks,
&gt;&gt; ~Dilip
&gt;&gt;
&gt;&gt;
&gt;&gt;
&gt;&gt;
&gt;&gt;
&gt;&gt;
&gt;&gt; Get Your Private, Free E-mail from Indiatimes at
http://email.indiatimes.com
&gt;
&gt; Buy The Best In BOOKS at http://www.bestsellers.indiatimes.com
&gt;
&gt; Bid for for Air Tickets @ Re.1 on Air Sahara Flights. Just log on to
&gt; http://airsahara.indiatimes.com and Bid Now !

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Tim Gorman
INET: tim_at_sagelogix.com

Fat City Network Services -- 858-538-5051 http://www.fatcity.com
San Diego, California -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from). You may
also send the HELP command for other information (like subscribing).
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: John Kanagaraj
INET: john.kanagaraj_at_hds.com

Fat City Network Services -- 858-538-5051 http://www.fatcity.com
San Diego, California -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from). You may
also send the HELP command for other information (like subscribing).



Get Your Private, Free E-mail from Indiatimes at http://email.indiatimes.com

 Buy The Best In BOOKS at http://www.bestsellers.indiatimes.com

Bid for for Air Tickets @ Re.1 on Air Sahara Flights. Just log on to http://airsahara.indiatimes.com and Bid Now !

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Dilip
  INET: dilip7772002_at_indiatimes.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Tue Oct 14 2003 - 00:54:25 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US