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: Explain THIS plan.

Re: Explain THIS plan.

From: Stephane Faroult <sfaroult_at_oriole.com>
Date: Tue, 14 May 2002 11:54:38 -0800
Message-ID: <F001.00460623.20020514115438@fatcity.com>


"Kirsch, Walter J (Northrop Grumman)" wrote:
>
> 2-cpu, 220mhz, 32-bit HPUX 11.0. Oracle 8.1.7.0.0
>
> Could someone explain what's going on here?
>
> This SQL takes no time at all :
>
> select
> substr(username , 1, 12) "User"
> , substr(lock_type, 1, 18) "Lock Type"
> , substr(mode_held, 1, 18) "Mode Held"
> from sys.dba_lock a
> , v$session b
> where /*lock_type not in ('Media Recovery','Redo Thread')
> and*/ a.session_id = b.sid;
>
> with explain plan:
>
> SELECT STATEMENT Optimizer=CHOOSE (Cost=70 Card=1 Bytes=148)
> NESTED LOOPS (Cost=70 Card=1 Bytes=148)
> NESTED LOOPS (Cost=60 Card=1 Bytes=141)
> NESTED LOOPS (Cost=20 Card=1 Bytes=107)
> FIXED TABLE (FULL) OF X$KSUSE (Cost=10 Card=1 Bytes=30)
> FIXED TABLE (FIXED INDEX #1) OF X$KSUSE (Cost=10 Card=1
> Bytes=77)
> VIEW OF GV$_LOCK
> UNION-ALL
> VIEW OF GV$_LOCK1 (Cost=20 Card=2 Bytes=162)
> UNION-ALL
> FIXED TABLE (FULL) OF X$KDNSSF (Cost=10 Card=1
> Bytes=94)
> FIXED TABLE (FULL) OF X$KSQEQ (Cost=10 Card=1
> Bytes=94)
> FIXED TABLE (FULL) OF X$KTADM (Cost=10 Card=1 Bytes=94)
> FIXED TABLE (FULL) OF X$KTCXB (Cost=10 Card=1 Bytes=94)
> FIXED TABLE (FIXED INDEX #1) OF X$KSQRS (Cost=10 Card=100
> Bytes=700)
>
> whereas an uncommented predicate consumes 40 minutes of CPU (sez TOP) with
> this explain plan:
>
> SELECT STATEMENT Optimizer=CHOOSE (Cost=70 Card=1 Bytes=148)
> NESTED LOOPS (Cost=70 Card=1 Bytes=148)
> NESTED LOOPS (Cost=30 Card=1 Bytes=114)
> MERGE JOIN (CARTESIAN) (Cost=20 Card=1 Bytes=37)
> FIXED TABLE (FULL) OF X$KSUSE (Cost=10 Card=1 Bytes=30)
> SORT (JOIN) (Cost=10 Card=1 Bytes=7)
> FIXED TABLE (FULL) OF X$KSQRS (Cost=10 Card=1 Bytes=7)
> FIXED TABLE (FIXED INDEX #1) OF X$KSUSE (Cost=10 Card=1
> Bytes=77)
> VIEW OF GV$_LOCK
> UNION-ALL
> VIEW OF GV$_LOCK1 (Cost=20 Card=2 Bytes=162)
> UNION-ALL
> FIXED TABLE (FULL) OF X$KDNSSF (Cost=10 Card=1 Bytes=94)
> FIXED TABLE (FULL) OF X$KSQEQ (Cost=10 Card=1 Bytes=94)
> FIXED TABLE (FULL) OF X$KTADM (Cost=10 Card=1 Bytes=94)
> FIXED TABLE (FULL) OF X$KTCXB (Cost=10 Card=1 Bytes=94)
>
> If it jams, force it. If it breaks, it needed replacing anyway. --John F
> Duval
>
> --
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> --
> Author: Kirsch, Walter J (Northrop Grumman)
> INET: walter.kirsch-eds_at_eds.com
>

Walter,

  Keep in mind that X$ tables (which underlay the V$ views) are relational representations of memory structures ''SGA-as-tables'). In two words : no statistics. In one acronym : RBO. NOT IN is to the RBO a strong 'full scan' signal. Add to this the absence of any join condition on 'a' and 'b' (noticed the cartesian merge ?) and anything can happen.

-- 
Regards,

Stephane Faroult
Oriole Software
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Stephane Faroult
  INET: sfaroult_at_oriole.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists
--------------------------------------------------------------------
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 May 14 2002 - 14:54:38 CDT

Original text of this message

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