Re: Explain THIS plan.

2002-05-15 Thread Connor McDonald

Try 'select /*+ ORDERED */'

hth
connor

 --- Kirsch, Walter J (Northrop Grumman)
[EMAIL PROTECTED] 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$sessionb
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: [EMAIL PROTECTED]
 
 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: [EMAIL PROTECTED] (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). 

=
Connor McDonald
http://www.oracledba.co.uk
http://www.oaktable.net

Some days you're the pigeon, some days you're the statue

__
Do You Yahoo!?
Everything you'll ever need on one web page
from News and Sport to Email and Music Charts
http://uk.my.yahoo.com
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: =?iso-8859-1?q?Connor=20McDonald?=
  INET: [EMAIL PROTECTED]

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: [EMAIL PROTECTED] (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).



Re: Explain THIS plan.

2002-05-14 Thread Stephane Faroult

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$sessionb
  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: [EMAIL PROTECTED]
 

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: [EMAIL PROTECTED]

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: [EMAIL PROTECTED] (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).



RE: Explain THIS plan. SOLVED

2002-05-14 Thread Kirsch, Walter J (Northrop Grumman)


select /*+ rule */ ...

cut the execution time to nil.

Thanks to Charlie Mengler for help and Tim Gorman for a note in his i.sql
that solved the problem.

-Original Message-
[mailto:[EMAIL PROTECTED]]
Sent: Tuesday, May 14, 2002 3:09 PM
To: Multiple recipients of list ORACLE-L



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$sessionb
 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: [EMAIL PROTECTED]

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: [EMAIL PROTECTED] (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.com
-- 
Author: Kirsch, Walter J (Northrop Grumman)
  INET: [EMAIL PROTECTED]

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: [EMAIL PROTECTED] (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).