Re: How to compare two different SQL executions plans (question is more deeper then seams from first look)?

  • From: "Jonathan Lewis" <jonathan@xxxxxxxxxxxxxxxxxx>
  • To: <oracle-l@xxxxxxxxxxxxx>
  • Date: Wed, 30 Jun 2004 09:19:24 +0100


The example is demonstrating the relevant of the question
that you quoted, but from the opposite direction to normal.


The two SQL statements repeated below
are 'iso-functional' - in fact the performance
tuning guide tells us that the optimizer may
choose to convert from the IN form to the
EXISTS form before optimizing.

The demonstration is showing, though, that
for a constant amount of CPU (ca. 45 seconds)

a)    One version can be executed 12 times
    whilst the other can only be executed 4 times

and

b)    The statement that can be executed more times
    for the same amount of CPU is the one that would
    be highlighted by many tools as the more expensive
    statement.  (viz. any tool that does a 'top 10' display
    by LIO - which is one of the commonest performance
    monitoring strategies around).



Regards

Jonathan Lewis

http://www.jlcomp.demon.co.uk

http://www.jlcomp.demon.co.uk/faq/ind_faq.html
The Co-operative Oracle Users' FAQ

http://www.jlcomp.demon.co.uk/seminar.html
Optimising Oracle Seminar - schedule updated May 1st


----- Original Message ----- 
From: "Mark W. Farnham" <mwf@xxxxxxxx>


Are you asking "If, given two iso-functional SQL-s operating on the same
dataset, is it usually true that the one which causes fewer LIOs is overall
cheaper in systems resources?" then I think I'm not sure what your examples
have to do with the question.

In the first case, example one gets 800,000 rows in 3.3 seconds from the
full table scan and example two gets 2.4 million rows in 7.5 seconds. Are
these the same datasets? A baseline select count(m.v) from main_tab m might
be illustrative. It appears that this full table scan is required (unless
there are resources inapparent in what is given, and hash won't be used in
RULE.)

In the second case, you're requiring an extraneous (and apparently
purposeless) sort operation.

Any iso-functional SQL can be tweaked to add extraneous use of CPU. If you
take two comparable queries and impose extra all in memory CPU use on one of
them, you indeed mask the usefulness of LIO as a thumbrule. So take the one
with comparable LIO that uses less CPU.




-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx]On Behalf Of J.Velikanovs@xxxxxxxx


TESTCASE 1 (output from 10046)
====================================================
SELECT /*+ RULE */ count(m.v) from main_tab m
where
        m.n in
        (select f.n from
  filter_tab f where f.v='a')


call     count       cpu    elapsed       disk      query    current  rows
------- ------  -------- ---------- ---------- ---------- ----------
----------
Parse        2      0.00       0.00          0          0          0     0
Execute      4      0.00       0.00          0          0          0     0
Fetch        4     44.48      46.17        562    1201856          0     4
------- ------  -------- ---------- ---------- ---------- ----------
----------
total       10     44.48      46.17        562    1201856          0     4

Rows     Row Source Operation
-------  ---------------------------------------------------
      2  SORT AGGREGATE (cr=801234 r=562 w=0 time=31244261 us)
 800000   NESTED LOOPS  (cr=801234 r=562 w=0 time=28962918 us)
 800000    TABLE ACCESS FULL MAIN_TAB (cr=1230 r=562 w=0 time=3309977 us)
 800000    TABLE ACCESS BY INDEX ROWID FILTER_TAB (cr=800004 r=0 w=0
time=16177875 us)
 800000     INDEX UNIQUE SCAN FILTER_TAB_I1 (cr=4 r=0 w=0 time=5226711
us)(object id 9699)



SELECT /*+ RULE */ count(m.v) from main_tab m
where
        exists
        (select v from
  filter_tab f where f.n=m.n and f.v='a')


call     count       cpu    elapsed       disk      query    current  rows
------- ------  -------- ---------- ---------- ---------- ----------
----------
Parse        2      0.00       0.00          0          0          0     0
Execute     12      0.01       0.00          0          0          0     0
Fetch       12     42.38      42.97       1686       5616          0    12
------- ------  -------- ---------- ---------- ---------- ----------
----------
total       26     42.39      42.98       1686       5616          0    12

Rows     Row Source Operation
-------  ---------------------------------------------------
      6  SORT AGGREGATE (cr=3738 r=1686 w=0 time=28675198 us)
2400000   FILTER  (cr=3738 r=1686 w=0 time=22306438 us)
2400000    TABLE ACCESS FULL MAIN_TAB (cr=3690 r=1686 w=0 time=7478255 us)
     24    TABLE ACCESS BY INDEX ROWID FILTER_TAB (cr=48 r=0 w=0 time=524
us)
     24     INDEX UNIQUE SCAN FILTER_TAB_I1 (cr=24 r=0 w=0 time=242
us)(object id 9699)




----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

Other related posts: