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: HASH_JOIN on RBO?

RE: HASH_JOIN on RBO?

From: Steve Adams <steve.adams_at_ixora.com.au>
Date: Tue, 19 Sep 2000 00:41:56 +1000
Message-Id: <10623.117244@fatcity.com>


Hi Chuck,

In that case, either one of the other pieces of information that you've given us is incorrect, or this is a bug. Could you please try it as follows

spool why_cost
set long 1000
column text format a80 word
select text from dba_views where view_name = 'PS_QVC_PERS_SRCH_VW'; alter session set events '10053 trace name context forever'; alter session set sql_trace = true;
set autotrace traceonly explain
SELECT --+ RULE
...
spool off
exit

Please note the extra space before the hint comment to force a reparse. If you need to do it more than once, insert one more space each time, or flush the shared pool first. Please post the spool file and the trace file.

@ Regards,
@ Steve Adams
@ http://www.ixora.com.au/
@ http://www.christianity.net.au/
@
@ Going to OpenWorld?
@ Catch the Ixora performance tuning seminar too!
@ See http://www.ixora.com.au/seminars/ for details.

-----Original Message-----
From: Chuck Hamilton [mailto:chuck_hamilton_at_yahoo.com] Sent: Monday, 18 September 2000 23:01
To: Steve Adams
Cc: main oracle list
Subject: RE: HASH_JOIN on RBO?

Moving the hint didn't change the explain plan. I puti t right after the INSERT. I also tried removing the insert and just tuning the SELECT portion,putting the hint right after the select....
SELECT --+ RULE
A.*
FROM PS_QVC_PERS_SRCH_VW A,
     PS_QVC_QUERY_USERS B
WHERE A.OPRID=B.OPRCLASS It still chooses a hash join. Only with a first_rows hint does it use all nested loops joins.
  Steve Adams <steve.adams_at_ixora.com.au> wrote:

Hi Chuck,

Your hint is in the wrong position. It should come after the INSERT, not the SELECT. Although the insert and the select are optimized separately, they are treated as a single statement block so far as determining an optimization approach is concerned. Therefore a RULE hint needs to be placed after the first keyword in that statement to be effective.

I have just checked the documentation on this, and unfortunately it is not very helpful. The Oracle8i Tuning guide even says, "A statement block can have only one comment containing hints. This comment can only follow the SELECT, UPDATE, or DELETE keyword." which suggests that you cannot put a hint after an INSERT keyword at all. Of course, you can and you sometimes must.

@ Regards,
@ Steve Adams
@ http://www.ixora.com.au/
@ http://www.christianity.net.au/
@
@ Going to OpenWorld?
@ Catch the Ixora performance tuning seminar too!
@ See http://www.ixora.com.au/seminars/ for details.

-----Original Message-----
From: Chuck Hamilton [mailto:chuck_hamilton_at_yahoo.com] Sent: Thursday, 14 September 2000 2:19
To: Steve Adams
Subject: RE: HASH_JOIN on RBO?

The really odd thing is that the init.ora file has optimizer_mode = RULE. Here's the SQL. It's pretty simple...

INSERT INTO PS_QVC_FAST_SEC
SELECT --+ RULE
A.*
FROM PS_QVC_PERS_SRCH_VW A,
PS_QVC_QUERY_USERS B
WHERE A.OPRID=B.OPRCLASS; The view it references (PA_QVC_PERS_SRCH_VW) has no hints at all in it's definition. I'm still perplexed by this one.

Steve Adams wrote:

Hi Chuck,

It sounds like there is some syntax error in the hint so that it just has the effect of forcing CBO to be used despite the absence of statistics.

@ Regards,
@ Steve Adams
@ http://www.ixora.com.au/
@ http://www.christianity.net.au/
@
@ Going to OpenWorld?
@ Catch the Ixora performance tuning seminar too!
@ See http://www.ixora.com.au/seminars/ for details.

-----Original Message-----
From: Chuck Hamilton [mailto:chuck_hamilton_at_yahoo.com] Sent: Wednesday, 13 September 2000 7:31
To: Multiple recipients of list ORACLE-L Subject: HASH_JOIN on RBO?

I have a query with a RULE hint, but the execution plan is show hash joins. Is this something new in the 8.1.5 optimizer? It used to be that you could only get HASH joins with CBO. Also, each of the operations is showing a cost and cardinality even though none of the tables have stats. The net result is I'm getting a horrible execution plan that includes Cartesian merges and runs for hours when previously this query ran in minutes. Any ideas? Received on Mon Sep 18 2000 - 09:41:56 CDT

Original text of this message

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