Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Rakesh .

Asked: March 21, 2003 - 7:58 pm UTC

Last updated: September 23, 2013 - 5:31 pm UTC

Version: 8.0.5

Viewed 50K+ times! This question is

You Asked

I am new in tuning sql statements. Can u give a methodology of tuning
the sql statements.

and Tom said...

Here is a short extract from a book I am working on. The short answer is

if you want a 10 step guide to tuning a query, buy a piece of software. You are not needed in this process, anyone can put a query in, get a query out and run it to see if it is faster. There are tons of these tools on the market. They work using rules (heuristics) and can tune maybe 1% of the problem queries out there. They APPEAR to be able to tune a much larger percent but that is only because the people using these tools never look at the outcome -- hence they continue to make the same basic mistakes over and over and over.

If you want to really be aboe to tune the other 99% of the queries out there, knowledge of lots of stuff -- physical storage mechanisms, access paths, how the optimizer works - thats the only way.

of course, read:
</code> http://docs.oracle.com/cd/A87860_01/doc/server.817/a76965/toc.htm
from cover to cover and
http://docs.oracle.com/cd/A87860_01/doc/server.817/a76992/toc.htm <code>
as well

1.1 Efficient SQL

This was probably the hardest part of the book to write - this chapter. That is not because the material is all that complex, rather because I know what people want - and I know what can be delivered. What people want: The 10 step process by which you can tune any query. What can be delivered: Knowledge about how queries are processed, knowledge you can use and apply day to day as you develop them.

Think about it for a moment. If there were a 10 step or even 1,000,000 step process by which any query can be tuned (or even X% of queries for that matter), we would write a program to do it. Oh don't get me wrong, there are many programs that actually try to do this - Oracle Enterprise Manager with its tuning pack, SQL Navigator and others. What they do is primarily recommend indexing schemes to tune a query, suggest materialized views, offer to add hints to the query to try other access plans. They show you different query plans for the same statement and allow you to pick one. They offer "rules of thumb" (what I generally call ROT since the acronym and the word is maps to are so appropriate for each other) SQL optimizations - which if they were universally applicable - the optimizer would do it as a matter of fact. In fact, the cost based optimizer does that already - it rewrites our queries all of the time. These tuning tools use a very limited set of rules that sometimes can suggest that index or set of indexes you really should have thought of during your design.

I'll close this idea out with this thought - if there were an N step process to tuning a query, to writing efficient SQL - the optimizer would incorporate it all and we would not be having a discussion about this topic at all. It is like the search for the holy grail - maybe someday the software will be sophisticated enough to be perfect in this regards, it will be able to take our SQL, understand the question being asked and process the question - rather then syntax.

To me - writing efficient SQL requires a couple of things:

o Knowledge of the physical organization of what I'm asked to query against. That is - the schema. Knowledge that the physical organization was actually designed in order to help me answer my frequently asked questions (refer back to the chapter on designing an efficient schema for advice in that arena)

o Knowledge of what the database is capable of doing. If I did not know about "skip scan indexes" and what they did (we'll cover them below) - I might look at a schema and say "ah hah, we are missing an index" when in fact we are not.

o Knowledge of all of the intricacies of SQL - from the lowly "WHERE" clause on up to analytics and psuedo columns. Knowledge of what using a particular construct will do to my runtime processing.

o And most importantly of all - a solid understanding of the goal, of what the question is. Tuning a query or process is really hard (impossible I would say) - unless you understand the question in the first place. I cannot tell you how many times I've not been able to tune a query until I had the question in hand. Certainly you can derive a question from a query - however, many times that derived question is much more confining then the real question being asked. For example, many people use outer joins in all queries - they are "afraid" of losing a row (perhaps they got "burned" in some past experience and now use outer joins everywhere). If the objects are related in a one to one mandatory fashion - we don't need an outer join at all. The question derived from the query is much more confining then reality.

That last topic or point is so important, I'll close out this section with it. In this chapter we'll cover the topics of what the database is capable of doing in general - looking at many of the access paths and join operations available to us. We'll look at what SQL is capable of doing - not by discussing the entire language, that in itself is a book. Rather, we'll look at a couple of things that will whet you appetite - show you how powerful this language can be, how much more than just "SELECT" "FROM" "WHERE" and "ORDER BY" there is. Then we'll close up with a look at that most important topic - why understanding the question is more important then having a query at hand to tune.

So, this section will not provide you with the N steps you need to follow in order to tune a query or write the best queries in the world. For every rule of thumb out there anyone has ever shown me regarding writing "efficient SQL", I've been able to come up with a slew of common (not esoteric) counter cases to prove that rule of thumb is wrong in as many cases as it is right. I've talked to people who swear "NOT IN" is fatal, never use it - always use NOT EXISTS. Then I show them NOT IN running a query 10 times faster then NOT EXISTS. I talk with people who feel NOT EXISTS is the worst construct on the planet - you must use IN. Then I do the same - showing them how NOT EXISTS can run many times faster then IN.
.....

Rating

  (891 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

SQL Tuning

Rakesh Dudhia, March 24, 2003 - 12:47 pm UTC

This information and guidence will help me a lot and gives me the direction for SQL Tuning. Thank you so much, Tom.

Difference in SQL's

Vivek Sharma, August 21, 2003 - 7:15 am UTC

Dear Tom,

Can you please tell me the difference between the following 2 queries in terms of resources and performance.

select object_name, cnt from vivek_temp a,
(select object_id, count(*) cnt from vivek_temp2
group by object_id) b
where a.object_id = b.object_id

and

select object_name, count(*)
from vivek_temp a, vivek_temp2 b
where a.object_id = b.object_id
group by object_name;

Which query will be better. At present there are no indexe on both the tables and the count of no. of records is
vivek_temp 29616 record and vivek_temp2 917 records.

I have read in a book that the first query will be faster but when I genereted the output using set autotrace traceonly, I could not find any difference.

Thanks and Regards


Tom Kyte
August 21, 2003 - 6:11 pm UTC

nope.

did you try benchmarking them. I could, but it seems you already have everything setup?


use tkprof

sql re-write suggestion

Baqir Hussain, October 10, 2003 - 4:04 pm UTC

Tom,
I would very much appreciate if you please give some suggestions that how the following query can be rewritten in robust fashion:

select count(personnel_id) from personnel
where personnel_id in (select personnel_id from personnel_role where department_id = 12)
and personnel_id in (select personnel_id from personnel_role where district_id is not null)
and personnel_id in (select personnel_id from personnel_role where end_date is null);

Thanks in advance

Tom Kyte
October 10, 2003 - 5:45 pm UTC



well, to generate the set of personnel ids we are interested int, we could:

select personnel_id,
max(decode(department_id,12,1)) got_dept,
max(decode(district_id,null,to_number(null),1)) got_district,
max(decode(end_date,null,1)) got_end_date
from personnel_role
group by personnel_id
/

(I'm assuming that there are many rows in personnel role for each person and we need to "look across them"

Now, if personnel_id in personnel_role MUST be in personnel (eg: parent child relationship) all we need to do is:

select count(*)
from ( THAT_QUERY )
/

else we can

select count(*)
from personnel a, (THAT_QUERY) b
where a.personnel_id = b.personnel_id
/





excellent explanation

austin, November 03, 2003 - 10:56 am UTC

Hi Tom

I am trying to fine tune this query .This takes almost 50 seconds need to get that down.

Select distinct PA.PersonAddress_IDX, AT.Name AddressType,
A.Line1 Address1, A.Line2 Address2, A.City, A.State,
A.County, A.Country, A.PostalCode, A.AllowPostalSoftYN,
PA.ChangedBy,
PA.ChangedDT, PA.DeletedYN ,PA.Person_Key, PA.Address_Key,
PA.AddressType_Key
FROM PersonAddress_h PA,Address_h A,AddressType_h AT,
(select max(CHANGEDDT)
maxchdt,Person_key,AddressType_Key,Address_Key
from PersonAddress_h
group by Person_key,AddressType_Key,Address_Key) X
where PA.AddressType_Key IN (1,2,3) AND AT.AddressType_IDX =
PA.AddressType_Key
And A.Address_IDX = PA.Address_Key and PA.DeletedYN = 0
and PA.Person_KEY in (SELECT PERSON_KEY FROM INSURED_h I where
I.insured_idx=592374 )
and PA.CHANGEDDT=X.maxchdt
and PA.AddressType_Key=X.AddressType_Key
and PA.Address_Key=X.Address_Key
and AT.CHANGEDDT=(select max(CHANGEDDT) from AddressType_h
where AddressType_IDX = PA.AddressType_Key)
and A.CHANGEDDT= (Select max(CHANGEDDT) from Address_h
where Address_IDX = PA.Address_Key and
(CHANGEDDT-to_date('10/22/2003
18:02:30','mm/dd/yyyy hh24:mi:ss'))<=0.001 )

The exaplain plan now is

Rows Row Source Operation
------- ---------------------------------------------------
3 SORT UNIQUE
8 FILTER
20 SORT GROUP BY
4256 TABLE ACCESS BY INDEX ROWID ADDRESS_H
8513 NESTED LOOPS
4256 NESTED LOOPS
1120 HASH JOIN
1120 HASH JOIN
560 HASH JOIN
560 TABLE ACCESS BY INDEX ROWID PERSONADDRESS_H
617 NESTED LOOPS
56 TABLE ACCESS BY INDEX ROWID INSURED_H
56 INDEX RANGE SCAN INDX_INSURED_H_IDX_EDATE_CDATE
(object id 35548)
560 INDEX RANGE SCAN INDX_PRSNADDR_PRSN_ADDR_H (object
id 56328)
3 VIEW
3 SORT GROUP BY
6 INDEX FAST FULL SCAN CI_ADDRESSTYPE_H (object id
34443)
6 TABLE ACCESS FULL ADDRESSTYPE_H
459380 VIEW
459380 SORT GROUP BY
462919 TABLE ACCESS FULL ADDRESS_H
4256 INDEX RANGE SCAN INDX_PRSNADDR_ALL (object id 56331)
4256 INDEX RANGE SCAN CI_ADDRESS_H (object id 34445)

what baffles me is why the full table scans on ADDRESSTYPE_H and
ADDRESS_H

The tables ADDRESSTYPE_H and ADDRESS_H contain 464080 and 8 records
respectively

Is ther a better way to rewrite this query.A hint or a pointer would be enough to set of the direction.Also i tried the manuals to understand the plan..the manuals are way to simplistic..was just wunderin if you can take some time out to explain what the query id tryin to do in tom speak :-)


Tom Kyte
November 03, 2003 - 2:47 pm UTC

lets see the autotrace traceonly explain output as well from sqlplus

and do you have access to my latest book "effective Oracle by design", in there I walk thru reading explain plans. i have an excerpt here
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:231814117467#7344298017927 <code>



heres my set autotrace on

austin, November 07, 2003 - 11:40 am UTC

Hi Tom

Select distinct PA.PersonAddress_IDX, AT.Name AddressType,
A.Line1 Address1, A.Line2 Address2, A.City, A.State,
A.County, A.Country, A.PostalCode, A.AllowPostalSoftYN, PA.ChangedBy,
PA.ChangedDT, PA.DeletedYN ,PA.Person_Key, PA.Address_Key,
PA.AddressType_Key
FROM PersonAddress_h PA,Address_h A,AddressType_h AT,
(select max(CHANGEDDT) maxchdt,Person_key,AddressType_Key,Address_Key
from PersonAddress_h
group by Person_key,AddressType_Key,Address_Key) X
where PA.AddressType_Key IN (1,2,3) AND AT.AddressType_IDX = PA.AddressType_Key
And A.Address_IDX = PA.Address_Key and PA.DeletedYN = 0
and PA.Person_KEY in (SELECT PERSON_KEY FROM INSURED_h I where I.insured_idx=592374 )
and PA.CHANGEDDT=X.maxchdt
and PA.AddressType_Key=X.AddressType_Key
and PA.Address_Key=X.Address_Key
and AT.CHANGEDDT=(select max(CHANGEDDT) from AddressType_h
where AddressType_IDX = PA.AddressType_Key)
and A.CHANGEDDT= (Select max(CHANGEDDT) from Address_h
where Address_IDX = PA.Address_Key and
(CHANGEDDT-to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss'))<=0.001 )




Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=3802 Card=1 Bytes=19
6)

1 0 SORT (UNIQUE) (Cost=3802 Card=1 Bytes=196)
2 1 FILTER
3 2 SORT (GROUP BY) (Cost=3802 Card=1 Bytes=196)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'ADDRESS_H' (Cost=3
Card=1 Bytes=74)

5 4 NESTED LOOPS (Cost=3791 Card=1 Bytes=196)
6 5 NESTED LOOPS (Cost=3788 Card=1 Bytes=122)
7 6 NESTED LOOPS (Cost=3785 Card=1 Bytes=101)
8 7 HASH JOIN (Cost=3783 Card=1 Bytes=79)
9 8 HASH JOIN (Cost=42 Card=13 Bytes=845)
10 9 TABLE ACCESS (BY INDEX ROWID) OF 'PERSON
ADDRESS_H' (Cost=6 Card=89634 Bytes=3854262)

11 10 NESTED LOOPS (Cost=40 Card=16 Bytes=84
8)

12 11 TABLE ACCESS (BY INDEX ROWID) OF 'IN
SURED_H' (Cost=10 Card=5 Bytes=50)

13 12 INDEX (RANGE SCAN) OF 'INDX_INSURE
D_H_IDX_EDATE_CDATE' (NON-UNIQUE) (Cost=4 Card=5)

14 11 INDEX (RANGE SCAN) OF 'INDX_PRSNADDR
_PRSN_ADDR_H' (NON-UNIQUE) (Cost=3 Card=3)

15 9 VIEW OF 'VW_SQ_1' (Cost=1 Card=3 Bytes=3
6)

16 15 SORT (GROUP BY) (Cost=1 Card=3 Bytes=3
3)

17 16 INLIST ITERATOR
18 17 INDEX (RANGE SCAN) OF 'CI_ADDRESST
YPE_H' (NON-UNIQUE) (Cost=1 Card=6 Bytes=66)

19 8 VIEW OF 'VW_SQ_2' (Cost=3740 Card=23212 By
tes=324968)

20 19 SORT (GROUP BY) (Cost=3740 Card=23212 By
tes=301756)

21 20 TABLE ACCESS (FULL) OF 'ADDRESS_H' (Co
st=3430 Card=23218 Bytes=301834)

22 7 INLIST ITERATOR
23 22 TABLE ACCESS (BY INDEX ROWID) OF 'ADDRESST
YPE_H' (Cost=2 Card=1 Bytes=22)

24 23 INDEX (RANGE SCAN) OF 'CI_ADDRESSTYPE_H'
(NON-UNIQUE) (Cost=1 Card=1)

25 6 INDEX (RANGE SCAN) OF 'INDX_PRSNADDR_ALL' (NON
-UNIQUE) (Cost=3 Card=1 Bytes=21)

26 5 INDEX (RANGE SCAN) OF 'CI_ADDRESS_H' (NON-UNIQUE
) (Cost=2 Card=1)





Statistics
----------------------------------------------------------
103 recursive calls
31 db block gets
38654 consistent gets
32404 physical reads
0 redo size
854 bytes sent via SQL*Net to client
253 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
7 sorts (memory)
1 sorts (disk)
3 rows processed

I managed to get expert one on one by you.Its a great book on oracle...and suits my rqeuirements esp loved the chapter where you compare oracle with sybase and DB2.

The other book is not available will try to get it too..

I understand that you want to look at the cardinalites .Just curious why you are askin for a autotrace output when we already have tkprof ..

Tom Kyte
November 07, 2003 - 2:57 pm UTC

reason i wanted both - i want to see what we EXPECTED, vs what we GOT

for example, look at the view on ADDRESS_H, we EXPECTED 23,212 rows. we GOT 459,380. This mistake made the cards go from an expected 1 in the hash/nested loops joins to thousands.


So, why? are the stats upto date? how do you gather them (exact command, please don't say "we compute", say "we run this command")

austin, November 08, 2003 - 9:56 pm UTC

Hi Tom

Thanks for taking your precious time out to look into this problem.I am learning a lot from your comments.The stats are collected everynight.Heres the exact command we use

exec dbms_stats.gather_schema_statsownname=>'AUSTIN',METHOD_OPT=>'for
all columns ',CASCADE=>true);

The optimizer expects 23,212 rows but finds 459,380 and the reason might be attributed to missin or stale stats.Have you explained such scenarios in your book Performance by design ?


Tom Kyte
November 09, 2003 - 7:01 am UTC

what happens to the autotrace if you change:

A.CHANGEDDT= (Select max(CHANGEDDT) from Address_h
where Address_IDX = PA.Address_Key and
(CHANGEDDT-to_date('10/22/2003 18:02:30','mm/dd/yyyy
hh24:mi:ss'))<=0.001 )

to

A.CHANGEDDT=
(Select max(CHANGEDDT)
from Address_h
where Address_IDX = PA.Address_Key
and CHANGEDDT <= to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss')+0.001 )

which seems like a "strange" constraint in the first place, why not just use 18:03:56 for the time and lose the 0.001?

excellent response I did not notice this

austin, November 12, 2003 - 3:03 pm UTC

Hi Tom

Thank you very much..You have spotted the right thing.

This time we have a slightly better plan

SQL> Select distinct PA.PersonAddress_IDX, AT.Name AddressType,
  2     A.Line1 Address1, A.Line2 Address2, A.City, A.State,
  3     A.County, A.Country, A.PostalCode, A.AllowPostalSoftYN, PA.ChangedBy,
  4     PA.ChangedDT, PA.DeletedYN ,PA.Person_Key, PA.Address_Key,
  5     PA.AddressType_Key
  6  FROM       PersonAddress_h PA,Address_h A,AddressType_h AT,
  7     (select max(CHANGEDDT) maxchdt,Person_key,AddressType_Key,Address_Key
  8             from PersonAddress_h
  9             group by Person_key,AddressType_Key,Address_Key) X
 10  where   PA.AddressType_Key IN (1,2,3) AND AT.AddressType_IDX = PA.AddressType_Key
 11     And A.Address_IDX = PA.Address_Key and PA.DeletedYN = 0
 12     and PA.Person_KEY in (SELECT PERSON_KEY FROM INSURED_h I where I.insured_idx=592374 )
 13     and PA.CHANGEDDT=X.maxchdt
 14     and PA.AddressType_Key=X.AddressType_Key
 15     and PA.Address_Key=X.Address_Key
 16     and AT.CHANGEDDT=(select max(CHANGEDDT) from AddressType_h
 17                             where AddressType_IDX = PA.AddressType_Key)
 18     and     A.CHANGEDDT= (Select max(CHANGEDDT) from Address_h
 19                     where Address_IDX = PA.Address_Key and
 20                     (CHANGEDDT-to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss'))<=0.001 )
 21  
                           
                                                                                

Execution Plan
----------------------------------------------------------                      
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=3779 Card=1 Bytes=18          
          7)                                                                    
                                                                                
   1    0   SORT (UNIQUE) (Cost=3779 Card=1 Bytes=187)                          
   2    1     FILTER                                                            
   3    2       SORT (GROUP BY) (Cost=3779 Card=1 Bytes=187)                    
   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'ADDRESS_H' (Cost=3          
           Card=1 Bytes=66)                                                     
                                                                                
   5    4           NESTED LOOPS (Cost=3768 Card=1 Bytes=187)                   
   6    5             NESTED LOOPS (Cost=3765 Card=1 Bytes=121)                 
   7    6               NESTED LOOPS (Cost=3762 Card=1 Bytes=100)               
   8    7                 HASH JOIN (Cost=3760 Card=1 Bytes=78)                 
   9    8                   HASH JOIN (Cost=42 Card=16 Bytes=1040)              
  10    9                     TABLE ACCESS (BY INDEX ROWID) OF 'PERSON          
          ADDRESS_H' (Cost=6 Card=101955 Bytes=4384065)                         
                                                                                
  11   10                       NESTED LOOPS (Cost=40 Card=16 Bytes=84          
          8)                                                                    
                                                                                
  12   11                         TABLE ACCESS (BY INDEX ROWID) OF 'IN          
          SURED_H' (Cost=10 Card=5 Bytes=50)                                    
                                                                                
  13   12                           INDEX (RANGE SCAN) OF 'INDX_INSURE          
          D_H_IDX_EDATE_CDATE' (NON-UNIQUE) (Cost=4 Card=5)                     
                                                                                
  14   11                         INDEX (RANGE SCAN) OF 'INDX_PRSNADDR          
          _PRSN_ADDR_H' (NON-UNIQUE) (Cost=3 Card=3)                            
                                                                                
  15    9                     VIEW OF 'VW_SQ_1' (Cost=1 Card=3 Bytes=3          
          6)                                                                    
                                                                                
  16   15                       SORT (GROUP BY) (Cost=1 Card=3 Bytes=3          
          3)                                                                    
                                                                                
  17   16                         INLIST ITERATOR                               
  18   17                           INDEX (RANGE SCAN) OF 'CI_ADDRESST          
          YPE_H' (NON-UNIQUE) (Cost=1 Card=6 Bytes=66)                          
                                                                                
  19    8                   VIEW OF 'VW_SQ_2' (Cost=3717 Card=23212 By          
          tes=301756)                                                           
                                                                                
  20   19                     SORT (GROUP BY) (Cost=3717 Card=23212 By          
          tes=255332)                                                           
                                                                                
  21   20                       TABLE ACCESS (FULL) OF 'ADDRESS_H' (Co          
          st=3430 Card=23218 Bytes=255398)                                      
                                                                                
  22    7                 INLIST ITERATOR                                       
  23   22                   TABLE ACCESS (BY INDEX ROWID) OF 'ADDRESST          
          YPE_H' (Cost=2 Card=1 Bytes=22)                                       
                                                                                
  24   23                     INDEX (RANGE SCAN) OF 'CI_ADDRESSTYPE_H'          
           (NON-UNIQUE) (Cost=1 Card=1)                                         
                                                                                
  25    6               INDEX (RANGE SCAN) OF 'INDX_PRSNADDR_ALL' (NON          
          -UNIQUE) (Cost=3 Card=1 Bytes=21)                                     
                                                                                
  26    5             INDEX (RANGE SCAN) OF 'CI_ADDRESS_H' (NON-UNIQUE          
          ) (Cost=2 Card=1)                                                     
                                                                                




Statistics
----------------------------------------------------------                      
          0  recursive calls                                                    
         31  db block gets                                                      
      38633  consistent gets                                                    
      31897  physical reads                                                     
          0  redo size                                                          
        865  bytes sent via SQL*Net to client                                   
        253  bytes received via SQL*Net from client                             
          2  SQL*Net roundtrips to/from client                                  
          3  sorts (memory)                                                     
          1  sorts (disk)                                                       
          3  rows processed                                                     

But can we improve the query performance at all ?

I also notice a very strange thing 

If in the qury on line 10 if we use

where   PA.AddressType_Key IN (1) instead of 
PA.AddressType_Key IN (1,2,3) or any single number then the result is instanttaneous any ideas why this happening.
 

Tom Kyte
November 12, 2003 - 4:56 pm UTC

well, in (1) processes less rows then in (1,2,3) would no?

you can see about using analytics instead of subqueries. for example, one approach to find the emp(s) with the max(hiredate) by dept could be:


select *
from emp
where hiredate = ( select max(hiredate) from emp e2 where e2.deptno = emp.deptno)

that is what you have coded, another way is:

select *
from ( select emp.*, max(hiredate) over ( partition by deptno ) max_hd
from emp
)
where hiredate = max_hd;



Optimal Schema Design

A reader, December 04, 2003 - 6:50 pm UTC

Hi Tom,

I have an impression that no matter how hard I spend time designing the schema, choosing table types, creating indexes, there is no such thing as "the most optimally designed schema".

For example, a table designed for small data volume may become very non-optimal if the data volume increases; a well-picked index may slow down the performance if there is ad-hoc query not being expected.

In your opinion, is there an "optimally designed schema" or not? Please comment.

Tom Kyte
December 04, 2003 - 8:44 pm UTC

there are optimally designed functions

today with huge schemas - probably not optimally designed schemas for the entire system.

You pick the hard parts -- optimize for them at the expense of others.

I'll gladly denormalize in a transactional system if

a) the inserts are relatively few compared to
b) the reads, which if I didn't optimize for -- would kill me

I did sort of a case study on that in my book "effective oracle by design". it was a palm pilot sort of application (well, it was a web calendard/scheduler/contact list to be synced with a palm)

we could have used the palm model, very terse, compact -- very fast for inserts

but -- dog dog dog slow for queries and impossible to query using sql (eg: had to read data out and do the query in the middle tier)

we realized (based on study) that well over 90% of the access was read. inserts -- few (you schedule an appointment once, you look at it dozens/hundreds of times as do others)

we optimized for reads -- took more storage, much harder to update, but the performance -- outstanding.


Take your low hanging fruit -- go for it. Make it good and the rest good enough. concentrate on the things that if they do not work would kill you. make them go really good.

my 2cents worth.

Sql's across db links.

Sai, December 05, 2003 - 6:24 am UTC

Hi Tom,

Tuning sql statments across db links driving me crazy, absolutely no consistency in Oracle optimizer plans. For example.. I want to write following pl/sql block in to single sql statment, but it was always doing full table scan with one single statment( no matter whatever analyze, hints...etc...I do). I have to use Index range scan here, since it selects very few rows out of a 20G table, and hence I was forced to choose pl/sql.

for i in ( select * from prod.poof_model_login@ctoc
where time_created between v_time and v_time_end) loop
insert into ctoc.poof_model_login values (i.id,i.account_number,i.time_created
,i.flags,i.spoof_bucket,i.login_ip,i.susp_activity_level,i.geography);
end loop;

What I have observed was, Oracle will use efficient optimizer plans across db links only in a plain select statment, but not with CTAS, insert/update/delete statments.

Your thoughts on this is very much appreciated.

Thanks

SQL tuning the scientific way

A reader, January 01, 2004 - 2:18 pm UTC

Hi

I bought a SQL tuning book recently from OReilly, the title is called "SQL Tuning" by Dan Tow. I read a few chapters and noticed he is base many things scientifically, using filter ratios, heuristic join orderes, nodes, links between tabla joins, full query diagrams etc. Are these the basics behind Oracle Optimizer? Do you tune a query this way or using common sense such as reducing the query result sets as small as possible (the Oracle documentation way). The book seems reasonably good just that if we are using CBO I think it's quite useless :-)



Tom Kyte
January 01, 2004 - 5:29 pm UTC

I believe that is the work of software, our job is in the design. If you have a bad design for the questions you frequently ask -- no amount of query tuning is going to help.

if you run a query 1,000,000 times in a loop -- it'll still be slow even if you make it run 2x as fast. You want to look at the algorithms and change them so you don't do something 1,000,000 times (use bulk SQL)...



Reducing I/O

Vivek Sharma, January 03, 2004 - 5:41 pm UTC

Dear Tom,

I have a query which is scanning table Nbfc_Pmnt_dtl table twice via Index. This table has around 2.3 Crore Rows. How can I change this query so that this table is scanned only once so as to perform single I/O.

SELECT a.Chequeid,a.AllocatedAmt,
nvl(a.intcomp_recd/*used this as chargecodeid 22 was used earlier*/,0) allocated_prin
FROM finnonelea.Nbfc_Pmnt_Dtl a
WHERE TxnAdviceID = :txnadviceid
AND NVL(a.Status,'Z') = 'Z'
UNION all
SELECT a.Chequeid,a.AllocatedAmt,0 allocated_prin
FROM finnonelea.Nbfc_Pmnt_Dtl a,
finnonelea.Nbfc_txn_advice_dtl b
WHERE a.TxnAdviceID = :txnadviceid
AND NVL(a.Status,'Z') = 'Z'
AND a.txnadviceid = b.txnadviceid
AND b.chargeid in ( select chargeid from finnonelea.nbfc_charges_m where chargecodeid in ( 82,261 ) )
/

Regards
Vivek Sharma

Tom Kyte
January 03, 2004 - 6:35 pm UTC

can't realistically (well, we could but it would probably be worse)

You have rows coming out of finnonelea.Nbfc_Pmnt_Dtl TWICE in that query.

once when not joined to B and again when joined to B.


If you are willing to change the output result set "shape", we can do this. Instead of outputting the row 2times, we'll use 2 columns on a single row.

SELECT a.Chequeid,
a.AllocatedAmt,
nvl(a.intcomp_recd/*used this as chargecodeid 22 was used earlier*/,0) c1,
decode( b.txnadviceid, NULL, NULL, 0 ) c2
FROM finnonelea.Nbfc_Pmnt_Dtl a,
(select txnadvicedid
from finnonelea.Nbfc_txn_advice_dtl
where txnadviceid = :txnadviceid
and chargeid in ( select chargeid
from finnonelea.nbfc_charges_m
where chargecodeid in ( 82,261 ) )
) b
WHERE a.TxnAdviceID = :txnadviceid
AND NVL(a.Status,'Z') = 'Z'
AND a.txnadviceid = b.txnadviceid(+)
/


Now, C1 will be filled in for all rows and if C1 is NULL, then the "second record" from A would not have existed. If C2 is 0, it would have existed (would have come out in the union all query)


Tuning SQL Query

Tarun, January 07, 2004 - 2:55 am UTC

Hi tom,
I tried to post question several times but, its showing status busy always. Please help me to write the following query in a better way.

INSERT INTO drehr_addr_errors
SELECT bu_name -- check for existence of town or city
,system_location
,system_name
,employee_number
,national_identifier
,'TOWN_OR_CITY'
,town_or_city
,'Town or City is Null'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE town_or_city IS NULL
UNION
SELECT bu_name -- check for existence of State
,system_location
,system_name
,employee_number
,national_identifier
,'REGION2'
,region2
,'State is Null'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE region2 IS NULL
UNION
SELECT bu_name -- check for existence of County
,system_location
,system_name
,employee_number
,national_identifier
,'REGION1'
,region1
,'County is Null'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE region1 IS NULL
UNION
SELECT bu_name -- check for existence of ZIP
,system_location
,system_name
,employee_number
,national_identifier
,'POSTAL_CODE'
,postal_code
,'Postal Code is Null'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE postal_code IS NULL
UNION
SELECT bu_name -- check for valid Primary Flag
,system_location
,system_name
,employee_number
,national_identifier
,'PRIMARY_FLAG'
,primary_flag
,'Invalid Primary Flag'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE UPPER (primary_flag) <> 'N'
AND UPPER (primary_flag) <> 'Y'
AND UPPER (primary_flag) <> 'YES'
AND UPPER (primary_flag) <> 'NO'
UNION
SELECT bu_name -- Chk for the Duplicate primary flag enabled for the employee
,system_location
,system_name
,employee_number
,national_identifier
,'PRIMARY_FLAG'
,primary_flag
,'Duplicate Primary Flag'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr a
WHERE 1 <
(SELECT COUNT (primary_flag)
FROM drehr_addr b
WHERE ( UPPER (primary_flag) = 'Y'
OR UPPER (primary_flag) = 'YES'
)
AND a.employee_number = b.employee_number
AND a.bu_name = b.bu_name
AND a.system_location = b.system_location
AND a.system_name = b.system_name
AND a.national_identifier = b.national_identifier
GROUP BY bu_name
,system_name
,system_location
,national_identifier
,employee_number)
UNION
SELECT bu_name -- check for date_from less than hiredate of employee
,system_location
,system_name
,employee_number
,national_identifier
,'DATE_FROM'
,TO_CHAR (date_from)
,'Date From is Less Than Hiredate of Employee'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr a
WHERE TRUNC (date_from) <
(SELECT DISTINCT TRUNC (original_date_of_hire)
FROM per_all_people_f p
WHERE a.employee_number= p.attribute3
AND NVL (a.national_identifier, '~') =
NVL (p.national_identifier, '~')
AND a.effective_date
BETWEEN p.effective_start_date
AND p.effective_end_date)
UNION
SELECT bu_name -- check for existence of national_identifier and it length for US addresses
,system_location
,system_name
,employee_number
,national_identifier
,'NATIONAL_IDENTIFIER'
,national_identifier
,'National Udentifier Existence/Length Validation failed for US Employee'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE UPPER (style) = 'US'
AND UPPER (country) = 'US'
AND ( national_identifier IS NULL
OR LENGTH (national_identifier) <> 11
)
UNION
SELECT bu_name -- Check for equality of Effective date and date from when prior addresses are not there
,system_location
,system_name
,employee_number
,national_identifier
,'EFFECTIVE_DATE'
,TO_CHAR (effective_date)
,'Effective_Date and Date_From not same for Single Address Record'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE TRUNC (effective_date) <> TRUNC (date_from)
GROUP BY bu_name
,system_name
,system_location
,national_identifier
,employee_number
,effective_date
HAVING COUNT (DISTINCT effective_date) = 1
/

Execution Plan
----------------------------------------------------------
0 INSERT STATEMENT Optimizer=CHOOSE (Cost=383 Card=30 Bytes=34
10)

1 0 SORT (UNIQUE) (Cost=383 Card=30 Bytes=3410)
2 1 UNION-ALL
3 2 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4 Byt
es=428)

4 2 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4 Byt
es=508)

5 2 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4 Byt
es=508)

6 2 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4 Byt
es=428)

7 2 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=1 Byt
es=107)

8 2 FILTER
9 8 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4 B
ytes=428)

10 8 SORT (GROUP BY NOSORT) (Cost=2 Card=1 Bytes=107)
11 10 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=1
Bytes=107)

12 2 FILTER
13 12 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4 B
ytes=432)

14 12 SORT (UNIQUE) (Cost=57 Card=1 Bytes=30)
15 14 TABLE ACCESS (FULL) OF 'PER_ALL_PEOPLE_F' (Cost=44
Card=1 Bytes=30)

16 2 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=1 Byt
es=139)

17 2 FILTER
18 17 SORT (GROUP BY) (Cost=27 Card=4 Bytes=432)
19 18 TABLE ACCESS (FULL) OF 'DREHR_ADDR' (Cost=2 Card=4
Bytes=432)





Tom Kyte
January 07, 2004 - 7:58 am UTC

well, i am just one guy -- i can take maybe 10/20 questions a day with people asking questions here. so, it is purely catch as catch can.

Actually, if the stats are accurate, this query should run in a fraction of a millisecond. no data in there... but anyway



take all of the queries of this form:

SELECT bu_name -- check for existence of town or city
...
,'TOWN_OR_CITY'
,town_or_city
,'Town or City is Null'
....
FROM drehr_addr
WHERE town_or_city IS NULL
UNION
SELECT bu_name -- check for existence of State
...
,'REGION2'
,region2
,'State is Null'
....
FROM drehr_addr
WHERE region2 IS NULL

and recode as a single statement:

SELECT bu_name -- check for existence of town or city
...
,decode( town_or_city, null, 'TOWN_OR_CITY') c1a,
,town_or_city c1b,
,decode( town_or_city, 'Town or City is Null' ) c1c,
,decode( region2, null, 'REGION2') c2a
,region2 c2b
,decode( region2, 'State is null' ) c2c

....
FROM drehr_addr
WHERE town_or_city IS NULL OR region2 is NULL


change the code that processes this to look at the c1x, c2x, c3x, ... columns instead of looking for row by row (yes, this will require a slight change to the client code.


start there and apply the same technique to the rest of the query.

You have things like a case statement, so this query:

SELECT bu_name -- check for valid Primary Flag
,system_location
,system_name
,employee_number
,national_identifier
,'PRIMARY_FLAG'
,primary_flag
,'Invalid Primary Flag'
,SYSDATE
,0
,SYSDATE
,0
,NULL
,NULL
FROM drehr_addr
WHERE UPPER (primary_flag) <> 'N'
AND UPPER (primary_flag) <> 'Y'
AND UPPER (primary_flag) <> 'YES'
AND UPPER (primary_flag) <> 'NO'

can become

select bu_name, ......, case when upper(primary_flag) not in ( 'N', 'Y', 'YES', 'NO' ) then 'Invalid Primary Flag' end, .....


your goal -- process ALL of the exceptions for a record in a single record! if a record has 5 errors, instead of getting 5 records, you'll get 1 record with 5 sets of columns populated describing the errors.


index range scan related issue

Reader, January 07, 2004 - 1:13 pm UTC

12:25:45 SQL> @tc1
12:25:46 SQL> spool tc1;
12:25:46 SQL> set echo on timing on
12:25:46 SQL> column plan_plus_exp format a100
12:25:46 SQL> set linesize 150
12:25:46 SQL> set trimspool on
12:25:46 SQL> drop table t;

Table dropped.

Elapsed: 00:00:00.09
12:25:46 SQL> create table t nologging as select * from dba_objects;

Table created.

Elapsed: 00:00:00.45
12:25:47 SQL> create index t_idx on t(owner,object_id) nologging compute statistics;

Index created.

Elapsed: 00:00:00.28
12:25:47 SQL> set autot on
12:25:47 SQL> select rownum||' '||owner||' '||object_id from t where owner='SYS' and rownum<11;

ROWNUM||''||OWNER||''||OBJECT_ID
----------------------------------------------------------------------------------------------------------------
1 SYS 98
2 SYS 99
3 SYS 100
4 SYS 101
5 SYS 107
6 SYS 121
7 SYS 125
8 SYS 142
9 SYS 900
10 SYS 902

10 rows selected.

Elapsed: 00:00:00.64

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=10 Bytes=180)
   1    0   COUNT (STOPKEY)
   2    1     INDEX (RANGE SCAN) OF 'T_IDX' (NON-UNIQUE) (Cost=2 Card=218 Bytes=3924)




Statistics
----------------------------------------------------------
         22  recursive calls
          0  db block gets
          5  consistent gets
          1  physical reads
          0  redo size
        703  bytes sent via SQL*Net to client
        652  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         10  rows processed

12:25:48 SQL> select * from (select rownum||' '||owner||' '||object_id from t
12:25:48   2  where owner='SYS'
12:25:48   3  order by owner,object_id ) where rownum<11;

ROWNUM||''||OWNER||''||OBJECT_ID
----------------------------------------------------------------------------------------------------------------
1 SYS 98
2 SYS 99
3 SYS 100
4 SYS 101
5 SYS 107
6 SYS 121
7 SYS 125
8 SYS 142
9 SYS 900
10 SYS 902

10 rows selected.

Elapsed: 00:00:00.65

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=10 Bytes=580)
   1    0   COUNT (STOPKEY)
   2    1     VIEW (Cost=2 Card=218 Bytes=12644)
   3    2       COUNT
   4    3         INDEX (RANGE SCAN) OF 'T_IDX' (NON-UNIQUE) (Cost=2 Card=218 Bytes=3924)




Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          3  consistent gets
          0  physical reads
          0  redo size
        703  bytes sent via SQL*Net to client
        652  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         10  rows processed

12:25:48 SQL> 

Question: Is there any risk first SQL may not work as expected in future (if I drop index obviously it will not), but apart from that. Thus is the 2nd SQL really needed?

Somehow I have a feeling you will say don't use first and only use 2nd?

Thanks for your help! 

Tom Kyte
January 07, 2004 - 6:29 pm UTC

RULES OF THE GAME:

rule #1: if you want, expect, or need sorted data, there is exactly one way to achieve that in a relational database.

you must use order by

rule #2: please re-read #1 until you believe it.


the first query says "give me a random set of 10 rows for the SYS owner"

the second says "give me 10 rows for the sys owner starting at the smallest object_id in sorted order"

follow up to earlier

A reader, January 08, 2004 - 7:17 am UTC

Hi Tom,

Thanks for the answer.
However, "INDEX (RANGE SCAN) " vs full scan
Doesn't one goes from small -> big (or big->small) vs
scan all the blocks and present data as it presents (i.e no particular order).

If so, have you ever encountered data which says using "INDEX (RANGE SCAN) " AND is out of order?
Also, can you take a approach like below,

select * from (select rownum rn,owner,object_id
from t where rownum<6)
order by rn;

Now the client reading the data will ensure if next rows rn value is not rn+1 compared to current one, there is a problem.

I am trying to understand "INDEX (RANGE SCAN) " does mean go from node to node in certain order or not?

Again, thanks for your explanations

Tom Kyte
January 08, 2004 - 1:52 pm UTC

if you want SORTED DATA, you need to order by.


select * from (select rownum rn,owner,object_id
from t where rownum<6)
order by rn;

is not any different than

select rownum rn, owner, object_id from t where rownum < 6;

then are the same.


if you need SORTED DATA by all means ORDER BY it -- else you can have NO expectations as to the returned order of the data. NONE.

one correction

A reader, January 08, 2004 - 7:21 am UTC

my earlier question:

Actually no need to order for this test

select * from (select owner,object_id
from t where rownum<6)
;

Now the client reading the data will ensure owner+object_id of next row is in order (< or >) than current owner+object. If not rollback and retry


Tom Kyte
January 08, 2004 - 1:53 pm UTC



that is called a "random code path"

it is meaningless. it is "not sensible". it makes no sense.


retry what? you'll just get the same data (i guess you could call this an infinite loop)

Oops

A reader, January 08, 2004 - 7:22 am UTC

select owner,object_id from t where owner='SYS' and rownum<6
should be the sql I was saying in prior two posts.

Sorry for that.

Thanks

SQL Tuning

Gerry Jurrens, January 08, 2004 - 3:47 pm UTC

I teach SQL Tuning and found this thread EXTREMELY helpful! I try to tell my students that if I had a magic wand, I'd put the code in the kernel of Oracle and no one would have to do anything to tune their SQL.

Tom's book is great! Buy the book!

GJ


Kiran from India

Kiran, January 28, 2004 - 12:49 am UTC

Hi,

Tom Could u pls suggest me a good bood for SQL Tuning.

Tom Kyte
January 28, 2004 - 8:25 am UTC

how about the oracle documentation set?

have you read the concepts guide? the application developers guide? the performance guide?

they are all pretty solid.

after that -- it is practice, practice, practice. for you see -- the stuff that can be "taught" as a list (eg: do this, do that, do the other thing) well -- we put that into software. so the stuff you can find in a book (tips and tricks sort of stuff) -- it's already in the software.

The stuff that is NOT in the software -- how to take a slow by slow algorithm (row by row) and turn it into a single sql statement. You can tune a query to death but if you execute it a million times, it'll still take a really long time. If you take that procedural process and turn it into a single sql statement -- you'll find it goes much much faster.

tuning tools are much more clever than CBO!

A reader, January 29, 2004 - 3:48 am UTC

I never thought these tuning tools such as Quest SQL LAB can make queries run much better.

Was evaluating the tool and passed queries from one of slow batch jobs running in HP-UX Oracle 9.2.0.4 (latest patch)... Guess what, SQL LAB reduced by 10 times (yes 10!!!) the query execution times!!! Our batch job used to take 6 hours now takes 35 minutes wowowowo!!!

I dont understand how these tools work but they seem to be much better than CBO?!

Oracle should hire Quest to write their CBO

A reader, January 30, 2004 - 7:48 am UTC

I think so, Quest SQL LAB seems much better than CBO!

Tom Kyte
January 30, 2004 - 8:27 am UTC

you should give OEM a try as well -- it does the same thing.

Oracle should hire Quest?

Mark A. Williams, January 30, 2004 - 9:49 am UTC

Funny. Did the tool suggest a change to the query?

- Mark

Quest Lab Better Than CBO ???

Kevin Balfe, January 30, 2004 - 11:45 am UTC

I've used Quest Lab in the past. It's pretty good, but:

1. It can take a half-hour to test hundreds of different scenarios. Do you REALLY want the CBO to take that much time to evaluate alternatives every time you run a query?

2. It often uses HINTS which optimize the query under the particular circumstances tested, and DE-optimize it under other (untested) circumstances. This inflexible approach more or less assumes that circumstances (data, hardware, config) will not change much.

3. It sometimes re-writes your SQL, even warning you that the results may not be the same.

CBO does pretty well all things considered. Quest Lab is a useful tool -- but you have to live with IT's limitations too.

Tom Kyte
January 30, 2004 - 7:44 pm UTC

And in 10g -- we do have the option of letting the optimizer take as long as we want to optimize a query like that. It is like gathering statistics on a query -- and it uses extended stats in the data dictionary (not hints) to help the optimizer out in real time later on.

#3 is the really bad thing -- especially if the person asking quest to do this isn't SQL savvy enough to do it themselves -- how can they tell in some cases?

any thoughts on this query

john, March 12, 2004 - 12:14 pm UTC

Hi Tom,

This query is taking about 10 min. to execute.
Any thoughts on how can I improve it?

select t.tcode, sum(tp.percentage), t.FSTPERFYEARQTR
from title t,
(select b.TCODE, b.ICODE, b.percentage
from title_party b, (select a.TCODE, a.ICODE, a.PARTYID, a.RECORDCODE, a.TERRITORY,
max(a.EFFDTE) as effdte
from title_party a
group by a.tcode, a.icode, a.partyid, a.recordcode, a.territory) c
where b.tcode = c.tcode
and b.icode = c.icode
and b.partyid = c.partyid
and b.recordcode = c.recordcode
and b.territory = c.territory
and b.effdte = c.effdte
and b.recordcode = 1) tp
where t.ICODE = tp.ICODE
group by t.tcode, t.FSTPERFYEARQTR
having sum(tp.percentage) < 199


Tom Kyte
March 12, 2004 - 5:20 pm UTC

seems to me that:

(select b.TCODE, b.ICODE, b.percentage
from title_party b,
(select a.TCODE, a.ICODE, a.PARTYID, a.RECORDCODE,
a.TERRITORY, max(a.EFFDTE) as effdte
from title_party a
group by a.tcode, a.icode, a.partyid, a.recordcode, a.territory) c
where b.tcode = c.tcode
and b.icode = c.icode
and b.partyid = c.partyid
and b.recordcode = c.recordcode
and b.territory = c.territory
and b.effdte = c.effdte
and b.recordcode = 1) tp

Is just trying to get the ICODE/PERCENTAGE for each record such that the EFFDTE is the MAX(EFFDTE) by tcode,icode,partyid,territory for recordcode = 1

that is what it works out to in my head anyway -- since you generate the set of max_effdtes by that and join. If that agrees with your take on it, then I believe that is more simply said like this:

(
select icode, percentage
from ( (select icode, percentage, effdte,
max(effdte) over(partition by tcode, icode, partyid,
territory) max_effdte
from title
where recordcode = 1)
where effdte = max_effdte
) tp


so, you should be able to replace your TP with that one and make a single pass on the title table and only pick up the recordcode=1 records

You might have to throw in some "and tcode is not null and icode is not null ..." as well if they are nullable (as your JOIN removes them)

Thank You very much !!

mike, March 15, 2004 - 9:36 am UTC

Thanks, Tom. But I am getting this:

ERROR at line 9:
ORA-00907: missing right parenthesis


select t.tcode, sum(tp.percentage) , t.FSTPERFYEARQTR
from title t,
(select icode, percentage
from ( (select icode, percentage, effdte,
max(effdte) over(partition by tcode, icode, partyid,
territory) max_effdte
from title
where recordcode = 1)
where effdte = max_effdte ) tp
where t.ICODE = tp.ICODE
group by t.tcode, , t.FSTPERFYEARQTR
having sum(tp.percentage) < 199


Tom Kyte
March 15, 2004 - 9:54 am UTC

from ( (selec
^^ remove

Identifying Full Table Scan

Vivek Sharma, April 12, 2004 - 12:55 pm UTC

Dear Tom,

I was going through your book "Effective Oracle by Design". On page no.104 you have done following

create table I1(n number primary key, v varchar2(10));
create table I2(n number primary key, v varchar2(10));
and a map table
create table map
(n number primary key,
i1 number referencing I1(n),
i2 number referencing I2(n));
create unique index IDX_MAP on MAP(i1, i2);

Now the explain plan for the query
select * from i1, map, i2
where i1.n=map.i1
and i2.n=map.i2
and i1.v = 'x'
and i2.v = 'y';

The plan showed a full table scan of MAP. You commented "Is there any way to avoid the full table scan on the Map table ? Whatever I try, one table is always going for a full scan. What should I do to avoid a full scan in such case ?"

I do agree that full scans are not always evill indexes are not always good. But would like to know that how can you say so confidently that whatever, keep aside hints, we do there is no way to avoid a Full table scan in the above query. Would like to know for my knowledge purpose.

Thanks and Regards
Vivek Sharma

Tom Kyte
April 12, 2004 - 3:01 pm UTC

Look at the existing structures.


Look at the predicates.


there is a predicate "i1.v = 'x'". there is no index on i1(v)

there is a predicate "i2.v = 'y'". there is no index on i2(v)

so, if we lead with either of i1 or i2 -- we must full scan them since there is no index in place to be used.


So, we are left with "what if we drive with map". Well, we have NO predicates on map really -- just a join condition. Sure, map(i1,i2) is indexed but so what? We'd have to full scan I1 to find values to join to MAP (so we'd be back to driving with i1 again)


Just look at the indexes that are there, the query itself and tell me how to avoid an index. The question rules them out given the existing structures.

Do you have a better way for this query?

Jennifer Chen, April 14, 2004 - 2:32 pm UTC

Hi Tom,

We have an existing application that runs under SQL Server. I am now converting the DB part into Oracle. I can't change table strucatures. Here is the piece of SQL, I would like to see whether or not you have a better way:

CREATE TABLE test
(tcn VARCHAR2(13) NOT NULL,
alias_field VARCHAR2(25),
value VARCHAR2(100));

INSERT INTO test VALUES ('A', 'NAM', 'JOHN');
INSERT INTO test VALUES ('A', 'DOB', '12/31/1959');
INSERT INTO test VALUES ('B', 'NAM', 'JEN');
INSERT INTO test VALUES ('C', 'DOB', '01/12/1945');
INSERT INTO test VALUES ('D', null, null);

SELECT * from test;

TCN ALIAS_FIEL VALUE
------------- ---------- --------------------
A NAM JOHN
A DOB 12/31/1959
B NAM JEN
C DOB 01/12/1945
D

This 5 records cover all possible scenarios:

nam dob
------------------------
not null not null
not null null
null not null
null null

The query should return the following results:

tcn nam dob
--------------------------
A JOHN 12/31/1959
B JEN
C 01/12/1945
D

Here is what I wrote, but I don't think I can use this piece because the real table is big:

SELECT n1.tcn, n1.VALUE nam, n2.VALUE dob
FROM test n1,
test n2
WHERE n1.tcn = n2.tcn
AND n1.alias_field = 'NAM'
AND n2.alias_field = 'DOB'
UNION ALL
SELECT n1.tcn, NULL nam, n1.VALUE dob
FROM test n1
WHERE n1.alias_field = 'DOB'
AND EXISTS (SELECT n2.tcn
FROM test n2
WHERE n2.tcn = n1.tcn
GROUP BY n2.tcn
HAVING count(n2.tcn)=1)
UNION ALL
SELECT n1.tcn, n1.VALUE nam, NULL dob
FROM test n1
WHERE n1.alias_field = 'NAM'
AND EXISTS (SELECT n2.tcn
FROM test n2
WHERE n2.tcn = n1.tcn
GROUP BY n2.tcn
HAVING count(n2.tcn)=1)
UNION ALL
SELECT n1.tcn, NULL nam, NULL dob
FROM test n1
WHERE n1.alias_field IS NULL
AND EXISTS (SELECT n2.tcn
FROM test n2
WHERE n2.tcn = n1.tcn
GROUP BY n2.tcn
HAVING count(n2.tcn)=1);

Would you please help?

Thank you.



Tom Kyte
April 14, 2004 - 3:22 pm UTC

ugh, the funky data model.

so flexible, yet so non-performant and inflexible to query.

If you want to see my real opinion of this - i spent a couple of pages on "why you don't want to go here" in "Effective Oracle by Design".

But here you go:


ops$tkyte@ORA9IR2> select tcn,
  2         max(decode(alias_field,'NAM',value)) nam,
  3         max(decode(alias_field,'DOB',value)) dob
  4   from test
  5   group by tcn;
 
TCN           NAM             DOB
------------- --------------- ---------------
A             JOHN            12/31/1959
B             JEN
C                             01/12/1945
D
 

Thank You

Jennifer Chen, April 14, 2004 - 8:12 pm UTC

Wow, that sounds so easy for you. I showed your response to my boss, and he was impressed. Unfortunately, he can't pay you :), but he did buy all your books for me last year.

I will read the pages you mentioned here and will try to design a better data model when I get the opportunities.

Thanks for your prompt response and help.

Can you do better

Jennifer Chen, April 20, 2004 - 12:45 pm UTC

Hi Tom,

I have a simple query that joins 6 big tables:

SQL> set autotrace traceonly
SQL> set timing on
SQL> SELECT SID, fbi, last_name || ',' || first_name || middle_name,
  2         iii_status, sex, dob, rac, iffs
  3    FROM alias.cch_person c,
  4         alias.name_index n,
  5         alias.name_dob d,
  6         alias.name_sex s,
  7         alias.name_rac r
  8   WHERE status_code = 'A'
  9     AND enter_date_time < TO_DATE ('11/11/1951 12:00', 'MM/DD/YYYY HH24:MI')
 10     AND c.mpi_number = n.mpi_number
 11     AND n.name_type_code = 'B'
 12     AND n.mpi_number = d.mpi_number
 13     AND d.mpi_number = s.mpi_number
 14     AND s.mpi_number = r.mpi_number
 15     AND d.primary_value_flag = 'Y'
 16     AND s.primary_value_flag = 'Y'
 17     AND r.primary_value_flag = 'Y'
 18   ORDER BY SID;

59451 rows selected.

Elapsed: 00:01:28.01

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=13661 Card=68056 Byt
          es=6261152)

   1    0   SORT (ORDER BY) (Cost=13661 Card=68056 Bytes=6261152)
   2    1     HASH JOIN (Cost=11092 Card=68056 Bytes=6261152)
   3    2       HASH JOIN (Cost=9673 Card=68056 Bytes=5648648)
   4    3         HASH JOIN (Cost=8269 Card=68056 Bytes=5036144)
   5    4           HASH JOIN (Cost=7007 Card=102646 Bytes=5953468)
   6    5             TABLE ACCESS (FULL) OF 'CCH_PERSON' (Cost=3058 C
          ard=81485 Bytes=2770490)

   7    5             TABLE ACCESS (FULL) OF 'NAME_INDEX' (Cost=2519 C
          ard=1516118 Bytes=36386832)

   8    4           TABLE ACCESS (FULL) OF 'NAME_DOB' (Cost=540 Card=7
          94119 Bytes=12705904)

   9    3         TABLE ACCESS (FULL) OF 'NAME_SEX' (Cost=346 Card=177
          6558 Bytes=15989022)

  10    2       TABLE ACCESS (FULL) OF 'NAME_RAC' (Cost=346 Card=17765
          58 Bytes=15989022)





Statistics
----------------------------------------------------------
          0  recursive calls
          8  db block gets
      70743  consistent gets
      55919  physical reads
          0  redo size
    3524043  bytes sent via SQL*Net to client
      44093  bytes received via SQL*Net from client
       3965  SQL*Net roundtrips to/from client
          0  sorts (memory)
          1  sorts (disk)
      59451  rows processed

I rearranged the sql, and it improved a little:

SQL> SELECT c.SID, c.fbi, n.last_name || ',' || n.first_name || n.middle_name nam,
  2         c.iii_status, s.sex, d.dob, r.rac, c.iffs
  3    FROM (SELECT /*+ INDEX_COMBINE (cch_person bix_cch_person_status) */
  4                 mpi_number, sid, fbi, iii_status, iffs
  5            FROM alias.cch_person
  6           WHERE status_code = 'A'
  7             AND enter_date_time < TO_DATE ('11/11/1951 12:00', 'MM/DD/YYYY HH24:MI')) c,
  8         (SELECT mpi_number, last_name, first_name, middle_name
  9            FROM alias.name_index
 10           WHERE name_type_code = 'B') n,
 11         (SELECT mpi_number, dob
 12            FROM alias.name_dob
 13           WHERE primary_value_flag = 'Y') d,
 14         (SELECT mpi_number, sex
 15            FROM alias.name_sex 
 16           WHERE primary_value_flag = 'Y') s,
 17         (SELECT mpi_number, rac
 18            FROM alias.name_rac 
 19           WHERE primary_value_flag = 'Y') r
 20   WHERE c.mpi_number = n.mpi_number
 21     AND n.mpi_number = d.mpi_number
 22     AND d.mpi_number = s.mpi_number
 23     AND s.mpi_number = r.mpi_number
 24   ORDER BY c.SID;

59451 rows selected.

Elapsed: 00:02:05.06

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=59072 Card=231191 By
          tes=21038381)

   1    0   SORT (ORDER BY) (Cost=59072 Card=231191 Bytes=21038381)
   2    1     HASH JOIN (Cost=45719 Card=231191 Bytes=21038381)
   3    2       HASH JOIN (Cost=43889 Card=231191 Bytes=18957662)
   4    3         HASH JOIN (Cost=42147 Card=231191 Bytes=16876943)
   5    4           TABLE ACCESS (FULL) OF 'NAME_DOB' (Cost=540 Card=7
          94119 Bytes=12705904)

   6    4           HASH JOIN (Cost=40441 Card=348694 Bytes=19875558)
   7    6             TABLE ACCESS (BY INDEX ROWID) OF 'CCH_PERSON' (C
          ost=36278 Card=276807 Bytes=9134631)

   8    7               BITMAP CONVERSION (TO ROWIDS)
   9    8                 BITMAP INDEX (SINGLE VALUE) OF 'BIX_CCH_PERS
          ON_STATUS'

  10    6             TABLE ACCESS (FULL) OF 'NAME_INDEX' (Cost=2519 C
          ard=1516118 Bytes=36386832)

  11    3         TABLE ACCESS (FULL) OF 'NAME_SEX' (Cost=346 Card=177
          6558 Bytes=15989022)

  12    2       TABLE ACCESS (FULL) OF 'NAME_RAC' (Cost=346 Card=17765
          58 Bytes=15989022)





Statistics
----------------------------------------------------------
          0  recursive calls
          8  db block gets
      66357  consistent gets
      66703  physical reads
          0  redo size
    3520345  bytes sent via SQL*Net to client
      44093  bytes received via SQL*Net from client
       3965  SQL*Net roundtrips to/from client
          0  sorts (memory)
          1  sorts (disk)
      59451  rows processed

Do you see somewhere I can improve more?

Thanks in advance. 

Tom Kyte
April 20, 2004 - 3:25 pm UTC

without tkprofs to see actuals vs guesstimates (autotrace vs reality) it is hard to say.

TKPROF

Jennifer Chen, April 20, 2004 - 4:35 pm UTC

Hi Tom,

Thank you for your time. Does this tkprof helps?

SELECT c.SID, c.fbi, n.last_name || ',' || n.first_name || n.middle_name nam,
c.iii_status, s.sex, d.dob, r.rac, c.iffs
FROM (SELECT /*+ INDEX_COMBINE (cch_person bix_cch_person_status) */
mpi_number, sid, fbi, iii_status, iffs
FROM alias.cch_person
WHERE status_code = 'A'
AND enter_date_time < TO_DATE ('11/11/1951 12:00', 'MM/DD/YYYY HH24:MI')) c,
(SELECT mpi_number, last_name, first_name, middle_name
FROM alias.name_index
WHERE name_type_code = 'B') n,
(SELECT mpi_number, dob
FROM alias.name_dob
WHERE primary_value_flag = 'Y') d,
(SELECT mpi_number, sex
FROM alias.name_sex
WHERE primary_value_flag = 'Y') s,
(SELECT mpi_number, rac
FROM alias.name_rac
WHERE primary_value_flag = 'Y') r
WHERE c.mpi_number = n.mpi_number
AND n.mpi_number = d.mpi_number
AND d.mpi_number = s.mpi_number
AND s.mpi_number = r.mpi_number
ORDER BY c.SID

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.03 0.03 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 3965 58.65 227.98 65291 66358 8 59451
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3967 58.68 228.01 65291 66358 8 59451

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61

Rows Row Source Operation
------- ---------------------------------------------------
59451 SORT ORDER BY (cr=66358 r=65291 w=11546 time=226385255 us)
59451 HASH JOIN (cr=66358 r=64812 w=11067 time=225094002 us)
59451 HASH JOIN (cr=62773 r=59307 w=9135 time=192796293 us)
59451 HASH JOIN (cr=59188 r=53862 w=7259 time=162410802 us)
1516118 TABLE ACCESS FULL NAME_DOB (cr=5602 r=5488 w=0 time=23894432 us)
59451 HASH JOIN (cr=53586 r=43047 w=1932 time=104491139 us)
59452 TABLE ACCESS BY INDEX ROWID CCH_PERSON (cr=27406 r=21590 w=0 time=51747744 us)
1516094 BITMAP CONVERSION TO ROWIDS (cr=39 r=34 w=0 time=3455108 us)
72 BITMAP INDEX SINGLE VALUE BIX_CCH_PERSON_STATUS (cr=39 r=34 w=0 time=104162 us)(object id 36212)
1516117 TABLE ACCESS FULL NAME_INDEX (cr=26180 r=19525 w=0 time=36548056 us)
1776557 TABLE ACCESS FULL NAME_SEX (cr=3585 r=3569 w=0 time=13383135 us)
1776557 TABLE ACCESS FULL NAME_RAC (cr=3585 r=3573 w=0 time=16002629 us)

********************************************************************************


Tom Kyte
April 21, 2004 - 12:04 pm UTC

the query itself runs pretty fast -- it is waits for IO most likely. I see lots of writing to temp going on there.

is your hash_area_size/pga_aggregate_target set 'really small'? what are your settings for pga workspaces?

Good questions

Jennifer Chen, April 21, 2004 - 2:53 pm UTC

Hi Tom,

Thank you for still answering questions while you are at IOUG in Toronto. Your questions led me to find out the Metalink note 223730.1 (Automatic PGA Memory Management in 9i). That was very helpful.

My workarea_size_policy was set to AUTO and pga_aggregate_target was set to 40M. In that note, it states:
“Oracle does not recommend using the HASH_AREA_SIZE parameter unless the instance is configured with the shared server option. Oracle recommends that you enable automatic sizing of SQL working areas by setting PGA_AGGREGATE_TARGET instead. HASH_AREA_SIZE is retained for backward compatibility.”
I have bumped up pga_aggregate_target from 40M to 100M, and the sort for the query now occurs in the memory:

SQL> SELECT c.SID, c.fbi, n.last_name || ',' || n.first_name || n.middle_name nam,
  2         c.iii_status, s.sex, d.dob, r.rac, c.iffs
  3    FROM (SELECT /*+ INDEX_COMBINE (cch_person bix_cch_person_status) */
  4                 mpi_number, sid, fbi, iii_status, iffs
  5            FROM alias.cch_person
  6           WHERE status_code = 'A'
  7             AND enter_date_time < TO_DATE ('11/11/1951 12:00', 'MM/DD/YYYY HH24:MI')) c,
  8         (SELECT mpi_number, last_name, first_name, middle_name
  9            FROM alias.name_index
 10           WHERE name_type_code = 'B') n,
 11         (SELECT mpi_number, dob
 12            FROM alias.name_dob
 13           WHERE primary_value_flag = 'Y') d,
 14         (SELECT mpi_number, sex
 15            FROM alias.name_sex 
 16            WHERE primary_value_flag = 'Y') s,
 17         (SELECT mpi_number, rac
 18            FROM alias.name_rac 
 19           WHERE primary_value_flag = 'Y') r
 20   WHERE c.mpi_number = n.mpi_number
 21     AND n.mpi_number = d.mpi_number
 22     AND d.mpi_number = s.mpi_number
 23     AND s.mpi_number = r.mpi_number
 24   ORDER BY c.SID;

59450 rows selected.

Elapsed: 00:01:55.08

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=26197 Card=185404 By
          tes=18169592)

   1    0   SORT (ORDER BY) (Cost=26197 Card=185404 Bytes=18169592)
   2    1     HASH JOIN (Cost=23326 Card=185404 Bytes=18169592)
   3    2       HASH JOIN (Cost=22128 Card=185404 Bytes=16500956)
   4    3         HASH JOIN (Cost=20955 Card=185404 Bytes=14832320)
   5    4           HASH JOIN (Cost=19754 Card=279635 Bytes=17896640)
   6    5             TABLE ACCESS (BY INDEX ROWID) OF 'CCH_PERSON' (C
          ost=15614 Card=221985 Bytes=8879400)

   7    6               BITMAP CONVERSION (TO ROWIDS)
   8    7                 BITMAP INDEX (SINGLE VALUE) OF 'BIX_CCH_PERS
          ON_STATUS'

   9    5             TABLE ACCESS (FULL) OF 'NAME_INDEX' (Cost=2519 C
          ard=1516118 Bytes=36386832)

  10    4           TABLE ACCESS (FULL) OF 'NAME_DOB' (Cost=540 Card=7
          94119 Bytes=12705904)

  11    3         TABLE ACCESS (FULL) OF 'NAME_SEX' (Cost=346 Card=177
          6558 Bytes=15989022)

  12    2       TABLE ACCESS (FULL) OF 'NAME_RAC' (Cost=346 Card=17765
          58 Bytes=15989022)





Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
      66359  consistent gets
      55831  physical reads
          0  redo size
    3520301  bytes sent via SQL*Net to client
      44092  bytes received via SQL*Net from client
       3965  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      59450  rows processed

The new tkprof is:

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch     3965     55.48     212.10      55348      66359          0       59450
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     3967     55.51     212.13      55348      66359          0       59450

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61  



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.03       0.02          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch     3965     55.48     212.10      55348      66359          0       59450
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     3968     55.51     212.13      55348      66359          0       59450

Misses in library cache during parse: 1

Any additional comments? Thanks again for your responses. Really appreciate your time and help. 

Tom Kyte
April 21, 2004 - 9:11 pm UTC

lets see the stat records from the tkprof (with the cr= and such)...

Sorry, I didn't get it

Jennifer Chen, April 22, 2004 - 1:39 pm UTC

Hi Tom,

I am confused. Did you mean that I should run tkprof with option cr=....?

I didn't see tkprof provides that option. I run tkprof with option explain=...

Is that what you would like to see?

Thank you.

SELECT c.SID, c.fbi, n.last_name || ',' || n.first_name || n.middle_name nam,
c.iii_status, s.sex, d.dob, r.rac, c.iffs
FROM (SELECT /*+ INDEX_COMBINE (cch_person bix_cch_person_status) */
mpi_number, sid, fbi, iii_status, iffs
FROM alias.cch_person
WHERE status_code = 'A'
AND enter_date_time < TO_DATE ('11/11/1951 12:00', 'MM/DD/YYYY HH24:MI')) c,
(SELECT mpi_number, last_name, first_name, middle_name
FROM alias.name_index
WHERE name_type_code = 'B') n,
(SELECT mpi_number, dob
FROM alias.name_dob
WHERE primary_value_flag = 'Y') d,
(SELECT mpi_number, sex
FROM alias.name_sex
WHERE primary_value_flag = 'Y') s,
(SELECT mpi_number, rac
FROM alias.name_rac
WHERE primary_value_flag = 'Y') r
WHERE c.mpi_number = n.mpi_number
AND n.mpi_number = d.mpi_number
AND d.mpi_number = s.mpi_number
AND s.mpi_number = r.mpi_number
ORDER BY c.SID

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.03 0.02 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 3965 55.59 177.47 66826 67207 0 59450
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3967 55.62 177.50 66826 67207 0 59450

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 61 (ALIAS)

Rows Row Source Operation
------- ---------------------------------------------------
59450 SORT ORDER BY (cr=67207 r=66826 w=2730 time=175966470 us)
59450 HASH JOIN (cr=67207 r=66826 w=2730 time=173988156 us)
59450 HASH JOIN (cr=63622 r=62665 w=1710 time=146075237 us)
59450 HASH JOIN (cr=60037 r=58594 w=780 time=119320772 us)
59450 HASH JOIN (cr=54435 r=52785 w=135 time=92194054 us)
59451 TABLE ACCESS BY INDEX ROWID CCH_PERSON (cr=27407 r=27377 w=0 time=45900691 us)
1516093 BITMAP CONVERSION TO ROWIDS (cr=40 r=40 w=0 time=4613420 us)
72 BITMAP INDEX SINGLE VALUE BIX_CCH_PERSON_STATUS (cr=40 r=40 w=0 time=140011 us)(object id 36212)
1516116 TABLE ACCESS FULL NAME_INDEX (cr=27028 r=25273 w=0 time=34664686 us)
1516117 TABLE ACCESS FULL NAME_DOB (cr=5602 r=5164 w=0 time=8303261 us)
1776556 TABLE ACCESS FULL NAME_SEX (cr=3585 r=3141 w=0 time=11572124 us)
1776556 TABLE ACCESS FULL NAME_RAC (cr=3585 r=3141 w=0 time=10345249 us)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
59450 SORT (ORDER BY)
59450 HASH JOIN
59450 HASH JOIN
59450 HASH JOIN
59450 HASH JOIN
59451 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'CCH_PERSON'
1516093 BITMAP CONVERSION (TO ROWIDS)
72 BITMAP INDEX (SINGLE VALUE) OF
'BIX_CCH_PERSON_STATUS'
1516116 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'NAME_INDEX'
1516117 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'NAME_DOB'
1776556 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'NAME_SEX'
1776556 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'NAME_RAC'

********************************************************************************

alter session set sql_trace=false


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 61 (ALIAS)



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3 0.03 0.02 0 0 0 0
Execute 5 0.00 0.00 0 0 0 0
Fetch 3965 55.59 177.47 66826 67207 0 59450
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3973 55.62 177.50 66826 67207 0 59450

Misses in library cache during parse: 2


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 0 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 0 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0

5 user SQL statements in session.
0 internal SQL statements in session.
5 SQL statements in session.
1 statement EXPLAINed in this session.
********************************************************************************
Trace file: aliasdev_ora_4072.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
5 user SQL statements in trace file.
0 internal SQL statements in trace file.
5 SQL statements in trace file.
4 unique SQL statements in trace file.
1 SQL statements EXPLAINed using schema:
ALIAS.prof$plan_table
Default table was used.
Table was created.
Table was dropped.
4051 lines in trace file.

Tom Kyte
April 23, 2004 - 8:47 am UTC

no, tkprof provides the cr= statistics:

59450 SORT ORDER BY (cr=67207 r=66826 w=2730 time=175966470 us)
^^^^^^^^ consistent reads
^^^^^^ shows temp is still used
^^^^^^^ shows lots of physical IO

as compared to the original:

59451 SORT ORDER BY (cr=66358 r=65291 w=11546 time=226385255 us)

it is better for temp usage and some 50 seconds faster, but the physical IO is the last barrier. You have lots of stuff like this:

(SELECT mpi_number, rac
FROM alias.name_rac
WHERE primary_value_flag = 'Y') r

and that is going to be hard to get around (looks like a "data model issue" in some regards. I would prefer to keep "primary data" as attributes of the parent record itself and normalize out historical or secondary values in the detail table like this -- eg: primary_value_flag would not exist, DOB would be an attribute of cch_person directly -- in fact, does anyone really have a "non primary DOB"?)

Anyway, try this:

select c.sid, c.fbi,
(select n.last_name || ',' || n.first_name || n.middle_name nam
from alias.name_index
where name_type_code = 'B'
and mpi_number = c.mpi_number ) name,
c.iii_status,
(select sex
from alias.name_sex
where primary_value_flag='Y'
and mpi_number = c.mpi_number ) sex,
(select dob
from alias.name_dob
where primary_value_flag = 'Y'
and mpi_number = c.mpi_number ) dob,
(select rac
from alias.name_rac
where primary_value_flag = 'Y'
and mpi_number = c.mpi_number ) rac,
c.iffs
from alias.cch_person
where status_code = 'A'
and enter_date_time < TO_DATE ('11/11/1951 12:00', 'MM/DD/YYYY HH24:MI')


assuming indexes of the form

name_rac(mpi_number,primary_value_flag,name_rac)

on each of the detail tables (and assuming the mpi_number,primary_value is in fact the PRIMARY KEY of the detail table), you *might* find that to be better (it'll get the first rows faster for sure)

sql tuning

k.Venkat, April 28, 2004 - 4:15 am UTC

Tom,

We have a query against a view. The tkprof report of the query and also the
query related to the view generation is given below: The LIOs are high. How we
can decrease the LIOs and improve the performance time? Give your guidance.

TKPROF report on the query against the view:

SELECT APPLICATIONID,
ID,
FIRSTNAME,
LASTNAME,
EMAIL,
PHONE,
CREATEDON,
Taskid,
Queueid,
Workitemid,
Itemtypeid
FROM loscd.OCR_APP_LIST_VIEW_NEW
WHERE TaskId = 301 AND QueueId = 145
ORDER BY APPLICATIONID

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.04 0.05 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 268 0.46 0.48 0 20419 0 4000
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 270 0.50 0.54 0 20419 0 4000

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 64

Rows Row Source Operation
------- ---------------------------------------------------
4000 SORT ORDER BY
4000 NESTED LOOPS
4000 NESTED LOOPS
4000 HASH JOIN
4000 HASH JOIN
4000 TABLE ACCESS BY INDEX ROWID OW_WORKITEM_INSTANCE
4000 INDEX RANGE SCAN IDX_NU_TID_QID (object id 19609)
52565 TABLE ACCESS FULL OW_WORKITEM
11042 TABLE ACCESS FULL OCR_CREDIT_WORKFLOW_MAP
4000 TABLE ACCESS BY INDEX ROWID OCR_PTA_WB
4000 INDEX RANGE SCAN IDX_OCR_PTA_WB (object id 23181)
4000 TABLE ACCESS BY INDEX ROWID OCR_APPL_WB
4000 INDEX UNIQUE SCAN CLOS_APPL_WB_PK (object id 23117)

************************************************************

TKPROF report of the query on the view generation:

SELECT A.APP_ID
APPLICATIONID,
A.FIRST_NAME FIRSTNAME,
A.LAST_NAME LASTNAME,
B.WORKITEMID ID,
A.EMAIL EMAIL,
A.MOBILE_PHONE PHONE,
TO_CHAR(E.MAKER_DATE, 'DD-MON-YYYY') CREATEDON,
C.WORKITEMID WORKITEMID,
B.TASKID TASKID,
B.QUEUEID QUEUEID,
C.ITEMTYPEID ITEMTYPEID,
B.STATUS STATUS
FROM OCR_PTA_WB A,
OW_WORKITEM_INSTANCE B,
OW_WORKITEM C,
OCR_CREDIT_WORKFLOW_MAP D,
OCR_APPL_WB E
WHERE B.WORKITEMID = C.WORKITEMID AND
A.APP_ID = D.ID_NO AND
A.APP_ID = E.APP_ID AND
B.WORKITEMID= C.WORKITEMID AND
C.WORKITEMID = D.WORK_ITEM_ID AND
D.ID_TYPE = 'A' AND A.ROLE_CODE='A'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.02 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 737 1.48 4.06 242 58642 0 11033
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 739 1.50 4.08 242 58642 0 11033

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 64

Rows Row Source Operation
------- ---------------------------------------------------
11033 NESTED LOOPS
11033 NESTED LOOPS
11041 HASH JOIN
11042 HASH JOIN
11042 TABLE ACCESS FULL OCR_CREDIT_WORKFLOW_MAP
52565 TABLE ACCESS FULL OW_WORKITEM
23045 TABLE ACCESS FULL OW_WORKITEM_INSTANCE
11033 TABLE ACCESS BY INDEX ROWID OCR_PTA_WB
11033 INDEX RANGE SCAN IDX_OCR_PTA_WB (object id 23181)
11033 TABLE ACCESS BY INDEX ROWID OCR_APPL_WB
11033 INDEX UNIQUE SCAN CLOS_APPL_WB_PK (object id 23117)

************************************************************

Thanks,
Venkat


Constant in the join ?

Hector Gabriel Ulloa Ligarius, May 06, 2004 - 10:55 am UTC

Hi Tom ...

  How are you?


  I have seen a consultation that has in its body the following thing:

    select <fields_a,fields_b>
      from <table_a,table_b>
     where <table_a.fields_a> = <table_b.fields_b>
       and var_dato1 = <number>
       ;

  In the declare section

     declare
        var_Dato1 number;
       .
       .
       .

  The question...

   Is better , extract the line
     and var_dato1 = <number> and to place it in if

        if var_dato1 = <number> then

          select <fields_a,fields_b>
            from <table_a,table_b>
           where <table_a.fields_a> = <table_b.fields_b>


  In the explain : 

SQL> create table ulloa as select * from user_objects;

Table created.

SQL> select count(*) from ulloa;

 COUNT(*)
---------
     3523

SQL> create table ulloa2 as select * from user_objects where rownum < 1001;

Table created.

SQL> select count(*) from ulloa2;

 COUNT(*)
---------
     1000

SQL> set autotrace traceonly exp

SQL> select a.* , b.* from ulloa a , ulloa2 b where a.object_name = b.object_name;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE
   1    0   MERGE JOIN
   2    1     SORT (JOIN)
   3    2       TABLE ACCESS (FULL) OF 'ULLOA2'
   4    1     SORT (JOIN)
   5    4       TABLE ACCESS (FULL) OF 'ULLOA'

SQL> var var_dato1 number;

SQL>  select a.* , b.* from ulloa a , ulloa2 b where a.object_name = b.object_name and :var_dato1 = 0
SQL> /

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE
   1    0   FILTER
   2    1     MERGE JOIN
   3    2       SORT (JOIN)
   4    3         TABLE ACCESS (FULL) OF 'ULLOA2'
   5    2       SORT (JOIN)
   6    5         TABLE ACCESS (FULL) OF 'ULLOA'

SQL> 


The step FILTER is very EXPENSIVE??

 More expensive in the select or in the if?


  Some suggestions?


  Thank you again Tom Kyte..

 Regards

 Hector Ulloa Ligarius

     

Tom Kyte
May 06, 2004 - 1:58 pm UTC

if I had this

select <fields_a,fields_b>
from <table_a,table_b>
where <table_a.fields_a> = <table_b.fields_b>
and var_dato1 = <number>
;

and i was writing code, i would definitely code the if (var_dato1 = number) instead of doing it in the query like that.


the best way to speed up something -- is to not do it.

Constant in the Join?

Hector Gabriel Ulloa Ligarius, May 07, 2004 - 8:53 am UTC

Muchas gracias Tom

Regards

Hector Ulloa Ligarius


q on query!

A reader, May 26, 2004 - 9:04 pm UTC

Hi Tom
Quick question:
Consider the following schema and the final query
(at the end):
-------
scott@ORA10G> drop table c1;

Table dropped.

scott@ORA10G> drop table c2;

Table dropped.

scott@ORA10G> drop table p1;

Table dropped.

scott@ORA10G>
scott@ORA10G> create table p1
2 (
3 x varchar2(10) primary key
4 );

Table created.

scott@ORA10G>
scott@ORA10G> create table c1
2 (
3 x varchar2(10) references p1,
4 y int
5 );

Table created.

scott@ORA10G>
scott@ORA10G> create table c2
2 (
3 x varchar2(10) references p1,
4 y int
5 );

Table created.

scott@ORA10G>
scott@ORA10G> insert into p1 values( 'x1');

1 row created.

scott@ORA10G> insert into p1 values( 'x2');

1 row created.

scott@ORA10G>
scott@ORA10G> insert into c1 values( 'x1', 1);

1 row created.

scott@ORA10G> insert into c1 values( 'x1', 2);

1 row created.

scott@ORA10G> insert into c1 values( 'x2', 2);

1 row created.

scott@ORA10G>
scott@ORA10G> insert into c2 values( 'x1', 5);

1 row created.

scott@ORA10G> insert into c2 values( 'x1', 6);

1 row created.

scott@ORA10G> insert into c2 values( 'x2', 7);

1 row created.

scott@ORA10G>
scott@ORA10G> prompt p1 data
p1 data
scott@ORA10G> select * from p1;

X
----------
x1
x2

scott@ORA10G> prompt c1 data
c1 data
scott@ORA10G> select * from c1;

X Y
---------- ----------
x1 1
x1 2
x2 2

scott@ORA10G> prompt c2 data
c2 data
scott@ORA10G> select * from c2;

X Y
---------- ----------
x1 5
x1 6
x2 7

scott@ORA10G>
scott@ORA10G> prompt final query result
final query result
scott@ORA10G> select c1_y_sum, c2_y_sum
2 from
3 (
4 select c1.x c1x, sum(c1.y) c1_y_sum
5 from p1, c1
6 where p1.x = c1.x
7 group by c1.x
8 ),
9 (
10 select c2.x c2_x, sum(c2.y) c2_y_sum
11 from p1, c2
12 where p1.x = c2.x
13 group by c2.x
14 ) ;

C1_Y_SUM C2_Y_SUM
---------- ----------
3 11
3 7
2 11
2 7
---------------

Is there any other way to get the sums that I get in
the final query. In this case we have only 2 table joins
in each sub select - but consider the case
when we are joining with multiple tables as:

select c1.x c1x, sum(c1.y) c1_y_sum
from p1, p2, c1

in the first sub select and

select c2.x c2_x, sum(c2.y) c2_y_sum
from p1, p2, c2

in the second sub select. Would you have
written it in the same way or can we do some
kind of "refactoring" to optimize the query. (Since
joining to p1, p2 etc is being repeated.)

I hope I am making sense!

My hunch is that optimizer takes care of it but
I wanted to get your opinion.
Thanx!



Tom Kyte
May 27, 2004 - 8:53 am UTC

well, i would say in this case the join to P1 is not even necessary or desired. A simple "where x is not null" is more than sufficient since if x is not null, we know x must be in p1 and since x is unique in p1, it is in there at most once. so a simple

scott@ORA10G> select c1_y_sum, c2_y_sum
2 from
3 (
4 select c1.x c1x, sum(c1.y) c1_y_sum
5 from c1
6 where c1.x is not null
8 ),
9 (
10 select c2.x c2_x, sum(c2.y) c2_y_sum
11 from c2
12 where c2.x is not null
14 ) ;


would do. Now, in the more general case

p1,p2,c1

p1,p2,c2


what if c1 is small -- the join might be:

c1 nested loops p2 nested loops p1
resulting in 5 rows from c1, getting 20 rows from p2 getting 20 rows from p1

and c2 is big -- the join might be:

p1 hash join p2 hash join c2
every row in p1 with every row in p2


Now, if we tried to "reuse" p1 X p2, we'd have to pick the "bigger" one, that would not be good for the first query.


or consider both c1 and c2 are "small" c1 has numbers 1..100, c2 has numbers 500..600.

c1 will get an entirely DIFFERENT set of rows from p1Xp2 than c2 will get. It would be horribly inefficient to generate p1Xp2 here and then have c1/c2 join to it. we would use c1/c2 to *drive* into p2/p1 and pick up just the rows we need for each.

don't attribute procedural logic to SQL (sets, think in sets). The p1Xp2 isn't constant for each of the subqueries.



thanx Tom!

A reader, May 27, 2004 - 12:48 pm UTC

"well, i would say in this case the join to P1 is not even necessary or desired.
A simple "where x is not null" is more than sufficient since if x is not null,
we know x must be in p1 and since x is unique in p1, it is in there at most
once."

Aha - I guess I would not have thought of that!
However, in my actual case this is not true - we just
have bunch of tables with foreign key linkage.
The two "sub queries" have some commonality of tables with
only one table being different.

1. Does that change your answer in any way - would you want
to add some more thoughts?

"what if c1 is small -- the join might be:

c1 nested loops p2 nested loops p1
resulting in 5 rows from c1, getting 20 rows from p2 getting 20 rows from p1

and c2 is big -- the join might be:

p1 hash join p2 hash join c2
every row in p1 with every row in p2


Now, if we tried to "reuse" p1 X p2, we'd have to pick the "bigger" one, that
would not be good for the first query.
"

2. I think what you are saying is that it would be optimal
to separately join (like I did) in this case because
CBO gets a chance to optimize each separately
and then combine the results - correct?

3. I did not quite understand what you mean by "you would have to pick the bigger one"? what is the "bigger one" and
why do you have to pick it?:)

4. This is unrelated to the above question. Just
curious how much time you spend daily answering
questions on asktom?
Thanx Tom!!


Tom Kyte
May 27, 2004 - 8:25 pm UTC

1) i did -- p1 x p2 isn't a "constant" here -- the choice of c1 or c2 defintely and materially affect the processing.

2) dead on

3) in the case i was using -- we had a "small p1xp2" and a "big p1xp2", the small one would not work when we needed big so big would have to be used for both -- suboptimal

4) too much is what I hear.

thanx!

A reader, May 27, 2004 - 9:19 pm UTC

"too much is what I hear"
not sure what to make of that - anyways
thank you so much - I learn at least one
new thing every day from your site!

Need your help on this sql tuning

Jennifer Chen, June 01, 2004 - 11:37 am UTC

Hi Tom,

I have tables cch_person and incident, which are one to many related by pid_number. One person could have many incidents. I need to retrieve all person records where only one active incident is associated withe the person. Here is what I wrote:

SELECT i1.pid_number, i1.inc_number, c.SID, c.fbi, i1.ctn, i1.tcn, i1.oca
FROM alias.cch_person c, alias.incident i1
WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
AND c.prn IS NULL
AND c.status_code = 'A'
AND i1.status_code = 'A'
AND i1.pid_number = c.pid_number
AND i1.pid_number IN (SELECT /*+ CARDINALITY(I2 895637 ) */
i2.pid_number
FROM alias.incident i2
WHERE i2.pid_number = i1.pid_number
GROUP BY i2.pid_number
HAVING COUNT (i2.pid_number) = 1);

1. Do you have more efficient way for this query?
2. Should I use /*+ CARDINALITY(I2 895637 ) */ hint there? I saw the consistent gets were reduced from the explain plan, but not sure how it works after table grows.

Thanks so much for your help.

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=150276 Card=47125 By
tes=2921750)

1 0 FILTER
2 1 HASH JOIN (Cost=8901 Card=47125 Bytes=2921750)
3 2 TABLE ACCESS (FULL) OF 'INCIDENT' (Cost=5560 Card=4712
5 Bytes=1555125)

4 2 TABLE ACCESS (FULL) OF 'CCH_PERSON' (Cost=3107 Card=32
2486 Bytes=9352094)

5 1 FILTER
6 5 SORT (GROUP BY NOSORT) (Cost=3 Card=1 Bytes=6)
7 6 INDEX (RANGE SCAN) OF 'PK_INCIDENT' (UNIQUE) (Cost=3
Card=895637 Bytes=5373822)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
3565186 consistent gets
102387 physical reads
0 redo size
38217881 bytes sent via SQL*Net to client
500064 bytes received via SQL*Net from client
45417 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
681228 rows processed



Tom Kyte
June 01, 2004 - 3:18 pm UTC

lose the hint (statistics would be supplying that already) but give analytics a try:

select *
from (
SELECT i1.pid_number, i1.inc_number, c.SID, c.fbi, i1.ctn, i1.tcn, i1.oca,
count(*) over (partition by i1.pid_number) cnt
FROM alias.cch_person c, alias.incident i1
WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
AND c.prn IS NULL
AND c.status_code = 'A'
AND i1.status_code = 'A'
AND i1.pid_number = c.pid_number
)
where cnt = 1


or

SELECT i1.pid_number, i1.inc_number, c.SID, c.fbi, i1.ctn, i1.tcn, i1.oca,
from ( select *
from ( SELECT i1.pid_number, i1.inc_number, i1.ctn, i1.tcn, i1.oca,
count(*) over (partition by i1.pid_number) cnt
FROM alias.incident i1
WHERE i1.status_code = 'A'
)
where cnt = 1 ) il,
alias.cch_person c
WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
AND c.prn IS NULL
AND c.status_code = 'A'
AND i1.pid_number = c.pid_number



Thank You!!!

Jennifer Chen, June 01, 2004 - 4:50 pm UTC

Hi Tom,

Many, many thanks! Your sql reduced consistent gets dramatically (See below), but I haven't figured out why the number of rows processed is different. I am not familiar with analytics. Did you have more examples somewhere?

Thanks again for your help.

SQL> select * 
  2    from (
  3  SELECT i1.pid_number, i1.inc_number, c.SID, c.fbi, i1.ctn, i1.tcn, i1.oca,
  4         count(*) over (partition by i1.pid_number) cnt
  5    FROM alias.cch_person c, alias.incident i1
  6   WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
  7     AND c.prn IS NULL
  8     AND c.status_code = 'A'
  9     AND i1.status_code = 'A'
 10     AND i1.pid_number = c.pid_number
 11         )
 12   where cnt = 1
 13  ;

681234 rows selected.

Elapsed: 00:03:45.09

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=14900 Card=384006 By
          tes=31104486)

   1    0   VIEW (Cost=14900 Card=384006 Bytes=31104486)
   2    1     WINDOW (SORT) (Cost=14900 Card=384006 Bytes=23808372)
   3    2       HASH JOIN (Cost=10919 Card=384006 Bytes=23808372)
   4    3         TABLE ACCESS (FULL) OF 'CCH_PERSON' (Cost=3107 Card=
          322486 Bytes=9352094)

   5    3         TABLE ACCESS (FULL) OF 'INCIDENT' (Cost=5560 Card=94
          2506 Bytes=31102698)





Statistics
----------------------------------------------------------
          0  recursive calls
         52  db block gets
      90107  consistent gets
     155635  physical reads
          0  redo size
   35966755  bytes sent via SQL*Net to client
     500064  bytes received via SQL*Net from client
      45417  SQL*Net roundtrips to/from client
          0  sorts (memory)
          1  sorts (disk)
     681234  rows processed

SQL> SELECT i1.pid_number, i1.inc_number, c.SID, c.fbi, i1.ctn, i1.tcn, i1.oca
  2    FROM alias.cch_person c, alias.incident i1
  3   WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
  4     AND c.prn IS NULL
  5     AND c.status_code = 'A'
  6     AND i1.status_code = 'A'
  7     AND i1.pid_number = c.pid_number
  8     AND i1.pid_number IN (SELECT   /*+ CARDINALITY(I2 895637 ) */
  9                                    i2.pid_number
 10                               FROM alias.incident i2
 11                              WHERE i2.pid_number = i1.pid_number
 12                           GROUP BY i2.pid_number
 13                             HAVING COUNT (i2.pid_number) = 1);

681228 rows selected.

Elapsed: 00:03:01.05

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=150276 Card=47125 By
          tes=2921750)

   1    0   FILTER
   2    1     HASH JOIN (Cost=8901 Card=47125 Bytes=2921750)
   3    2       TABLE ACCESS (FULL) OF 'INCIDENT' (Cost=5560 Card=4712
          5 Bytes=1555125)

   4    2       TABLE ACCESS (FULL) OF 'CCH_PERSON' (Cost=3107 Card=32
          2486 Bytes=9352094)

   5    1     FILTER
   6    5       SORT (GROUP BY NOSORT) (Cost=3 Card=1 Bytes=6)
   7    6         INDEX (RANGE SCAN) OF 'PK_INCIDENT' (UNIQUE) (Cost=3
           Card=895637 Bytes=5373822)





Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
    3568464  consistent gets
     129619  physical reads
          0  redo size
   38211744  bytes sent via SQL*Net to client
     500064  bytes received via SQL*Net from client
      45417  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
     681228  rows processed 

Tom Kyte
June 01, 2004 - 5:17 pm UTC

ahh, you filter out people who have an ACTIVE and <any other status record>


  8     AND i1.pid_number IN (SELECT   /*+ CARDINALITY(I2 895637 ) */
  9                                    i2.pid_number
 10                               FROM alias.incident i2
 11                              WHERE i2.pid_number = i1.pid_number
 12                           GROUP BY i2.pid_number
 13                             HAVING COUNT (i2.pid_number) = 1);


You didn't have a predicate on status_code in there.  I took:

...
I need to retrieve all person 
records where only one active incident is associated withe the person.
......

literally.  

If you meant "only one ACTIVE incident", then my query is right and your query is missing them.  

If you meant "only one incident (regardless of status)", then my query is 'wrong' (but easy to fix) and your query is right.


SQL> select * 
  2    from (
  3  SELECT i1.pid_number, i1.inc_number, c.SID, c.fbi, i1.ctn, i1.tcn, i1.oca,
  4         count(*) over (partition by i1.pid_number) cnt, i1.status_code
  5    FROM alias.cch_person c, alias.incident i1
  6   WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
  7     AND c.prn IS NULL
  8     AND c.status_code = 'A'

 10     AND i1.pid_number = c.pid_number
 11         )
 12   where cnt = 1 and status_code = 'A'
 13  ;


just need to move the predicate on status_code to after the analytics.


Tons of examples on this site (search for:

analytics rock roll

) or I have a chapter on them in Expert one on one Oracle if you have access to that book. 

T H A N K Y O U

Jennifer Chen, June 01, 2004 - 8:26 pm UTC

Hi Tom,

That explains. Your code works well either way. Thank you so, so very much. I will find time to read more about analytics...

Again, thank you for teaching us.

Tom Kyte
June 02, 2004 - 7:35 am UTC

Oh, also try:


SELECT i1.pid_number, max(i1.inc_number), max(c.SID),
max(c.fbi), max(i1.ctn), max(i1.tcn), max(i1.oca)
FROM alias.cch_person c, alias.incident i1
WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
AND c.prn IS NULL
AND c.status_code = 'A'
AND i1.status_code = 'A'
AND i1.pid_number = c.pid_number
GROUP BY i1.pid_number
having count(*) = 1

or

SELECT i1.pid_number, max(i1.inc_number), max(c.SID),
max(c.fbi), max(i1.ctn), max(i1.tcn), max(i1.oca)
FROM alias.cch_person c, alias.incident i1
WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
AND c.prn IS NULL
AND c.status_code = 'A'
AND i1.pid_number = c.pid_number
GROUP BY i1.pid_number
having count(*) = 1 and max(status_code) = 'A'



It is even faster

Jennifer Chen, June 02, 2004 - 4:40 pm UTC

Hi Tom,

It is indeed faster compared to using the analytics way. They both speed up my stored procedure 70%:

SQL> SELECT *
  2                    FROM (SELECT i.pid_number, i.inc_number, c.SID, c.fbi,
  3                                 i.ctn, i.tcn, i.oca,
  4                                 COUNT (*) OVER (PARTITION BY i.pid_number) cnt,
  5                                 i.status_code
  6                            FROM alias.cch_person c, alias.incident i
  7                           WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL
  8                                 )
  9                             AND c.prn IS NULL
 10                             AND c.status_code = 'A'
 11                             AND i.status_code = 'A'
 12                             AND i.pid_number = c.pid_number)
 13                   WHERE cnt = 1;

681235 rows selected.

Elapsed: 00:04:37.02

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=14900 Card=384006 By
          tes=32256504)

   1    0   VIEW (Cost=14900 Card=384006 Bytes=32256504)
   2    1     WINDOW (SORT) (Cost=14900 Card=384006 Bytes=23808372)
   3    2       HASH JOIN (Cost=10919 Card=384006 Bytes=23808372)
   4    3         TABLE ACCESS (FULL) OF 'CCH_PERSON' (Cost=3107 Card=
          322486 Bytes=9352094)

   5    3         TABLE ACCESS (FULL) OF 'INCIDENT' (Cost=5560 Card=94
          2506 Bytes=31102698)





Statistics
----------------------------------------------------------
          0  recursive calls
         59  db block gets
      90107  consistent gets
     152491  physical reads
          0  redo size
   36648088  bytes sent via SQL*Net to client
     500064  bytes received via SQL*Net from client
      45417  SQL*Net roundtrips to/from client
          0  sorts (memory)
          1  sorts (disk)
     681235  rows processed


SQL> SELECT i.pid_number, max(i.inc_number), max(c.SID), 
  2         max(c.fbi), max(i.ctn), max(i.tcn), max(i.oca)
  3    FROM alias.cch_person c, alias.incident i
  4   WHERE (c.iii_status != 'MSO' OR c.iii_status IS NULL)
  5     AND c.prn IS NULL
  6     AND c.status_code = 'A'
  7     AND i.status_code = 'A'
  8     AND i.pid_number = c.pid_number
  9   GROUP BY i.pid_number
 10  HAVING COUNT(*) = 1;

681235 rows selected.

Elapsed: 00:03:15.01

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=13062 Card=3841 Byte
          s=238142)

   1    0   FILTER
   2    1     SORT (GROUP BY) (Cost=13062 Card=3841 Bytes=238142)
   3    2       HASH JOIN (Cost=10919 Card=384006 Bytes=23808372)
   4    3         TABLE ACCESS (FULL) OF 'CCH_PERSON' (Cost=3107 Card=
          322486 Bytes=9352094)

   5    3         TABLE ACCESS (FULL) OF 'INCIDENT' (Cost=5560 Card=94
          2506 Bytes=31102698)





Statistics
----------------------------------------------------------
          0  recursive calls
         44  db block gets
      90107  consistent gets
     119023  physical reads
          0  redo size
   35966781  bytes sent via SQL*Net to client
     500064  bytes received via SQL*Net from client
      45417  SQL*Net roundtrips to/from client
          0  sorts (memory)
          1  sorts (disk)
     681235  rows processed

Thank you for your dedication and excellence! 

Query with ROWNUM

Tony, June 07, 2004 - 4:24 pm UTC

Hi Tom,
Thanks a lot for your precious comments,

I have a query which is taking about 2 minutes on a one million rows table. The query is straight forward I mean no joins etc.

select * from ( select -----.....----- from PART_t L where 1 = 1 AND L.d_code = 'XYZ' AND L.carrier_id =
'ABC' AND L.PART_TYP = '2' AND L.DIS_STA = 5230 order by L.PART_ID desc ) where
rownum <= 15;


The explain plan shows that it's using the index(on d_code,carrier_id,part_typ columns) on the part_t.

If I use first_rows hint then this query comes backs in fraction of a sec but the cost is very high with hint and it uses the primary key index (on PART_ID ).

Here are the results :

WITH first_rows Hint:

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=HINT: FIRST_ROWS (Cost=33797 Card
=1409 Bytes=1875379)

1 0 COUNT (STOPKEY)
2 1 VIEW (Cost=33797 Card=1409 Bytes=1875379)
3 2 TABLE ACCESS (BY INDEX ROWID) OF PART_T' (Cost=3379
7 Card=1409 Bytes=481878)

4 3 INDEX (FULL SCAN DESCENDING) OF 'PK_PART' (UNIQUE)
(Cost=2490 Card=1409)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
35 consistent gets
21 physical reads
0 redo size
14049 bytes sent via SQL*Net to client
1713 bytes received via SQL*Net from client
3 SQL*Net roundtrips to/from client
2 sorts (memory)
0 sorts (disk)
18 rows processed


WITHOUT hint:

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=178 Card=1409 Bytes
1875379)

1 0 COUNT (STOPKEY)
2 1 VIEW (Cost=178 Card=1409 Bytes=1875379)
3 2 SORT (ORDER BY STOPKEY) (Cost=178 Card=1409 Bytes=481
78)

4 3 TABLE ACCESS (BY INDEX ROWID) OF 'PART_T' (Cost=1
6 Card=1409 Bytes=481878)

5 4 INDEX (RANGE SCAN) OF 'PART_I7' (NON-UNIQUE) (C
st=12 Card=1409)





Statistics
----------------------------------------------------------
0 recursive calls
6 db block gets
55744 consistent gets
55748 physical reads
0 redo size
14049 bytes sent via SQL*Net to client
1695 bytes received via SQL*Net from client
3 SQL*Net roundtrips to/from client
2 sorts (memory)
1 sorts (disk)
18 rows processed

Now if I change the query little bit i.e. by taking rownum from outer query and putting it in the inner query, the results are very fast again:

select * from ( select -----.....----- from PART_t L where 1 = 1 AND L.d_code = 'XYZ' AND L.carrier_id =
'ABC' AND L.PART_TYP = '2' AND L.DIS_STA = 5230
AND ROWNUM <= 15order by L.PART_ID desc ) ;

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=178 Card=1409 Bytes=
1875379)

1 0 VIEW (Cost=178 Card=1409 Bytes=1875379)
2 1 SORT (ORDER BY) (Cost=178 Card=1409 Bytes=481878)
3 2 COUNT (STOPKEY)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'PART_T' (Cost=10
6 Card=1409 Bytes=481878)

5 4 INDEX (RANGE SCAN) OF 'PART_I7' (NON-UNIQUE) (Co
st=12 Card=1409)





Statistics
----------------------------------------------------------
3878 recursive calls
0 db block gets
971 consistent gets
12 physical reads
0 redo size
10573 bytes sent via SQL*Net to client
1694 bytes received via SQL*Net from client
3 SQL*Net roundtrips to/from client
7 sorts (memory)
0 sorts (disk)
18 rows processed

the Execution Plan of this query is the same as original query itself but it's very fast and the reason is in "consistent gets" I guess.

Please tell me why there is huge diff. in consistent gets when the Execution Plan of both is same. I can not use hints(application restrictions) is it right thing to use the rownum inside the nested query , I get the same results in my test env. but somebody told me that the logic is compleltely different and I might end up getting wrong data.


Tom Kyte
June 07, 2004 - 4:31 pm UTC

select * from t where rownum <= 15 order by x


does this:

a) gets 15 random rows from t
b) sorts them


where as

select * from ( select * from t order by x ) where rownum <= 15

a) orders the result set by x
b) gets the first 15 after sorting.


so, you cannot compare them.


Why cannot you use a safe, positive, good hint? you *want* first rows, not the standard all rows optimization here.

Best Optimisation

Saar, June 08, 2004 - 3:17 am UTC

If a table has more than 10,000 records and I want to flush the table every time when I start it. what do u suggest to use if I don?

Records getting stored in this way..

id serialnumber from to
20 1 ---- ----
20 2 ---- ----
20 3 ---- ----
20 4 ---- ----

21 1 ---- ----
21 2 ---- ----
21 3 ---- ----

22 1 ---- ----
22 2 ---- ----
22 3 ---- ----
22 4 ---- ----

Best practise to delete this table....

1. Delete <table_name>;

2. Take bulk collect of unique id using select statements and use Forall statement to delete it.

Pls. advice

Tom Kyte
June 08, 2004 - 8:28 am UTC

3) use a global temporary table, it sounds like you want a temp table


but -- #2 would be the worst way to do it. #1 would be OK if you wanted to be able to rollback. #4 would be "truncate"

MERGE JOIN CARTESIAN

Goh Seong Hin, June 22, 2004 - 3:10 am UTC

Dear Tom,

Would need your advice on this as I found one of the slow SQL which contain a very high value in MERGE JOIN CARTESIAN. The following is the SQL statement, tkprof and Exp Plan for the Sql.

** From your advice in others thread, the outer join can be take out rite. ( pl.item_id = msi.inventory_item_id (+) )
** Your advice not to use function in predicate.How can I restructe this predicate. nvl(NULL,pov.vendor_name ) = xxx
** hr_employees, po_headers, po_lines is VIEW
** mtl_system_items is SYNONYM
** How can i determine which tables is causing MERGE JOIN CARTESIAN and return such a huge rows. Can I say that exp no. 7 (FTS of 'PER_ALL_PEOPLE_F') and 9 (FTS of 'PO_VENDORS') causing the Cartesian JOIN and I should look at the link for this two tables.
** Appreciate if you can advice us in this SQL tuning.

select distinct pov.vendor_name,
MSI.SEGMENT1 C_FLEX_ITEM , msi.segment1 item_name,
hre . employee_id
FROM hr_employees hre , po_vendors pov , po_headers poh ,
po_lines pl , mtl_system_items msi
WHERE poh . agent_id = hre . employee_id
AND poh . vendor_id = pov . vendor_id
and pl.item_id = msi.inventory_item_id (+)
AND msi.organization_id = 1
and pl.po_header_id = poh . po_header_id
AND poh.type_lookup_code in ('STANDARD','BLANKET','PLANNED')
AND nvl(poh.cancel_flag,'N') = 'N'
AND pov.vendor_name BETWEEN nvl(NULL , pov.vendor_name )
AND nvl(NULL,pov.vendor_name )
AND hre.full_name = nvl (NULL , hre.full_name )
order by pov.vendor_name

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.20 0.20 0 0 0 0
Execute 2 0.00 0.00 0 0 0 0
Fetch 1 40.56 11.95 4 1040 12 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 40.76 120.15 4 1040 12 0

Rows Row Source Operation
------- ---------------------------------------------------
0 SORT UNIQUE
0 FILTER
1 NESTED LOOPS
1 NESTED LOOPS
1 HASH JOIN
3670156 MERGE JOIN CARTESIAN
1149 TABLE ACCESS FULL PER_ALL_PEOPLE_F
3670156 SORT JOIN
3197 TABLE ACCESS FULL PO_VENDORS
0 TABLE ACCESS FULL PO_HEADERS_ALL
0 TABLE ACCESS BY INDEX ROWID PO_LINES_ALL
0 INDEX RANGE SCAN (object id 45108)
0 TABLE ACCESS BY INDEX ROWID MTL_SYSTEM_ITEMS_B
0 INDEX UNIQUE SCAN (object id 38017)
0 SORT AGGREGATE
0 TABLE ACCESS FULL FINANCIALS_SYSTEM_PARAMS_ALL

EXPLAIN PLAN
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=177 Card=2 Bytes=304)
1 0 SORT (UNIQUE) (Cost=174 Card=2 Bytes=304)
2 1 FILTER
3 2 NESTED LOOPS (Cost=170 Card=2 Bytes=304)
4 3 NESTED LOOPS (Cost=168 Card=2 Bytes=270)
5 4 HASH JOIN (Cost=162 Card=2 Bytes=244)
6 5 MERGE JOIN (CARTESIAN) (Cost=33 Card=8 Bytes=760)
7 6 TABLE ACCESS (FULL) OF 'PER_ALL_PEOPLE_F' (Cost=9 Card=1 Bytes=66)
8 6 SORT (JOIN) (Cost=24 Card=8 Bytes=232)
9 8 TABLE ACCESS (FULL) OF 'PO_VENDORS' (Cost=24 Card=8 Bytes=232)
10 5 TABLE ACCESS (FULL) OF 'PO_HEADERS_ALL' (Cost=128 Card=232 Bytes=6264)
11 4 TABLE ACCESS (BY INDEX ROWID) OF 'PO_LINES_ALL' (Cost=3 Card=841 Bytes=10933)
12 11 INDEX (RANGE SCAN) OF 'PO_LINES_U2' (UNIQUE) (Cost=1 Card=841)
13 3 TABLE ACCESS (BY INDEX ROWID) OF 'MTL_SYSTEM_ITEMS_B' (Cost=1 Card=8444 Bytes=143548)
14 13 INDEX (UNIQUE SCAN) OF 'MTL_SYSTEM_ITEMS_B_U1' (UNIQUE)
15 2 SORT (AGGREGATE)
16 15 TABLE ACCESS (FULL) OF 'FINANCIALS_SYSTEM_PARAMS_ALL'
(Cost=2 Card=1 Bytes=5)

Thanks in advance.

Rgds
SHGoh

Tom Kyte
June 22, 2004 - 8:21 am UTC

you have views in there -- i don't know what tables map to with views.

the explain plan is expecting 1 row back from per_all_people_f, you got 1,149

the explain plan is expecting 8 rows back from po_vendors, you got 3,197

assuming that is the POV table above -- the predicate:


AND pov.vendor_name BETWEEN nvl(NULL , pov.vendor_name )
AND nvl(NULL,pov.vendor_name )

(in addition to being a verbose way to say "and pov.vendor_name is not null") is assumed to return 8 rows. does that seem right? (obviously not, there is probably 3,197 rows in that table). that is throwing it way off.


I suspect that hre is the people table -- full_name is probably almost unique, it sees "almost_unique_column = f(x)" and is coming up with card=1


These generic predicates are killing it -- if you use bind variables, you might see something very different. consider:


big_table@ORA9IR2> create table hre as select * from big_table where rownum <= 1149;

Table created.

big_table@ORA9IR2> create index hre_idx on hre(object_name);

Index created.

big_table@ORA9IR2> create table pov as select * from big_table where rownum <= 3197;

Table created.

big_table@ORA9IR2> create index pov_idx on pov(object_name);

Index created.

big_table@ORA9IR2>
big_table@ORA9IR2> analyze table hre compute statistics;

Table analyzed.

big_table@ORA9IR2> analyze table pov compute statistics;

Table analyzed.

big_table@ORA9IR2>
big_table@ORA9IR2> variable x varchar2(30);
big_table@ORA9IR2> set autotrace traceonly explain
big_table@ORA9IR2> select * from pov where object_name between nvl(null,object_name) and nvl(null,object_name);

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6 Card=8 Bytes=736)
1 0 TABLE ACCESS (FULL) OF 'POV' (Cost=6 Card=8 Bytes=736)



big_table@ORA9IR2> select * from pov where object_name between nvl(:x,object_name) and nvl(:x,object_name);

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=9 Card=88 Bytes=8096)
1 0 CONCATENATION
2 1 FILTER
3 2 TABLE ACCESS (FULL) OF 'POV' (Cost=3 Card=8 Bytes=736)
4 1 FILTER
5 4 TABLE ACCESS (BY INDEX ROWID) OF 'POV' (Cost=3 Card=8 Bytes=736)
6 5 INDEX (RANGE SCAN) OF 'POV_IDX' (NON-UNIQUE) (Cost=2 Card=1)



big_table@ORA9IR2> select * from hre where object_name = nvl(null,object_name);

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=3 Card=1 Bytes=92)
1 0 TABLE ACCESS (FULL) OF 'HRE' (Cost=3 Card=1 Bytes=92)



big_table@ORA9IR2> select * from hre where object_name = nvl(:x,object_name);

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5 Card=1150 Bytes=105800)
1 0 CONCATENATION
2 1 FILTER
3 2 TABLE ACCESS (FULL) OF 'HRE' (Cost=2 Card=1 Bytes=92)
4 1 FILTER
5 4 TABLE ACCESS (BY INDEX ROWID) OF 'HRE' (Cost=2 Card=1 Bytes=92)
6 5 INDEX (RANGE SCAN) OF 'HRE_IDX' (NON-UNIQUE) (Cost=1 Card=1)



big_table@ORA9IR2> set autotrace off
big_table@ORA9IR2>


I would suggest however, that since this seems to be a query that will be used to either accept some values for pov to constrain the result set, or some values for hre, or maybe values for both -- that you use a stored procedure that returns a result set via a ref cursor and use a tiny bit of dynamic sql to construct the best predicate for each case

Like this example:
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279 <code>



and yes, this:

and pl.item_id = msi.inventory_item_id (+)
AND msi.organization_id = 1

indicates the (+) is "not meaningful". organization_id would be null if you actually had to outer join, null is not going to be 1, hence (+) is not useful.


Help Needed

atul, June 30, 2004 - 5:56 am UTC

Hi,

Following are some queries with tkprof which are very slow
and need to tune..

Could you give some inputs

SELECT /*+FIRST_ROWS INDEX(DCGRQST DCGRQST_0U) INDEX(DCGCRC DCGCRC_0U) */
DCGRQST.POREQUESTID
FROM
DCGRQST,DCGCRC
WHERE DCGRQST.POEXCONSG LIKE '5050043RTM%'
AND
DCGRQST.POREQUESTID=DCGCRC.POREQUESTID
ORDER BY DCGRQST.POREQUESTID ASC


call count cpu elapsed disk query current rows

------- ------ -------- ---------- ---------- ---------- ---------- ----------

Parse 1 0.00 0.01 0 0 0 0

Execute 1 0.00 0.00 0 0 0 0

Fetch 13 32.17 99.78 62622 460521 0 13

------- ------ -------- ---------- ---------- ---------- ---------- ----------
Misses in library cache during parse: 0
Optimizer goal: FIRST_ROWS
Parsing user id: 71 (OPS$A012MTO)

Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: HINT: FIRST_ROWS
13 NESTED LOOPS
456621 TABLE ACCESS (BY ROWID) OF 'DCGRQST'
456621 INDEX (FULL SCAN) OF 'DCGRQST_0U' (UNIQUE)
13 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF 'DCGCRC_0U' (UNIQUE)
================================================================================

Example 2: when run on voyage
==============================
SELECT /*+FIRST_ROWS INDEX(DCGRQST DCGRQST_0U) INDEX(DCGCRC DCGCRC_0U) */
DCGRQST.POREQUESTID
FROM
DCGRQST,DCGCRC
WHERE DCGCRC.POVOYNO LIKE 'MCU4623%'
AND DCGRQST.POREQUESTID= DCGCRC.POREQUESTID
ORDER BY DCGRQST.POREQUESTID ASC


call count cpu elapsed disk query current rows

------- ------ -------- ---------- ---------- ---------- ---------- ----------

Parse 1 0.02 0.05 0 0 0 0

Execute 1 0.00 0.00 0 0 0 0

Fetch 13 51.36 101.87 9697 2249489 0 13

------- ------ -------- ---------- ---------- ---------- ---------- ----------

total 15 51.38 101.92 9697 2249489 0 13


Misses in library cache during parse: 1
Optimizer goal: FIRST_ROWS
Parsing user id: 71 (OPS$A012MTO)

Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: HINT: FIRST_ROWS
13 NESTED LOOPS
449842 INDEX (FULL SCAN) OF 'DCGRQST_0U' (UNIQUE)
449842 TABLE ACCESS (BY ROWID) OF 'DCGCRC'
449842 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF 'DCGCRC_0U' (UNIQUE)
==============

Following are the indexes available on these two table as seen from the Dancarg QA :
=======================
TABLE_NAME COLUMN_NAME INDEX_NAME
--------------- --------------- ---------------
DCGCRC POREQUESTID DCGCRC_0U
DCGCRC POVOYNO DCGCRC1_NU

DCGRQST POREQUESTID DCGRQST_4NU
DCGRQST PORECDTIME DCGRQST1
DCGRQST POAGNTRQID DCGRQST_4NU
DCGRQST POREQUESTID DCGRQST_0U
DCGRQST POPREVID DCGRQST_1NU
=====================================================

all the tables involved in the queries have data around 100000 rows..

Please give your suggestions

Tom Kyte
June 30, 2004 - 10:14 am UTC

in the first one, the optimizer blindly followed your advice and used that index.

bummer, isn't it. drop the hints and come back and then we'll talk.


indexes are NOT fast=true.

Is there a better way to write this?

DPears, August 11, 2004 - 2:31 pm UTC

Hi Tom. I saw this query over and over in an app I worked on and it bugs me. Surely there is a better way than the subquery.

All they want is the most recent row in a series of rows created to record changes to an entity (as identified by xxxxx in query mockup below) as it goes through its life cycle (not MY design solution!).

select stuff
from table_a
where xxxxx and date_column = (select max(date_column)
from table_a
where xxxxx)

DB 9iR2. This is pretty generic so I left out the "create," "insert," etc stuff you requested. If you need to know what is indexed, I can find out.

Thanks in advance.



Tom Kyte
August 12, 2004 - 7:40 am UTC

"Gettting it faster" Oracle Magazine

Logan Palanisamy, August 12, 2004 - 2:51 pm UTC

Tom,

In the "Getting it faster" section of your Oracle Magazine article, why are you ordering by "pet_id DESC"? Isn't it redundant when the the where clause is "pet_id = :b1"? Or is it some kind of a trick for the optimizer?

select weight
from (select weight
from t
where pet_id = :b1
order by pet_id DESC,
setup_date DESC,
weight DESC )
where rownum = 1;

I feel, it can be just:

select weight
from (select weight
from t
where pet_id = :b1
order by setup_date DESC,
weight DESC )
where rownum = 1;


Thanks for your wonderful service. You are a good role model for people like me.

Tom Kyte
August 12, 2004 - 3:27 pm UTC

it was to help the optimizer out -- the index is on pet_id, setup_date, weight -- the order by is redundant, but typically necessary.

Order by slows things down

A reader, August 17, 2004 - 6:10 pm UTC

I am seeing something really weird, Oracle 9.2.0.4 all tables analyzed using dbms_stats, histograms and everything, the full works.

I have a query that returns approx 1000 rows fine in under a second, great.

As soon as I add an ORDER BY to the query, it tanks. The plan changes completely, the tkprof and the explain plan differ wildly, etc.

Why would a ORDER BY slow things down so much for a result set of 1000 rows only?

Thanks

Tom Kyte
August 18, 2004 - 7:37 am UTC

i'd have to see an example in order to explain anything.

INDEX_COMBINE for subquery?

A reader, August 18, 2004 - 1:50 pm UTC

Hi Tome,

I have a fairly simple example here.

create table dimtable
(col1 number(10) primary key)
/
insert into dimtable select rownum from all_tables where rownum <= 10
/
commit
/
create table bigtable
(id number(10) primary key,
col1 number(10),
col2 number(10)
)
/
insert into bigtable select rownum, mod(rownum, 1000), mod(rownum, 434) from all_objects
/
commit
/
create bitmap index b_col1_idx on
bigtable(col1)
compute statistics
/
create bitmap index b_col2_idx on
bigtable(col2)
compute statistics
/

Then I run the following query. It uses INDEX_COMBINE correctly.

SELECT /*+ INDEX_COMBINE(B B_COL1_IDX B_COL2_IDX) */
*
FROM BIGTABLE B
WHERE B.COL1 IN (1,2,3,4,5,6,7,8,9,10)
AND B.COL2 IN (23, 24, 31, 48, 78, 102, 103, 222, 225, 333, 11, 22, 3, 223, 272, 33, 342, 283, 232,122, 99 )
/

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=37 Card=2658 Bytes=3
9870)

1 0 TABLE ACCESS (BY INDEX ROWID) OF 'BIGTABLE' (Cost=37 Card=
2658 Bytes=39870)

2 1 BITMAP CONVERSION (TO ROWIDS)
3 2 BITMAP AND
4 3 BITMAP OR
5 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
6 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
7 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
8 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
9 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
10 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
11 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
12 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
13 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
14 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL1_IDX'
15 3 BITMAP OR
16 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
17 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
18 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
19 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
20 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
21 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
22 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
23 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
24 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
25 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
26 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
27 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
28 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
29 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
30 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
31 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
32 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
33 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
34 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
35 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
36 15 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'


However if I change one IN list to a subquery, it then failed to use INDEX_COMBINE correctly.

SELECT /*+ INDEX_COMBINE(B B_COL1_IDX B_COL2_IDX) */
*
FROM BIGTABLE B
WHERE B.COL1 IN (SELECT col1 from dimtable)
AND B.COL2 IN (23, 24, 31, 48, 78, 102, 103, 222, 225, 333, 11, 22, 3, 223, 272, 33, 342, 283, 232,122, 99 )
/

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=55 Card=21793 Bytes=
610204)

1 0 NESTED LOOPS (Cost=55 Card=21793 Bytes=610204)
2 1 INLIST ITERATOR
3 2 TABLE ACCESS (BY INDEX ROWID) OF 'BIGTABLE' (Cost=53 Card=26577 Bytes=398655)
4 3 BITMAP CONVERSION (TO ROWIDS)
5 4 BITMAP INDEX (SINGLE VALUE) OF 'B_COL2_IDX'
6 1 INDEX (UNIQUE SCAN) OF 'SYS_C0056373' (UNIQUE)


Is it possible that I can force the CBO to evaluate the subquery first and then convert the result to an IN list of constant values and then apply the INDEX_COMBINE?


Thanks.

Tom Kyte
August 18, 2004 - 11:35 pm UTC

No -- that would be like asking "run part of the query -- and then optimize the rest of it based on what you find"

the optimizer doesn't/cant work like that.

Too long query

Rory, October 15, 2004 - 3:19 am UTC

Hi Tom,

Could you pls take a look at this query. It takes too long to process. And I always end up with snaphot too old even if I've changed my undo_retention to 4hrs already. A developer needs to run this. My last run took 4hrs but ended with snapshot too old. I'll paste the query here with the explain plan. I could have put the statistics but then I can't finish the query.

select distinct last_name ||','|| first_name name
, TO_DATE(substr(prrv1.result_value,1,11),'YYYY/MM/DD')||':'|| SUBSTR(TO_CHAR(TO_DATE(SUBSTR(ROUND(prrv5.result_value,1),1,4),'HH24:MI'),'DD-MON-YYYY HH24:MI'),13,3) ||
LPAD(ROUND( MOD( (prrv5.result_value * 60), 60)),2,0) ot_start
, TO_DATE(substr(prrv4.result_value,1,11),'YYYY/MM/DD')||':'||SUBSTR(TO_CHAR(TO_DATE(SUBSTR(ROUND(prrv6.result_value,1),1,4),'HH24:MI'),'DD-MON-YYYY HH24:MI'),13,3) ||
LPAD(ROUND( MOD( (prrv6.result_value * 60), 60)),2,0) ot_end
,prrv.run_result_id
,petf.element_type_id
,substr(paf.assignment_number,1,10)asg_no
,substr(TO_CHAR(TO_DATE(substr(prrv1.result_value,1,11),'YYYY/MM/DD'),'DAY'),1,3) DOW
,SUM(substr(prrv.result_value,1,15)) amount
,substr(prrv2.result_value,1,15) type
,substr(prrv3.result_value,1,15) hrs
,paa.assignment_id ass_id
from pay_assignment_actions paa
,pay_run_results prr
,pay_run_result_values prrv
,pay_input_values_f pivf
,pay_element_types_f petf
,pay_payroll_actions ppa
,per_time_periods ptp
,pay_element_classifications pec
/*ot_start*/
,pay_run_result_values prrv1
,pay_input_values_f pivf1
/*ot_end*/
,pay_run_result_values prrv4
,pay_input_values_f pivf4
/*ot_start_time*/
,pay_run_result_values prrv5
,pay_input_values_f pivf5
/*ot_end_time*/
,pay_run_result_values prrv6
,pay_input_values_f pivf6
/*ot_type*/
,pay_run_result_values prrv2
,pay_input_values_f pivf2
/*ot_hours*/
,pay_run_result_values prrv3
,pay_input_values_f pivf3
/*ot_end*/
,per_people_f ppf
,per_assignments_f paf
where paa.assignment_action_id = prr.assignment_action_id
and paa.assignment_id = paf.assignment_id
and paf.person_id = ppf.person_id
and prr.element_type_id = petf.element_type_id
and petf.classification_id = pec.classification_id
and prr.status IN ('P','PA')
and prr.run_result_id = prrv.run_result_id
and prrv.input_value_id = pivf.input_value_id
and pivf.element_type_id = petf.element_type_id
and paa.payroll_action_id = ppa.payroll_action_id
and ppa.payroll_id = 86
and ppa.payroll_id = ptp.payroll_id
and ppa.time_period_id = ptp.time_period_id
and trunc(PTP.end_date) BETWEEN to_date('2004/09/01','yyyy/mm/dd') and to_date('2004/09/22','yyyy/mm/dd')
-- and UPPER(petf.element_name) = 'OVERTIME PAY'
--and petf.element_type_id in(51027,51026, 52992)
and petf.element_type_id = 150
and upper(pivf.name)= 'PAY VALUE'
/*ot_start*/
and pivf1.element_type_id = petf.element_type_id
and prrv1.input_value_id = pivf1.input_value_id
and prr.run_result_id = prrv1.run_result_id
and upper(pivf1.name) = 'START_DATE'
/*ot_end*/
and pivf4.element_type_id = petf.element_type_id
and prrv4.input_value_id = pivf1.input_value_id
and prr.run_result_id = prrv4.run_result_id
and upper(pivf4.name) = 'END_DATE'
/*ot_start_time*/
and pivf5.element_type_id = petf.element_type_id
and prrv5.input_value_id = pivf5.input_value_id
and prr.run_result_id = prrv5.run_result_id
and upper(pivf5.name) = 'START_TIME'
/*ot_end_time*/
and pivf6.element_type_id = petf.element_type_id
and prrv6.input_value_id = pivf6.input_value_id
and prr.run_result_id = prrv6.run_result_id
and upper(pivf6.name) = 'END_TIME'
/*ot_type*/
and pivf2.element_type_id = petf.element_type_id
and prrv2.input_value_id = pivf2.input_value_id
and prr.run_result_id = prrv2.run_result_id
and upper(pivf2.name)= 'OT_TYPE'
/*ot_hrs*/
and pivf3.element_type_id = petf.element_type_id
and prrv3.input_value_id = pivf3.input_value_id
and prr.run_result_id = prrv3.run_result_id
and upper(pivf3.name)= 'HOURS'
and ppf.effective_start_date = (select max(effective_start_date)
from per_people_f
where person_id = ppf.person_id)
and paf.effective_start_date = (select max(effective_start_date)
from per_assignments_f
where assignment_id = paf.assignment_id)
GROUP BY paa.assignment_id,last_name ||','|| first_name
,petf.element_type_id
,prrv.run_result_id
,substr(paf.assignment_number,1,10)
,substr(prrv2.result_value,1,15)
,substr(to_char(ptp.end_date,'YYYY/MM/DD'),1,11)
,substr(prrv3.result_value,1,15)
, TO_DATE(substr(prrv1.result_value,1,11),'YYYY/MM/DD')||':'||SUBSTR(TO_CHAR(TO_DATE(SUBSTR(ROUND(prrv5.result_value,1),1,4),'HH24:MI'),'DD-MON-YYYY HH24:MI'),13,3) ||
LPAD(ROUND( MOD( (prrv5.result_value * 60), 60)),2,0)
, TO_DATE(substr(prrv4.result_value,1,11),'YYYY/MM/DD')||':'||SUBSTR(TO_CHAR(TO_DATE(SUBSTR(ROUND(prrv6.result_value,1),1,4),'HH24:MI'),'DD-MON-YYYY HH24:MI'),13,3) ||
LPAD(ROUND( MOD( (prrv6.result_value * 60), 60)),2,0)
, substr(TO_CHAR(TO_DATE(substr(prrv1.result_value,1,11),'YYYY/MM/DD'),'DAY'),1,3)
,paa.assignment_id
/

Explain plan is

SELECT STATEMENT Cost = 112
SORT UNIQUE
SORT GROUP BY
VIEW
FILTER
SORT GROUP BY
TABLE ACCESS BY INDEX ROWID PAY_INPUT_VALUES_F
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
TABLE ACCESS BY INDEX ROWID PER_TIME_PERIODS
INDEX RANGE SCAN PER_TIME_PERIODS_N50
TABLE ACCESS BY INDEX ROWID PAY_PAYROLL_ACTIONS
INDEX RANGE SCAN PAY_PAYROLL_ACTIONS_FK8
TABLE ACCESS BY INDEX ROWID PAY_ASSIGNMENT_ACTIONS
INDEX RANGE SCAN PAY_ASSIGNMENT_ACTIONS_N50
TABLE ACCESS BY INDEX ROWID PER_ALL_ASSIGNMENTS_F
INDEX RANGE SCAN PER_ASSIGNMENTS_F_PK
SORT AGGREGATE
TABLE ACCESS BY INDEX ROWID PER_ALL_ASSIGNMENTS_F
INDEX RANGE SCAN PER_ASSIGNMENTS_F_PK
TABLE ACCESS BY INDEX ROWID PER_ALL_PEOPLE_F
INDEX RANGE SCAN PER_PEOPLE_F_PK
TABLE ACCESS BY INDEX ROWID PER_ALL_PEOPLE_F
INDEX RANGE SCAN PER_PEOPLE_F_PK
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULTS
INDEX RANGE SCAN PAY_RUN_RESULTS_N50
TABLE ACCESS BY INDEX ROWID PAY_ELEMENT_TYPES_F
INDEX RANGE SCAN PAY_ELEMENT_TYPES_F_PK
INDEX UNIQUE SCAN PAY_ELEMENT_CLASSIFICATION_PK
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_RUN_RESULT_VALUES
INDEX RANGE SCAN PAY_RUN_RESULT_VALUES_N50
TABLE ACCESS BY INDEX ROWID PAY_INPUT_VALUES_F
INDEX RANGE SCAN PAY_INPUT_VALUES_F_N1
TABLE ACCESS BY INDEX ROWID PAY_INPUT_VALUES_F
INDEX RANGE SCAN PAY_INPUT_VALUES_F_N1
INDEX RANGE SCAN PAY_INPUT_VALUES_F_UK2
TABLE ACCESS BY INDEX ROWID PAY_INPUT_VALUES_F
INDEX RANGE SCAN PAY_INPUT_VALUES_F_N1
TABLE ACCESS BY INDEX ROWID PAY_INPUT_VALUES_F
INDEX RANGE SCAN PAY_INPUT_VALUES_F_N1
TABLE ACCESS BY INDEX ROWID PAY_INPUT_VALUES_F
INDEX RANGE SCAN PAY_INPUT_VALUES_F_N1
INDEX RANGE SCAN PAY_INPUT_VALUES_F_N1

Thanks a lot TOm.

Tom Kyte
October 15, 2004 - 11:41 am UTC

i like the design it makes when I scroll the plan up and down - swish, swoop... neat.


anyhow, when I see this:

 from    pay_assignment_actions paa
        ,pay_run_results        prr
        ,pay_run_result_values  prrv
        ,pay_input_values_f     pivf
        ,pay_element_types_f    petf
        ,pay_payroll_actions    ppa
        ,per_time_periods       ptp
                ,pay_element_classifications  pec
/*ot_start*/
                ,pay_run_result_values  prrv1
                ,pay_input_values_f     pivf1
/*ot_end*/
                ,pay_run_result_values  prrv4
                ,pay_input_values_f     pivf4
/*ot_start_time*/
                ,pay_run_result_values  prrv5
                ,pay_input_values_f     pivf5
/*ot_end_time*/
                ,pay_run_result_values  prrv6
                ,pay_input_values_f     pivf6
/*ot_type*/
                ,pay_run_result_values  prrv2
                ,pay_input_values_f     pivf2
/*ot_hours*/
                ,pay_run_result_values  prrv3
                ,pay_input_values_f     pivf3
/*ot_end*/
                ,per_people_f ppf
               ,per_assignments_f paf

I immediately think "pivot"... so, I'll not be rewriting your query, I'll show you a TECHNIQUE you can use and reuse over and over.......

you are simply trying to make "in record" some dimension that is currently "cross record".

So, you have a funky schema like this:

ops$tkyte@ORA9IR2> create table people( id number primary key, name varchar2(5) );
 
Table created.
 
ops$tkyte@ORA9IR2> insert into people values ( 10, 'Tom' );
 
1 row created.
 
ops$tkyte@ORA9IR2> insert into people values ( 20, 'Lori' );
 
1 row created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create table people_attr
  2  ( id number primary key,
  3    people_id references people,
  4    attr_name varchar2(10),
  5    val varchar2(10) )
  6  /
 
Table created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> insert into people_attr values ( 1, 10, 'job', 'oracle' );
 
1 row created.
 
ops$tkyte@ORA9IR2> insert into people_attr values ( 2, 20, 'job', 'accounting' );
 
1 row created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> insert into people_attr values ( 3, 10, 'work phone', '123-4567' );
 
1 row created.
 
ops$tkyte@ORA9IR2> insert into people_attr values ( 4, 20, 'work phone', '953-2234' );
 
1 row created.


<b>to report on people, their jobs and their numbers, you could:</b>
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select people.id, people.name, pa1.val, pa2.val
  2    from people,
  3         people_attr pa1,
  4             people_attr pa2
  5   where people.id = pa1.people_id
  6     and pa1.attr_name = 'job'
  7     and people.id = pa2.people_id
  8     and pa2.attr_name = 'work phone'
  9  /
 
        ID NAME  VAL        VAL
---------- ----- ---------- ----------
        10 Tom   oracle     123-4567
        20 Lori  accounting 953-2234
 
<b>as you have, or you can join ONCE and pivot:</b>

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select people.id, people.name,
  2         max( decode( pa.attr_name, 'job', pa.val ) ),
  3         max( decode( pa.attr_name, 'work phone', pa.val ) )
  4    from people,
  5         people_attr pa
  6   where people.id = pa.people_id
  7   group by people.id, people.name
  8  /
 
        ID NAME  MAX(DECODE MAX(DECODE
---------- ----- ---------- ----------
        10 Tom   oracle     123-4567
        20 Lori  accounting 953-2234
 
<b>try the pivot</b>

 

sorry for posting it here but need this clarifications

Raj, October 15, 2004 - 12:08 pm UTC

I read following in the </code> http://www.fortunecity.com/skyscraper/oracle/699/orahtml/hayden/libcache.html <code>

Reducing Library Cache Misses
You can reduce library cache misses by
Allocating Additional Memory for the Library Cache

You may be able to reduce library cache misses on execution calls by allocating additional memory for the library cache. To ensure that shared SQL areas remain in the cache once their SQL statements are parsed, increase the amount of memory available to the library cache until the V$LIBRARYCACHE.RELOADS value is near 0. To increase the amount of memory available to the library cache, increase the value of the initialization parameter SHARED_POOL_SIZE. The maximum value for this parameter depends on your operating system. This measure will reduce implicit reparsing of SQL statements and PL/SQL blocks on execution. To take advantage of additional memory available for shared SQL areas, you may also need to increase the number of cursors permitted for a session. You can increase this limit by increasing the value of the initialization parameter OPEN_CURSORS. Be careful not to induce paging and swapping by allocating too much memory for the library cache. The benefits of a library cache large enough to avoid cache misses can be partially offset by reading shared SQL areas into memory from disk whenever you need to access them.
Writing Identical SQL Statements

You may be able to reduce library cache misses on parse calls by ensuring that SQL statements and PL/SQL blocks share a shared SQL area whenever possible. For two different occurrences of a SQL statement or PL/SQL block to share a shared SQL area, they must be identical according to these criteria:
The text of the SQL statements or PL/SQL blocks must be identical, character for character, including spaces and case. For example, these statements cannot use the same shared SQL area:
SELECT * FROM emp;
SELECT * FROM emp;

These statements cannot use the same shared SQL area:
SELECT * FROM emp;
SELECT * FROM Emp;

References to schema objects in the SQL statements or PL/SQL blocks must resolve to the same object in the same schema. For example, if the schemas of the users BOB and ED both contain an EMP table and both users issue the following statement, their statements cannot use the same shared SQL area:
SELECT * FROM emp;
SELECT * FROM emp;

If both statements query the same table and qualify the table with the schema, as in the following statement, then they can use the same shared SQL area: SELECT * FROM bob.emp;
Bind variables in the SQL statements must match in name and datatype. For example, these statements cannot use the same shared SQL area: SELECT * FROM emp WHERE deptno = :department_no; SELECT * FROM emp WHERE deptno = :d_no;
The SQL statements must be optimized using the same optimization approach and, in the case of the cost-based approach, the same optimization goal. For information on optimization approach and goal, see Chapter 9, "Tuning SQL Statements". Shared SQL areas are most useful for reducing library cache misses for multiple users running the same application. Discuss these criteria with the developers of such applications and agree on strategies to ensure that the SQL statements and PL/SQL blocks of an application can use the same shared SQL areas:
Use bind variables rather than explicitly specified constants in your statements whenever possible. For example, the following two statements cannot use the same shared area because they do not match character for character: SELECT ename, empno FROM emp WHERE deptno = 10; SELECT ename, empno FROM emp WHERE deptno = 20; You can accomplish the goals of these statements by using the following statement that contains a bind variable, binding 10 for one occurrence of the statement and 20 for the other: SELECT ename, empno FROM emp WHERE deptno = :department_no; The two occurrences of the statement can use the same shared SQL area.
Be sure that individual users of the application do not change the optimization approach and goal for their individual sessions. You can also increase the likelihood that SQL statements issued by different applications can share SQL areas by establishing these policies among the developers of these applications:
Standardize naming conventions for bind variables and spacing conventions for SQL statements and PL/SQL blocks.
Use stored procedures whenever possible. Multiple users issuing the same stored procedure automatically use the same shared PL/SQL area. Since stored procedures are stored in a parsed form, they eliminate runtime parsing altogether.

Does this mean that to in order to soft parse a query they have to completely identical even in terms of spaces, case

I always thought that if query is not using bind variables or the where conditions is different then Oracle does a hard parse

Thanks

Tom Kyte
October 15, 2004 - 3:02 pm UTC

if two queries match in every detail -- they can be shared.

if they do not, they won't and they will hard parse the first time they are executed.


(why would you copy an entire web page -- that is what the link is for...)


the existence of bind variables does not affect the algorithm. If you execute

"select * from dual"

a billion times, there will be a hard parse the first time and soft parses after that. NO BINDS THERE.

you use binds when you are executing a query that differs ONLY in its inputs:

select * from emp where empno = 1
select * from emp where empno = 2
...
select * from emp where empno = 1000000000

those are all "unique" sql's - but:

select * from emp where empno = :x

with the inputs 1, 2, ..., 1000000000 is a single reusable sql statement.

hmm..

A reader, October 15, 2004 - 5:08 pm UTC

"select * from emp where empno = :x

with the inputs 1, 2, ..., 1000000000 is a single reusable sql statement. "

the size of the input also matters as we have seen
elsewhere in your site (I think.) But in general the above
would be a reusable statement for a range of :x values.
Instead of getting one hard parse, you would
get perhaps, say 3 hard parses for different size ranges
(e.g. for x from 1 to 40000, one hard parse and so on - note
that these numbers are totally imaginary.)
Still much better than having 1000000000 unique statements.



Tom Kyte
October 15, 2004 - 6:11 pm UTC

well, i tricked you didn't i :)

I used a number, not a string....

yes, it could result in a few shareable sql statements based on bind input sizes.....
<b>
(keep me honest -- excellent, don't stop... shows me people are watching :)
</b>

ops$tkyte@ORA9IR2> drop table t;
 
Table dropped.
 
ops$tkyte@ORA9IR2> alter system flush shared_pool;
 
System altered.
 
ops$tkyte@ORA9IR2> create table t ( x int );
 
Table created.
 
ops$tkyte@ORA9IR2> variable n number
ops$tkyte@ORA9IR2> exec :n := 1;
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> select * from t where x = :n;
 
no rows selected
 
ops$tkyte@ORA9IR2> exec :n := to_number(rpad('9',38,'9'))
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> select * from t where x = :n;
 
no rows selected
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select sql_text from v$sql where sql_text like 'select * from t where x = %';
 
SQL_TEXT
-------------------------------------------------------------------------------
select * from t where x = :n
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> variable s varchar2(1)
ops$tkyte@ORA9IR2> exec :s := 1;
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> select * from t where x = :s;
 
no rows selected
 
ops$tkyte@ORA9IR2> variable s varchar2(38)
ops$tkyte@ORA9IR2> exec :s := to_number(rpad('9',38,'9'))
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> select * from t where x = :s;
 
no rows selected
 
ops$tkyte@ORA9IR2> select sql_text from v$sql where sql_text like 'select * from t where x = %';
 
SQL_TEXT
-------------------------------------------------------------------------------
select * from t where x = :s
select * from t where x = :s
select * from t where x = :n
 
 

A reader, October 15, 2004 - 6:27 pm UTC

Not sure I understand.

"yes, it could result in a few shareable sql statements based on bind input sizes....."

What does the bind input size have to do here?

select from t where empno = :x

will not be hard parsed regardless of the actual value of the bind variable passed in, right? Why did the previous reader say that there will be hard parses for different size ranges?

Tom Kyte
October 16, 2004 - 10:29 am UTC

with a number correct.

with a string -- well, see the above example. i showed (not just having a reader saying) that string sizes "count" -- different bind lengths for strings (there are 'steps' like 32 is a 'step' -- bind a string < 32 charcters -- one child cursor, bind a string >= 32 characters -- another child cursor).

A number is a number however, we don't need different setups for them. For strings -- we have different child sql statements for different ranges (as demonstrated right above with two :s queries)

v$sql_shared_cursor

Winston, October 15, 2004 - 7:40 pm UTC

I could reproduce the test case and I noticed that hard parse did happen from the sql trace file.

I also checked v$sql_shared_cursor and found out the reason that sharing did not happen was BIND_MISMATCH.

BIND_MISMATCH


VARCHAR2(1)


(Y|N) The bind metadata does not match the existing child cursor

Tom Kyte
October 16, 2004 - 10:32 am UTC

correct, that is exactly what I was showing - it is supposed to happen that way.

too long query

Rory, October 17, 2004 - 11:20 pm UTC

Hi tom,

Thanks for the "pivot query". I dont know how to
say this but would it be possible for you to rewrite
my query above using the pivot that you mentioned.
But with that, I'll be able to understand it.
My query is the one with the swish, swoop explain plan.
Hope you'll have the time. I really need the sql badly
and the developer doesnt have an idea on pivot.
Thanks a lot.

Tom Kyte
October 18, 2004 - 7:55 am UTC

you cannot read the above and figure it out?

I showed you a technique -- JOIN ONCE, use decode to move the data out into columns and then group by. The technique above must be understood by you before you can use it (just a picky thing about me I guess -- before someone uses something I believe they should understand what it is, how it works, what it does).

Soooo -- apply the technique to your query. As I don't have your tables, your data, etc -- I might make a mistake, one that you would not detect unless you yourself understand what this is doing and how it does it.

sql profile in 10g

James, October 19, 2004 - 4:53 pm UTC

Hope you don't mind asking me this in this thread.

In 10g, If I used sql tuning advisor to tune a sql statement including creating sql profile for that statement, how do I remove that profile if next time when the sql statement is run the profile that was generated eariler should not be used. Is there a way to remove sql profiles? Thanks.

Tom Kyte
October 19, 2004 - 8:49 pm UTC

SQL Tuning

Thirumaran, October 25, 2004 - 11:40 am UTC

Hi Tom,

When thinking about query tuning i have some doubts when a query is joined with 2 or more tables .
version 9i

Example:

Select empno,ename,dname,loc from emp e,dept d
where e.deptno = d.deptno
and salary > 8000
and job not in ('CLERK')

1) using table alias name for columns will speed up the query processing or is just only for readability.
i.e Select e.empno,e.ename,d.dname,d.loc instead of
Select empno,ename,dname,loc as mentioned above.

2) where e.deptno = d.deptno
A) will Oracle read from Right to Left or Left to Right .
my understanding is it read from Left to Right (am i right)
B) I generall put small tables to left and Big table to right (is this a good method of writing queries)

3) How will oracle read the query from top to bottom or Bottom to top or the cost based optimizer wil take care.

i.e (as per the above query)
will it read joins first then read the salary > 1000 and then job not in ('CLERK')
or the reverse ways.

4) When should i use suquery and when should i use joins
i read an article you can change Subquery to a join but not the reverse . Why ?

Thanks ,
Thirumaran


Tom Kyte
October 25, 2004 - 11:59 am UTC

1) readability

2) either or, the job of the optimizer is to figure out which table to drive with. you don't need to concern yourself with "what order should the things in a predicate be specified" like that.

3) CBO doesn't care really, rbo did, but the CBO doesn't.

4) use a subquery when you don't need the columns in your result set (when you don't select from it), use a join otherwise. the job of the optimizer is to figure out if the subquery should be written as a join (it does that)

query tuning

Sree, October 29, 2004 - 12:57 pm UTC

Hi Tom,

This query is running very slow and some time it does not.
Table WMS_INV_UNITS_TRANS is our transaction table which has 9 M and growing.
I think in-line query with max(iut_id) is making the damage.
Is their any other way to rewrite the query to run fast.

Thanks Sree

SELECT loc_code, i.item_code, i.item_descr, i.grade_code,
SUM (trans_qty) balance_qty, aprv_cust_code
FROM (
SELECT
(SELECT i1.i_id
FROM wms_inv_units_trans i1
WHERE i1.iut_id = trans_iut_id) i_id,
(SELECT aprv_cust_code
FROM wms_inv_units_trans ap1
WHERE ap1.iut_id = trans_iut_id) aprv_cust_code,
DECODE (trans_code,
'TRANSFEROT', new_balance_qty * 1,
'SHIPPED', new_balance_qty * -1,
'TRANSFERIN', trans_qty,
trans_qty
) trans_qty,
NVL (zone_loc_code_dnmlz,
SUBSTR (zone_code_dnmlz, 1, 3)
) loc_code
FROM wms_inv_units_trans iu,
(SELECT
iu.iu_id trans_iu_id, MAX (iu.iut_id) trans_iut_id
FROM wms_inv_units_trans iu
WHERE iu.zone_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059',
'mm/dd/rrrr hh24miss'
)
AND iu.item_type_code_dnmlz = 'BRITE'
GROUP BY iu.iu_id) iu1
WHERE 1 = 1
AND iu.iu_id = iu1.trans_iu_id
AND iu.zone_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059', 'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz = 'BRITE'
UNION ALL
SELECT
(SELECT i1.i_id
FROM wms_inv_units_trans i1
WHERE i1.iut_id = trans_iut_id) i_id,
(SELECT aprv_cust_code
FROM wms_inv_units_trans ap1
WHERE ap1.iut_id = trans_iut_id) aprv_cust_code,
DECODE (trans_code,
'TRANSFEROT', new_balance_qty * -1,
'SHIPPED', new_balance_qty * -1,
'TRANSFERIN', trans_qty,
trans_qty
) trans_qty,
iu.transfer_from_loc_code_dnmlz loc_code
FROM wms_inv_units_trans iu,
(SELECT
iu.iu_id trans_iu_id, MAX (iu.iut_id) trans_iut_id
FROM wms_inv_units_trans iu
WHERE iu.transfer_from_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059',
'mm/dd/rrrr hh24miss'
)
AND iu.item_type_code_dnmlz = 'BRITE'
AND iu.trans_code = 'TRANSFEROT'
GROUP BY iu.iu_id) iu1
WHERE iu.iu_id = iu1.trans_iu_id
AND iu.transfer_from_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059', 'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz = 'BRITE'
AND iu.trans_code = 'TRANSFEROT') a,wms_items i
WHERE 1 = 1 AND i.i_id = a.i_id
GROUP BY loc_code,
item_code,
item_descr,
grade_code,
aprv_cust_code
HAVING SUM (trans_qty) <> 0
ORDER BY 1,2

Explain plan
------------

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=CHOOSE 755 100509
FILTER
SORT GROUP BY 755 60 K 100509
HASH JOIN 15 K 1 M 100398
VIEW 15 K 618 K 100334
UNION-ALL
HASH JOIN 15 K 998 K 66704
VIEW 14 K 380 K 33384
SORT GROUP BY 14 K 380 K 33384
TABLE ACCESS FULL GEM.WMS_INV_UNITS_TRANS 15 K 381 K 33308
TABLE ACCESS FULL GEM.WMS_INV_UNITS_TRANS 15 K 616 K 33308
TABLE ACCESS BY INDEX ROWID GEM.WMS_INV_UNITS_TRANS 1 33 8
NESTED LOOPS 44 2 K 33630
VIEW 45 1 K 33313
SORT GROUP BY 45 1 K 33313
TABLE ACCESS FULL GEM.WMS_INV_UNITS_TRANS 45 1 K 33308
INDEX RANGE SCAN GEM.IUT_IU_COMP_IDX 5 2
TABLE ACCESS FULL GEM.WMS_ITEMS 25 K 1001 K 41

Tom Kyte
October 29, 2004 - 4:56 pm UTC

yes, instead of self joining back with max(dt) by id

select *
from ( select ..., MAX(dt) over (partition by id) max_dt
from ...
where ...)
where dt = max_dt;



Oracle 9204

A reader, November 03, 2004 - 3:52 pm UTC

Tom,

I have a query like this

INSERT INTO d
(SELECT a.*, sysdate
FROM a, vw_a b
WHERE a.cnum = b.cnum
AND a.idnum = b.idnum)

and the view vw_a is

select cnum, max(idnum) as idnum from a group by cnum
having count(*) > 1


Can you show me how to modify this query in a better way.

Thanks.

Tom Kyte
November 05, 2004 - 10:57 am UTC

so, insert the row from A having the max IDNUM in any group of CNUMS having more than one record


select idnum, cnum, ...., sysdate
from (
select a.*,
count(*) over (partion by cnum) cnt,
max(idnum) over (partition by cnum) maxid
from a
)
where cnt > 1
and idnum = maxid



Update in a loop - SQL tuning?

A reader, November 04, 2004 - 5:04 am UTC

run_resultid INTEGER;

...

FOR matrixvalue IN (SELECT mv.POSITION, mv.proposed
FROM matrix_type mt,
matrix_values mv,
matrix m,
RESULT r
WHERE r.result_id =
run_resultid
AND m.user_id = r.user_id
AND m.matrix_type_id =
mt.matrix_type_id
AND mt.op = 3
AND mv.matrix_id =
m.matrix_id
AND m.matrix_id IN (
SELECT mre.matrix_id
FROM matrix_result mre
WHERE mre.result_id =
run_resultid)
ORDER BY mv.POSITION ASC)

LOOP

xaxisvalue := sf_getaxisvalue (
run_resultid,
3,
'X',
MOD (
matrixvalue.POSITION,
sf_getmatrixcolcount (3)
)
);
yaxisvalue := sf_getaxisvalue (
run_resultid,
3,
'Y',
FLOOR (
matrixvalue.POSITION /
sf_getmatrixrowcount (3)
)
);

UPDATE result_table rt
SET rt.op = 3,
rt.done = 1,
rt.proposed = matrixvalue.proposed
WHERE rt.done = 0
AND rt.result_id = run_resultid
AND rt.product_id IN (
SELECT p.product_id
FROM product p, global_prod_data gkd
WHERE p.product_serial_no =
gkd.product_serial_no
AND p.package_code =
gkd.package_code
AND gkd.spl >= xaxisvalue)
AND p.sales_frequency_accumulated >=
yaxisvalue
);

END LOOP;

There are indexes on columns package_code and product_serial_no in tables p and gkd, and also on the result_id in the rt table.

What i have:
I have a subset of products from table p which are stored in table rt - on which a number of calculations are to be made using values contained in matrices. The data to the products are stored on local warehouse level in the p table and global product variables are stored in the gkd table. For reference the no of rows of the tables are something like; p: ~40,000 * 30, gkd 120,000, rt: could reach 40,000 * 3000. Although for this run we would only be interested in 40,000 records of each of course.

What I need:
I need to loop through all the matrix values and do this for each value present in the matrix (I compare with the headers in the matrix (i.e. X, Y) and update the table with the code in the matrix itself.) I need to loop from either high value in X or Y - This is a typical matrix with X/Y values and codes:
Y/X 175 150 130 110
8 C C C C
6 C N S
5 D C
4 E

Although I am using indexes I think that this could tune a little bit more... but after a number of tests I only get it going slower than this.

Is there any possibility that you could take a peek and hint on this poor one.

Thanks!
/Tony

Tom Kyte
November 05, 2004 - 11:52 am UTC

sorry -- too complex and incomplete for a review/followup.

I cannot run the example and it is bigger than a breadbox (so not appropriate here)

sql tuning

sree, November 04, 2004 - 1:50 pm UTC

Hi Tom,
I changed query as you advised above. It is still taking too long (may be 20 min) on our testdatabse. It does not run at all in our production database. Here is the trace file. could you please help me to optimize the query.
Thanks

SELECT loc_code, i.item_code, i.item_descr, i.grade_code,
SUM (trans_qty) balance_qty, aprv_cust_code
FROM (
SELECT /*+ rule */
(SELECT i1.i_id
FROM wms_inv_units_trans i1
WHERE i1.iut_id = trans_iut_id) i_id,
(SELECT aprv_cust_code
FROM wms_inv_units_trans ap1
WHERE ap1.iut_id = trans_iut_id) aprv_cust_code,
DECODE (trans_code,
'TRANSFEROT', new_balance_qty * 1,
'SHIPPED', new_balance_qty * -1,
'TRANSFERIN', trans_qty,
trans_qty
) trans_qty,
NVL (zone_loc_code_dnmlz,
SUBSTR (zone_code_dnmlz, 1, 3)
) loc_code
FROM wms_inv_units_trans iu,
(SELECT /*+ rule */
iu.iu_id trans_iu_id,
MAX (iu.iut_id) over(partition by iu.i
u_id) trans_iut_id
FROM wms_inv_units_trans iu
WHERE iu.zone_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059',
'mm/dd/rrrr hh24miss'
)
AND iu.item_type_code_dnmlz = 'BRITE'
) iu1
WHERE 1 = 1
AND iu.iu_id = iu1.trans_iu_id
AND iu.zone_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059', 'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz = 'BRITE'
UNION ALL
SELECT /*+ rule */
(SELECT i1.i_id
FROM wms_inv_units_trans i1
WHERE i1.iut_id = trans_iut_id) i_id,
(SELECT aprv_cust_code
FROM wms_inv_units_trans ap1
WHERE ap1.iut_id = trans_iut_id) aprv_cust_code,
DECODE (trans_code,
'TRANSFEROT', new_balance_qty * -1,
'SHIPPED', new_balance_qty * -1,
'TRANSFERIN', trans_qty,
trans_qty
) trans_qty,
iu.transfer_from_loc_code_dnmlz loc_code
FROM wms_inv_units_trans iu,
(SELECT /*+ rule */
iu.iu_id trans_iu_id,
MAX (iu.iut_id) over(partition by iu.i
u_id) trans_iut_id
FROM wms_inv_units_trans iu
WHERE iu.transfer_from_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059',
'mm/dd/rrrr hh24miss'
)
AND iu.item_type_code_dnmlz = 'BRITE'
AND iu.trans_code = 'TRANSFEROT') iu1
WHERE iu.iu_id = iu1.trans_iu_id
AND iu.transfer_from_loc_code_dnmlz LIKE '010'
AND iu.trans_effective_ts <=
TO_DATE ('10/25/2004 060059', 'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz = 'BRITE'
AND iu.trans_code = 'TRANSFEROT') a,wms_items i
WHERE 1 = 1 AND i.i_id = a.i_id
GROUP BY loc_code,
item_code,
item_descr,
grade_code,
aprv_cust_code
HAVING SUM (trans_qty) <> 0
ORDER BY 1,2

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.07 0.09 0 589 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 44 406.16 973.64 468772 17776508 167 632
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 46 406.23 973.73 468772 17777097 167 632

Misses in library cache during parse: 1
Optimizer goal: RULE
Parsing user id: 60

Rows Row Source Operation
------- ---------------------------------------------------
632 FILTER (cr=17776508 r=468772 w=21012 time=973639247 us)
776 SORT GROUP BY (cr=17776508 r=468772 w=21012 time=973637989 us)
4241035 NESTED LOOPS (cr=17776508 r=468772 w=21012 time=944477872 us)
4241035 VIEW (cr=9294289 r=468595 w=21012 time=858818518 us)
4241035 UNION-ALL (cr=9294289 r=468595 w=21012 time=852951631 us)
4232223 TABLE ACCESS BY INDEX ROWID OBJ#(30440) (cr=7752390 r=362248 w=208
71 time=700601655 us)
7007145 NESTED LOOPS (cr=1839250 r=153738 w=20871 time=407192972 us)
823659 VIEW (cr=177047 r=136972 w=20871 time=306200149 us)
823659 WINDOW SORT (cr=177047 r=136972 w=20871 time=305048310 us)
823659 TABLE ACCESS BY INDEX ROWID OBJ#(30440) (cr=177045 r=116098 w=
0 time=230171464 us)
823659 INDEX RANGE SCAN OBJ#(38441) (cr=4162 r=4162 w=0 time=3675397
us)(object id 38441)
6183485 INDEX RANGE SCAN OBJ#(31334) (cr=1662203 r=16766 w=0 time=818803
93 us)(object id 31334)
8812 NESTED LOOPS (cr=322077 r=43784 w=141 time=47854415 us)
8784 VIEW (cr=40230 r=39818 w=141 time=44789200 us)
8784 WINDOW SORT (cr=40230 r=39818 w=141 time=44776718 us)
8784 TABLE ACCESS BY INDEX ROWID OBJ#(30440) (cr=40230 r=39676 w=0 t
ime=44383665 us)
554880 INDEX RANGE SCAN OBJ#(37831) (cr=2367 r=2367 w=0 time=8335855
us)(object id 37831)
8812 TABLE ACCESS BY INDEX ROWID OBJ#(30440) (cr=281847 r=3966 w=0 tim
e=2976580 us)
10150 AND-EQUAL (cr=271697 r=3128 w=0 time=2754523 us)
73943 INDEX RANGE SCAN OBJ#(31334) (cr=145313 r=1612 w=0 time=1231489
us)(object id 31334)
63835 INDEX RANGE SCAN OBJ#(37831) (cr=126384 r=1516 w=0 time=1297948
us)(object id 37831)
4241035 TABLE ACCESS BY INDEX ROWID OBJ#(30444) (cr=8482219 r=177 w=0 time=6
3070435 us)
4241035 INDEX UNIQUE SCAN OBJ#(30451) (cr=4241037 r=24 w=0 time=30921961 us
)(object id 30451)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 44 0.00 0.00
db file sequential read 447756 0.06 566.99
direct path write 8 0.02 0.03
direct path read 7109 2.36 40.83
SQL*Net message from client 44 837.84 838.10



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3 0.10 0.10 1 596 0 0
Execute 4 0.04 0.05 5 255 0 0
Fetch 45 406.16 973.64 468772 17776511 167 633
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 52 406.30 973.80 468778 17777362 167 633

Misses in library cache during parse: 3
Misses in library cache during execute: 1

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 47 0.00 0.00
SQL*Net message from client 47 837.84 843.60
db file sequential read 447757 0.06 567.00
SQL*Net more data from client 1 0.00 0.00
direct path write 8 0.02 0.03
direct path read 7109 2.36 40.83


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 63 0.04 0.05 1 4 0 0
Execute 169 0.02 0.01 0 3 0 1
Fetch 422 0.03 0.08 39 666 0 347
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 654 0.09 0.15 40 673 0 348

Misses in library cache during parse: 19

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 39 0.01 0.06

4 user SQL statements in session.
63 internal SQL statements in session.
67 SQL statements in session.
0 statements EXPLAINed in this session.
********************************************************************************
Trace file: gemtest_ora_75344.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
4 user SQL statements in trace file.
63 internal SQL statements in trace file.
67 SQL statements in trace file.
23 unique SQL statements in trace file.
456266 lines in trace file.


Tom Kyte
November 05, 2004 - 2:44 pm UTC

you didn't do it the way I told you.

it has rule hints in it, i would never say to do that.

sql tuning

Sree, November 09, 2004 - 9:15 am UTC

Hi Tom,

I changed the query as you told with cost based.
Still it takes 4 to 7 minutes depending up on the data and the load.
I would appreciate if you help me to improve the performance.
Here is the tkprof attached.

Thanks Sree

**************************************************************
TKPROF: Release 9.2.0.4.0 - Production on Mon Nov 8 17:00:16 2004

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: gemprod_ora_3469512.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

alter session set sql_trace = true


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: SYS
********************************************************************************

select obj#,type#,ctime,mtime,stime,status,dataobj#,flags,oid$, spare1,
spare2
from
obj$ where owner#=:1 and name=:2 and namespace=:3 and remoteowner is null
and linkname is null and subname is null


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 4 0.00 0.00 0 0 0 0
Fetch 4 0.00 0.02 1 8 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 0.00 0.02 1 8 0 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS (recursive depth: 1)
********************************************************************************

select condition
from
cdef$ where rowid=:1


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 40 0.00 0.00 0 0 0 0
Execute 40 0.00 0.00 0 0 0 0
Fetch 40 0.00 0.00 0 80 0 40
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 120 0.00 0.00 0 80 0 40

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
1 TABLE ACCESS BY USER ROWID CDEF$ (cr=1 r=0 w=0 time=24 us)

********************************************************************************

SELECT loc_code, (SELECT loc_name
FROM wms_locations l1
WHERE l1.loc_code = a.loc_code) loc_name,
LTRIM (RTRIM (SUBSTR (s, 1, 20))) item_type_code,
item_code my_item_code, i.item_code, i.item_descr, i.grade_code,
pkg_report.fnc_balance_conversion (SUM (trans_qty),
'EXTERNAL CONVERSION',
external_conv_factor
) balance_qty,
pkg_report.fnc_uom_conversion
('EXTERNAL CONVERSION',
LTRIM (RTRIM (SUBSTR (s, 181, 20))),
external_conv_factor
) inv_uom_code,
LTRIM (RTRIM (SUBSTR (s, 21, 40))) aprv_cust_code,
LTRIM (RTRIM (SUBSTR (s, 61, 40))) quality_status_dnmlz
FROM (SELECT iu.iu_id, iut_id, (SELECT i1.i_id
FROM wms_inv_units_trans i1
WHERE i1.iut_id = trans_iut_id) i_id,
(SELECT RPAD (NVL (item_type_code_dnmlz, ' '), 20, ' ')
|| RPAD (NVL (aprv_cust_code, ' '), 40, ' ')
|| RPAD (NVL (quality_status_dnmlz, ' '), 40, ' ')
|| RPAD (NVL (zone_code_dnmlz, ' '), 40, ' ')
|| RPAD (NVL (quality_confirmed_flag, ' '), 40, ' ')
|| RPAD (NVL (inv_uom_code_dnmlz, ' '), 20, ' ')
|| RPAD (NVL (lot_code, ' '), 20, ' ')
FROM wms_inv_units_trans s1
WHERE s1.iut_id = trans_iut_id) s,
DECODE (trans_code,
'TRANSFEROT', new_balance_qty * 1,
'SHIPPED', new_balance_qty * -1,
'TRANSFERIN', trans_qty,
trans_qty
) trans_qty,
NVL (zone_loc_code_dnmlz,
SUBSTR (zone_code_dnmlz, 1, 3)
) loc_code
FROM wms_inv_units_trans iu,
(SELECT trans_iu_id, trans_iut_id
FROM (SELECT iu_id trans_iu_id, iut_id,
MAX (iut_id) OVER (PARTITION BY iu_id)
trans_iut_id
FROM wms_inv_units_trans iu
WHERE iu.zone_loc_code_dnmlz LIKE
UPPER (REPLACE ('043', '*', '%'))
AND iu.trans_effective_ts <=
TO_DATE ('11/05/2004 060059',
'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz LIKE
REPLACE ('BRITE', '*', '%'))
WHERE iut_id = trans_iut_id) iu1
WHERE 1 = 1
AND iu.iu_id = iu1.trans_iu_id
AND iu.zone_loc_code_dnmlz LIKE
UPPER (REPLACE ('043', '*', '%'))
AND iu.trans_effective_ts <=
TO_DATE ('11/05/2004 060059', 'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz LIKE REPLACE ('BRITE', '*', '%')
UNION ALL
SELECT iu.iu_id, iut_id, (SELECT i1.i_id
FROM wms_inv_units_trans i1
WHERE i1.iut_id = trans_iut_id) i_id,
(SELECT RPAD (NVL (item_type_code_dnmlz, ' '), 20, ' ')
|| RPAD (NVL (aprv_cust_code, ' '), 40, ' ')
|| RPAD (NVL (quality_status_dnmlz, ' '), 40, ' ')
|| RPAD (NVL (zone_code_dnmlz, ' '), 40, ' ')
|| RPAD (NVL (quality_confirmed_flag, ' '), 40, ' ')
|| RPAD (NVL (inv_uom_code_dnmlz, ' '), 20, ' ')
|| RPAD (NVL (lot_code, ' '), 20, ' ')
FROM wms_inv_units_trans s1
WHERE s1.iut_id = trans_iut_id) s,
DECODE (trans_code,
'TRANSFEROT', new_balance_qty * -1,
'SHIPPED', new_balance_qty * -1,
'TRANSFERIN', trans_qty,
trans_qty
) trans_qty,
iu.transfer_from_loc_code_dnmlz loc_code
FROM wms_inv_units_trans iu,
(SELECT trans_iu_id, trans_iut_id
FROM (SELECT iu_id trans_iu_id, iut_id,
MAX (iut_id) OVER (PARTITION BY iu_id)
trans_iut_id
FROM wms_inv_units_trans iu
WHERE iu.transfer_from_loc_code_dnmlz LIKE
UPPER (REPLACE ('043', '*', '%'))
AND iu.trans_effective_ts <=
TO_DATE ('11/05/2004 060059',
'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz LIKE
REPLACE ('BRITE', '*', '%')
AND iu.trans_code = 'TRANSFEROT')
WHERE iut_id = trans_iut_id) iu1
WHERE iu.iu_id = iu1.trans_iu_id
AND iu.transfer_from_loc_code_dnmlz LIKE
UPPER (REPLACE ('043', '*', '%'))
AND iu.trans_effective_ts <=
TO_DATE ('11/05/2004 060059', 'mm/dd/rrrr hh24miss')
AND iu.item_type_code_dnmlz LIKE REPLACE ('BRITE', '*', '%')
AND iu.trans_code = 'TRANSFEROT') a,
wms_items i
WHERE 1 = 1 AND i.i_id = a.i_id
GROUP BY loc_code,
LTRIM (RTRIM (SUBSTR (s, 1, 20))),
item_code,
item_code,
item_descr,
grade_code,
LTRIM (RTRIM (SUBSTR (s, 181, 20))),
LTRIM (RTRIM (SUBSTR (s, 21, 40))),
LTRIM (RTRIM (SUBSTR (s, 61, 40))),
external_conv_factor
HAVING SUM (trans_qty) <> 0
ORDER BY 2, 3, 4

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.04 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 10 0.00 197.18 196521 2866079 7 124
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 12 0.00 197.23 196521 2866079 7 124

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS

Rows Row Source Operation
------- ---------------------------------------------------
1 TABLE ACCESS BY INDEX ROWID WMS_LOCATIONS (cr=2 r=0 w=0 time=18 us)
1 INDEX UNIQUE SCAN L_LOC_CODE_UK (cr=1 r=0 w=0 time=11 us)(object id 30482)
124 SORT ORDER BY (cr=2866079 r=196521 w=5321 time=197186405 us)
124 FILTER (cr=2866077 r=196521 w=5321 time=197184041 us)
184 SORT GROUP BY (cr=2866077 r=196521 w=5321 time=197183887 us)
422165 HASH JOIN (cr=2866077 r=196521 w=5321 time=194089003 us)
25671 TABLE ACCESS FULL WMS_ITEMS (cr=411 r=0 w=0 time=25046 us)
422165 VIEW (cr=2865666 r=196521 w=5321 time=193133938 us)
422165 UNION-ALL (cr=2865666 r=196521 w=5321 time=192824126 us)
414894 HASH JOIN (cr=262930 r=162381 w=5321 time=137001153 us)
89296 VIEW (cr=126056 r=92188 w=5321 time=125159035 us)
414894 WINDOW SORT (cr=126056 r=92188 w=5321 time=124896635 us)
414894 TABLE ACCESS BY INDEX ROWID WMS_INV_UNITS_TRANS (cr=126056 r=86866 w=0 time=113893622 us)
501253 INDEX RANGE SCAN ZONE_DNMLZ_IDX (cr=1938 r=1937 w=0 time=1775929 us)(object id 38300)
414894 TABLE ACCESS BY INDEX ROWID WMS_INV_UNITS_TRANS (cr=136874 r=70193 w=0 time=10450918 us)
501253 INDEX RANGE SCAN ZONE_DNMLZ_IDX (cr=1938 r=1937 w=0 time=919263 us)(object id 38300)
7271 TABLE ACCESS BY INDEX ROWID WMS_INV_UNITS_TRANS (cr=129034 r=14221 w=0 time=25672120 us)
71150 NESTED LOOPS (cr=66928 r=3816 w=0 time=11055647 us)
7271 VIEW (cr=51644 r=5 w=0 time=2232945 us)
7271 WINDOW SORT (cr=51644 r=5 w=0 time=2220599 us)
7271 TABLE ACCESS BY INDEX ROWID WMS_INV_UNITS_TRANS (cr=51644 r=5 w=0 time=2129560 us)
709147 INDEX RANGE SCAN WMS_INV_UNITS_TRANS_I_TRANS_CO (cr=2417 r=3 w=0 time=491733 us)(object id 37831)
63878 INDEX RANGE SCAN IUT_IU_COMP_IDX (cr=15284 r=3811 w=0 time=8724292 us)(object id 38305)

********************************************************************************

alter session set sql_trace = false


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.00 0.00 0 0 0 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.04 0 0 0 0
Execute 3 0.00 0.00 0 0 0 0
Fetch 10 0.00 197.18 196521 2866079 7 124
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 15 0.00 197.23 196521 2866079 7 124

Misses in library cache during parse: 2
Misses in library cache during execute: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 41 0.00 0.00 0 0 0 0
Execute 44 0.00 0.00 0 0 0 0
Fetch 44 0.00 0.02 1 88 0 40
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 129 0.00 0.03 1 88 0 40

Misses in library cache during parse: 2

3 user SQL statements in session.
41 internal SQL statements in session.
44 SQL statements in session.
********************************************************************************
Trace file: gemprod_ora_3469512.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
3 user SQL statements in trace file.
41 internal SQL statements in trace file.
44 SQL statements in trace file.
5 unique SQL statements in trace file.
516 lines in trace file.


Tom Kyte
November 09, 2004 - 9:29 am UTC

sorry -- but a multi-page query with tons of unions, inline views, scalar subqueries - etc....


you'll have to look at it and "tune it".

I don't know what your question is (why is the query the way it is)...
I don't know your system
I don't know your schema
I don't know your indexes

You do though, you have the best chance at doing this.


I do get suspicious when I see a UNION with the same table over and over. I'm sure you can do something about that.

Best way when an IN value can be NULL

A reader, November 10, 2004 - 6:38 am UTC

Thanks Tom for a THE most useful site!!!

I must be having a really bad day or ... I have missed something crucial - is there a better way of evaluating IN values. When I submitt all NULLS I want to get all Employees but when I asign either of the values I want these to be checked against the employee table.

CREATE OR REPLACE FUNCTION getemployee
(id INTEGER, firstname VARCHAR2, lastname VARCHAR2)
RETURN cursor
AS
empcursor cursor ;
BEGIN
OPEN empcursor FOR
SELECT employee_id FROM employee
WHERE( (id IS NOT NULL AND employee_id = id)
OR id IS NULL
)
AND
( (firstname IS NOT NULL AND first_name = firstname)
OR firstname IS NULL
)
AND
( (lastname IS NOT NULL AND last_name = lastname)
OR lastname IS NULL
);
RETURN empcursor;
END;

Thanks!!!

Tom Kyte
November 10, 2004 - 7:12 am UTC

for this, you would probably be best off using a ref cursor and native dyanmic sql.

if you send in "nothing" (all nulls) you would like a full scan.
if you send in "id", you would like an index unique scan on that primary key index.
if you send in "lastname", you would like an index range scan on.....

and so on -- meaning, you want different plans for different inputs.

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279 <code>

Thank you, Thank you, Thank you!!!!!

A reader, November 10, 2004 - 8:11 am UTC

Thanks for untieing the Brain Knot (your comment + a couple of coffees ;-)

Thank you! Brilliant as usual!


How about getting rid of the OR's from above

Christoph, November 10, 2004 - 8:25 am UTC

Hi Tom,

this is a different approach to the above query (from "A reader") without beeing concerned about different execution plans for different column.

create table test(col1 number,col2 number);
alter table test add (constraint pk_test primary key (col1,col2));

insert into test select * from table(create_rows(20)),table(create_rows(1000));
commit;

where create rows is a pipelined function to return the given number of rows
so we inserted 20000 rows

analyze table test compute statistics for table for all indexes for all indexed columns;

var col1 number;

now when we execute

select *
from test
where ((:col1 is not null and col1 = :col1) or (:col1 is null));

we get:
Elapsed: 00:00:00.40

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=15 Card=1048 Bytes=5240)
1 0 TABLE ACCESS (FULL) OF 'TEST' (TABLE) (Cost=15 Card=1048 Bytes=5240)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
1406 consistent gets
0 physical reads
0 redo size
326331 bytes sent via SQL*Net to client
15175 bytes received via SQL*Net from client
1335 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
20000 rows processed

and for:

select *
from test
where col1 = nvl(:col1,col1);

we get:
20000 rows selected.

Elapsed: 00:00:00.41

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=15 Card=21000 Bytes=105000)
1 0 CONCATENATION
2 1 FILTER
3 2 TABLE ACCESS (FULL) OF 'TEST' (TABLE) (Cost=14 Card=20000 Bytes=100000)
4 1 FILTER
5 4 INDEX (RANGE SCAN) OF 'PK_TEST' (INDEX (UNIQUE)) (Cost=6 Card=1000 Bytes=5000)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
1406 consistent gets
0 physical reads
0 redo size
326331 bytes sent via SQL*Net to client
15175 bytes received via SQL*Net from client
1335 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
20000 rows processed

ok we did not give :col1 a value so we get the same amount of lio's

but when :col1=1

we get this for the first query
1000 rows selected.

Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=15 Card=1048 Bytes=5240)
1 0 TABLE ACCESS (FULL) OF 'TEST' (TABLE) (Cost=15 Card=1048 Bytes=5240)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
143 consistent gets
0 physical reads
0 redo size
16760 bytes sent via SQL*Net to client
1238 bytes received via SQL*Net from client
68 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1000 rows processed

and this for the second one
1000 rows selected.

Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=15 Card=21000 Bytes=105000)
1 0 CONCATENATION
2 1 FILTER
3 2 TABLE ACCESS (FULL) OF 'TEST' (TABLE) (Cost=14 Card=20000 Bytes=100000)
4 1 FILTER
5 4 INDEX (RANGE SCAN) OF 'PK_TEST' (INDEX (UNIQUE)) (Cost=6 Card=1000 Bytes=5000)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
71 consistent gets
0 physical reads
0 redo size
16760 bytes sent via SQL*Net to client
1238 bytes received via SQL*Net from client
68 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1000 rows processed

so it seems the second query is more efficient if we supply a value, but at least as efficient as the first one without a value (for lio).
is this assumption right? and also could you please explain the second query plan. i am a little confused about the full scan of test and the filter concatenation.

thanks a lot
christoph


Tom Kyte
November 10, 2004 - 11:56 am UTC

that works well with "a" bind -- but once you have two or three, it breaks down (send in lastname and firstname for example)

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:7555175291763 <code>

goes thru this "technique"

Need your help

Jennifer Chen, November 15, 2004 - 2:53 pm UTC

Hi Tom,

I have a query using wildcard search, which takes 37 seconds to run:

SQL> connect alias/alias@aliastst
Connected.
SQL> set autotrace traceonly
SQL> set timing on
SQL> SELECT m.tcn, f.fin_agency_id, f.agency_name, m.current_tcn_status, n.nam,
  2         n.dob, m.enter_user_id,
  3         TO_CHAR (m.enter_date_time, 'MM/DD/YYYY HH24:MI') enter_date_time
  4    FROM (SELECT *
  5            FROM alias.wq_master
  6           WHERE tot IN ('MAP', 'NFUF') AND SOURCE = 'L') m,
  7         (SELECT   tcn, MAX (DECODE (alias_field, 'NAM', VALUE)) nam,
  8                   MAX (DECODE (alias_field, 'DOB', VALUE)) dob,
  9                   MAX (DECODE (alias_field,
 10                                'REQUESTORID', VALUE
 11                               )) requestor_id
 12              FROM alias.wq_nist
 13             WHERE record_number = 0 AND SOURCE = 'N'
 14          GROUP BY tcn) n,
 15         alias.fin_agency f
 16   WHERE m.tcn LIKE 'A104%' AND m.tcn = n.tcn
 17         AND n.requestor_id = f.fin_agency_id;

no rows selected

Elapsed: 00:00:37.07

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=38 Card=1 Bytes=122)
   1    0   FILTER
   2    1     SORT (GROUP BY) (Cost=38 Card=1 Bytes=122)
   3    2       MERGE JOIN (CARTESIAN) (Cost=24 Card=1196 Bytes=145912
          )

   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'WQ_NIST' (Cost=3 C
          ard=1 Bytes=33)

   5    4           NESTED LOOPS (Cost=5 Card=1 Bytes=81)
   6    5             TABLE ACCESS (BY INDEX ROWID) OF 'WQ_MASTER' (Co
          st=2 Card=1 Bytes=48)

   7    6               INDEX (RANGE SCAN) OF 'PK_WQ_MASTER' (UNIQUE)
          (Cost=1 Card=1)

   8    5             INDEX (RANGE SCAN) OF 'FK_WQ_NIST_TCN' (NON-UNIQ
          UE) (Cost=1 Card=1)

   9    3         BUFFER (SORT) (Cost=35 Card=7846 Bytes=321686)
  10    9           TABLE ACCESS (FULL) OF 'FIN_AGENCY' (Cost=19 Card=
          7846 Bytes=321686)





Statistics
----------------------------------------------------------
          0  recursive calls
         60  db block gets
        370  consistent gets
      52451  physical reads
          0  redo size
        631  bytes sent via SQL*Net to client
        369  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          1  sorts (memory)
          1  sorts (disk)
          0  rows processed

TCN is a VARCHAR2(13) column. All tables involved in this query contain maximum 200 records. If I change like 'A104%' to like 'A1040000%', the query finish in 1 ~ 2 seconds.

Do you see anything wrong here or how I can improve the query.

Many thanks in advance.
 

Tom Kyte
November 15, 2004 - 9:00 pm UTC

what does the tkprof look like

Please help

Jennifer Chen, November 16, 2004 - 9:46 am UTC

Hi Tom,

Here is TKPROF. I still didn't figure out how to get cr=statistics:

TKPROF: Release 9.2.0.5.0 - Production on Tue Nov 16 09:10:42 2004

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: aliastst_ora_5108.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

alter session set sql_trace=true


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 80
********************************************************************************

SELECT m.tcn, f.fin_agency_id, f.agency_name, m.current_tcn_status, n.nam,
n.dob, m.enter_user_id,
TO_CHAR (m.enter_date_time, 'MM/DD/YYYY HH24:MI') enter_date_time
FROM (SELECT *
FROM alias.wq_master
WHERE tot IN ('MAP', 'NFUF') AND SOURCE = 'L') m,
(SELECT tcn, MAX (DECODE (alias_field, 'NAM', VALUE)) nam,
MAX (DECODE (alias_field, 'DOB', VALUE)) dob,
MAX (DECODE (alias_field,
'REQUESTORID', VALUE
)) requestor_id
FROM alias.wq_nist
WHERE record_number = 0 AND SOURCE = 'N'
GROUP BY tcn) n,
alias.fin_agency f
WHERE m.tcn LIKE 'A104%' AND m.tcn = n.tcn
AND n.requestor_id = f.fin_agency_id

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 9.60 36.53 52320 375 60 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 9.62 36.54 52320 375 60 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 80



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 2 0.00 0.00 0 0 0 0
Fetch 1 9.60 36.53 52320 375 60 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 9.62 36.54 52320 375 60 0

Misses in library cache during parse: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 0 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 0 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0

2 user SQL statements in session.
0 internal SQL statements in session.
2 SQL statements in session.
********************************************************************************
Trace file: aliastst_ora_5108.trc
Trace file compatibility: 9.02.00
Sort options: default

1 session in tracefile.
2 user SQL statements in trace file.
0 internal SQL statements in trace file.
2 SQL statements in trace file.
2 unique SQL statements in trace file.
51 lines in trace file.


Thanks again.

Tom Kyte
November 16, 2004 - 12:59 pm UTC

you need to have that cursor closed.

go into sqlplus.
run the query
EXIT sqlplus

and then run tkprof.

Please help

Jennifer Chen, November 16, 2004 - 1:14 pm UTC

Sorry, here is the TKPROF:


TKPROF: Release 9.2.0.5.0 - Production on Tue Nov 16 13:12:32 2004

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: aliastst_ora_4440.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

alter session set sql_trace=true


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 80 (ALIAS)
********************************************************************************

SELECT m.tcn, f.fin_agency_id, f.agency_name, m.current_tcn_status, n.nam,
n.dob, m.enter_user_id,
TO_CHAR (m.enter_date_time, 'MM/DD/YYYY HH24:MI') enter_date_time
FROM (SELECT *
FROM alias.wq_master
WHERE tot IN ('MAP', 'NFUF') AND SOURCE = 'L') m,
(SELECT tcn, MAX (DECODE (alias_field, 'NAM', VALUE)) nam,
MAX (DECODE (alias_field, 'DOB', VALUE)) dob,
MAX (DECODE (alias_field,
'REQUESTORID', VALUE
)) requestor_id
FROM alias.wq_nist
WHERE record_number = 0 AND SOURCE = 'N'
GROUP BY tcn) n,
alias.fin_agency f
WHERE m.tcn LIKE 'A104%' AND m.tcn = n.tcn
AND n.requestor_id = f.fin_agency_id

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 10.01 57.66 51448 397 60 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 10.01 57.66 51448 397 60 0

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 80 (ALIAS)

Rows Row Source Operation
------- ---------------------------------------------------
0 FILTER
15692 SORT GROUP BY
455068 MERGE JOIN CARTESIAN
58 TABLE ACCESS BY INDEX ROWID OBJ#(41984)
77 NESTED LOOPS
2 TABLE ACCESS BY INDEX ROWID OBJ#(41982)
288 INDEX RANGE SCAN OBJ#(42098) (object id 42098)
74 INDEX RANGE SCAN OBJ#(42488) (object id 42488)
455068 BUFFER SORT
7846 TABLE ACCESS FULL OBJ#(41908)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
0 FILTER
15692 SORT (GROUP BY)
455068 MERGE JOIN (CARTESIAN)
58 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'WQ_NIST'
77 NESTED LOOPS
2 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'WQ_MASTER'
288 INDEX GOAL: ANALYZED (RANGE SCAN) OF
'PK_WQ_MASTER' (UNIQUE)
74 INDEX GOAL: ANALYZED (RANGE SCAN) OF
'FK_WQ_NIST_TCN' (NON-UNIQUE)
455068 BUFFER (SORT)
7846 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'FIN_AGENCY'




********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 2 0.00 0.00 0 0 0 0
Fetch 1 10.01 57.66 51448 397 60 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 10.01 57.66 51448 397 60 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 0 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 0 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0

2 user SQL statements in session.
0 internal SQL statements in session.
2 SQL statements in session.
1 statement EXPLAINed in this session.
********************************************************************************
Trace file: aliastst_ora_4440.trc
Trace file compatibility: 9.02.00
Sort options: default

1 session in tracefile.
2 user SQL statements in trace file.
0 internal SQL statements in trace file.
2 SQL statements in trace file.
2 unique SQL statements in trace file.
1 SQL statements EXPLAINed using schema:
ALIAS.prof$plan_table
Default table was used.
Table was created.
Table was dropped.
63 lines in trace file.




Tom Kyte
November 16, 2004 - 10:56 pm UTC

Looking at what it "thought":

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=38 Card=1 Bytes=122)
1 0 FILTER
2 1 SORT (GROUP BY) (Cost=38 Card=1 Bytes=122)
3 2 MERGE JOIN (CARTESIAN) (Cost=24 Card=1196 Bytes=145912)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'WQ_NIST' (Cost=3 C ard=1 Bytes=33)
5 4 NESTED LOOPS (Cost=5 Card=1 Bytes=81)
6 5 TABLE ACCESS (BY INDEX ROWID) OF 'WQ_MASTER' (Co st=2 Card=1 Bytes=48)
7 6 INDEX (RANGE SCAN) OF 'PK_WQ_MASTER' (UNIQUE) (Cost=1 Card=1)
8 5 INDEX (RANGE SCAN) OF 'FK_WQ_NIST_TCN' (NON-UNIQ UE) (Cost=1 Card=1)
9 3 BUFFER (SORT) (Cost=35 Card=7846 Bytes=321686)
10 9 TABLE ACCESS (FULL) OF 'FIN_AGENCY' (Cost=19 Card= 7846 Bytes=321686)

versus what it "got"

Rows Row Source Operation
------- ---------------------------------------------------
0 FILTER
15692 SORT GROUP BY
455068 MERGE JOIN CARTESIAN
58 TABLE ACCESS BY INDEX ROWID OBJ#(41984)
77 NESTED LOOPS <<<=== way off, it thought "1"
2 TABLE ACCESS BY INDEX ROWID OBJ#(41982)
288 INDEX RANGE SCAN OBJ#(42098) (object id 42098)
74 INDEX RANGE SCAN OBJ#(42488) (object id 42488)
455068 BUFFER SORT
7846 TABLE ACCESS FULL OBJ#(41908)



so, since you know the query and tables and indexes better than I, what part of the query is that NL join and what predicates are involved and how exactly do you gather statistics (eg: trying to find out why it was sure "1 row" but got lots more..)



Please help

Jennifer Chen, November 16, 2004 - 2:04 pm UTC

Hi Tom,

From the explain plan, the cost seems at full table scan in the fin_agency table and CARTESIAN MERGE JOIN. f.fin_agency_id is the pk in the fin_agency table, but I have no way to create an index on n.requestor_id because the way that table was designed...

An analyst at metalink suggests me to apply patch 3444115 to get rid of CARTESIAN MERGE JOIN.

What do you think?

Thanks again for your time and help.

SQL> set lines 130
SQL> SELECT m.tcn, f.fin_agency_id, f.agency_name, m.current_tcn_status, n.nam,
  2         n.dob, m.enter_user_id,
  3         TO_CHAR (m.enter_date_time, 'MM/DD/YYYY HH24:MI') enter_date_time
  4    FROM (SELECT *
  5            FROM alias.wq_master
  6           WHERE tot IN ('MAP', 'NFUF') AND SOURCE = 'L') m,
  7         (SELECT   tcn, MAX (DECODE (alias_field, 'NAM', VALUE)) nam,
  8                   MAX (DECODE (alias_field, 'DOB', VALUE)) dob,
  9                   MAX (DECODE (alias_field,
 10                                'REQUESTORID', VALUE
 11                               )) requestor_id
 12              FROM alias.wq_nist
 13             WHERE record_number = 0 AND SOURCE = 'N'
 14          GROUP BY tcn) n,
 15         alias.fin_agency f
 16   WHERE m.tcn LIKE 'A104%' AND m.tcn = n.tcn
 17         AND n.requestor_id = f.fin_agency_id
 18  ;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=37 Card=1 Bytes=122)
   1    0   FILTER
   2    1     SORT (GROUP BY) (Cost=37 Card=1 Bytes=122)
   3    2       MERGE JOIN (CARTESIAN) (Cost=24 Card=1181 Bytes=144082)
   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'WQ_NIST' (Cost=3 Card=1 Bytes=33)
   5    4           NESTED LOOPS (Cost=5 Card=1 Bytes=81)
   6    5             TABLE ACCESS (BY INDEX ROWID) OF 'WQ_MASTER' (Cost=2 Card=1 Bytes=48)
   7    6               INDEX (RANGE SCAN) OF 'PK_WQ_MASTER' (UNIQUE)(Cost=1 Card=1)
   8    5             INDEX (RANGE SCAN) OF 'FK_WQ_NIST_TCN' (NON-UNIQUE) (Cost=1 Card=1)
   9    3         BUFFER (SORT) (Cost=34 Card=7846 Bytes=321686)
  10    9           TABLE ACCESS (FULL) OF 'FIN_AGENCY' (Cost=19 Card=7846 Bytes=321686) 

Tom Kyte
November 16, 2004 - 10:59 pm UTC

you could, that virtually disables this access plan (merge join cartesian)

i'd rather try to figure out why the optimizer thinks "1" first - -if it didn't think "1", it would not cartesian join.

Any Idea how I can re-write this sql

Mike, November 16, 2004 - 4:19 pm UTC

SELECT x.mbricode, x.ID, x.psdocae, y.cae_nr, y.NAME
FROM (SELECT b.ip_base_nr, a.psdocae, mbricode, ID
FROM member_pseudonym a, stg_match_cae b
WHERE a.mbricode = b.mbr_grp_icode
AND src_ind = 'V'
-- and b.MBR_GRP_ICODE < 50
AND a.psdocae > 0
GROUP BY b.ip_base_nr, a.psdocae, mbricode, ID) x,
(SELECT c.ip_base_nr, c.cae_nr, c.NAME
FROM caematch_ipi c
WHERE EXISTS (SELECT ip_base_nr
FROM stg_match_cae d
WHERE d.ip_base_nr = c.ip_base_nr AND src_ind = 'V')) y
-- and Mbr_grp_icode < 50)) y
WHERE x.ip_base_nr = y.ip_base_nr AND x.psdocae = y.cae_nr

Tom Kyte
November 16, 2004 - 11:35 pm UTC

not without lots of other details -- not really.

is the relationship from x to y 1:1? scalar subqueries could work.

you are using the CBO right?

Thanks

A reader, November 17, 2004 - 9:17 am UTC

Yes I am using CBO and the RElationship is 1:1



Tom Kyte
November 17, 2004 - 11:04 am UTC

ok, so try things like scalar subqueries and the like (if you don't know what they are -- search for

"scalar subquery"
"scalar subqueries"

on this site.

A little backwards from the usual

sPh, November 24, 2004 - 10:57 am UTC

Tom,
Do you have an example of a _bad_ query? What I am thinking of is a fairly simple set of queries, each building on the last, that starts out running in a reasonable amount of time but at some point explodes (goes to exponential runtime).

I would like to demonstrate to some of our GUI-tool query users how easy it is to go wrong when one does not look at the underlying structure of the query. However, while I confess that I have inadvertently created my share of bad queries, I am not smart enough to do so in a controlled environment.

Can Tom's brain run in reverse? Inquiring minds want to know!

sPh

Tom Kyte
November 24, 2004 - 12:04 pm UTC

not sure what you mean -- in general if I have a query q1 that runs "fast", i would expect

select ...
from (Q1)
where ....

to do OK and if we call that Q2, i would expect

select ..
from (Q2)
where ....

to go ok too. so, can you be a little more clear in what you mean exactly -- are you talking about mega join of views with hidden "features" like group by's, analytics and such?

Tried to create a reply

sPh, November 24, 2004 - 12:43 pm UTC

I tried to create a more expanded reply, got to about 700 words and realized it is probably not something suited for this forum. And I probably can't afford your consulting rates.

We have data extractors almost totally trained in the GUI/Microsoft world. They are very resistant to any suggestion that they need to understand what happens below the GUI level. What I need is an example I can build up step by step in the GUI tool until it no longer works. Then go back to Oracle, analyze it using your techniques, and rebuild it as an optimized view.

But creating that would be a non-trivial effort I fear. I have the time but not the ability.

sPh

How to eliminate to query this huge table twice

Jennifer Chen, December 07, 2004 - 3:50 pm UTC

Hi Tom,

In the arrest_offense table, one pid, inc, arrest have multiple arrest_offense. I need to return the smallest arrest_offense and its associated arrest_type and arrest_class. Basically the first row in the table below. would you please correst my sql so that arrest_type will be in the same row with arrest_offense and I don't have to query this huge table twice.

Thanks in advance for your help.


pid inc arrest arrest_offense arrest_type arrest_class
1 1 1 1 C XX
1 1 1 2 B YY
1 1 2 1 A ZZ
1 2 3 1 H AA


SELECT pid,
inc,
arrest,
MIN (ao1.arrest),
MIN (arrest_type_code) arrest_type,
MIN (arrest_file_class) arrest_class
FROM alias.arrest_offense ao1
GROUP BY pid, inc, arrest

Tom Kyte
December 07, 2004 - 8:51 pm UTC

new question and not relevant to the thread started on this page....

Manish, January 04, 2005 - 1:08 pm UTC

Hi Tom,

I had a very basic question on SQL tuning. Is it true that in case there are complex joins between tables, we get much better query performance if the primary keys are 'number' instead of 'varchar2'.

thanks for help in advance

Manish

Tom Kyte
January 05, 2005 - 8:55 am UTC

no, date is much better


kidding.


no, not true. not unless your strings a literraly HUGE -- thousands of bytes.

How to make in SQL statement?

MARIANA, January 07, 2005 - 1:04 pm UTC

Hello,Tom,
In PLSQL code i have:

BEGIN
SELECT learnable_prcnt
INTO l_rtrn_rtrn_calc_rtrn_prcnt
FROM
KM_TMP_PREDICT_BRANCH_EDITIONS
WHERE PROD_NO=:prod_no
AND NWPR_DATE=:p_date
AND BRANCH_NO=:p_branch
AND learnable_prcnt>=30;
EXCEPTION
WHEN NO_DATA_FOUND
THEN
BEGIN
SELECT RTRN_PRCNT INTO l_rtrn_rtrn_calc_rtrn_prcnt
FROM KM_TMP_RTRN_STD
WHERE
PROD_NO=:prod_no
AND DAY_IN_WEEK=TO_CHAR(:p_date,'D')
AND BRANCH_NO=:p_branch;
EXCEPTION
WHEN_NO_DATA_FOUND
THEN
l_rtrn_rtrn_calc_rtrn_prcnt=NULL;
END;
END;
How can i make it in one select?
Thank you for answer.
Mariana.


Tom Kyte
January 08, 2005 - 3:57 pm UTC

how about going way back to the invoker and saying:


instead of you running a query to get umpteen rows and call me over and over, why don't you use this view:


select .....,
nvl( (select learnable_prcnt from KM_TMP_PREDICT_BRANCH_EDITIONS
where prod_no = X.prod_no and nwp_date = X.wpr_date ..... ),
(select ...... ) )
from your_table X;


that would be one way.

Another way would be:

begin
select nvl( ( SELECT learnable_prcnt
FROM KM_TMP_PREDICT_BRANCH_EDITIONS
WHERE PROD_NO=:prod_no
AND NWPR_DATE=:p_date
AND BRANCH_NO=:p_branch
AND learnable_prcnt>=30 ),
( SELECT RTRN_PRCNT
FROM KM_TMP_RTRN_STD
WHERE PROD_NO=:prod_no
AND DAY_IN_WEEK=TO_CHAR(:p_date,'D')
AND BRANCH_NO=:p_branch ) )
into l_rtrn_rtrn_calc_rtrn_prcnt
from dual;

return l_rtrn_rtrn_calc_rtrn_prcnt;
end;


no exception blocks needed (if you get no_data_found or too_many_rows -- then DUAL itself is "broken" and that is something you would like to find out)


sure, you could also:

select * from
(SELECT learnable_prcnt, 1
FROM KM_TMP_PREDICT_BRANCH_EDITIONS
WHERE PROD_NO=:prod_no
AND NWPR_DATE=:p_date
AND BRANCH_NO=:p_branch
AND learnable_prcnt>=30
UNION ALL
SELECT RTRN_PRCNT, 2
FROM KM_TMP_RTRN_STD
WHERE PROD_NO=:prod_no
AND DAY_IN_WEEK=TO_CHAR(:p_date,'D')
AND BRANCH_NO=:p_branch
order by 2 )
where rownum = 1

but that might miss a TOO_MANY_ROWS exception that should be thrown when the data is bad.

Continue to make better SQL

Mariana, January 08, 2005 - 4:47 pm UTC

Hello,Tom,
Thank you for a great solution to better SQL:

begin
select nvl( ( SELECT learnable_prcnt
FROM KM_TMP_PREDICT_BRANCH_EDITIONS
WHERE PROD_NO=:prod_no
AND NWPR_DATE=:p_date
AND BRANCH_NO=:p_branch
AND learnable_prcnt>=30 ),
( SELECT RTRN_PRCNT
FROM KM_TMP_RTRN_STD
WHERE PROD_NO=:prod_no
AND DAY_IN_WEEK=TO_CHAR(:p_date,'D')
AND BRANCH_NO=:p_branch ) )
into l_rtrn_rtrn_calc_rtrn_prcnt
from dual;

return l_rtrn_rtrn_calc_rtrn_prcnt;
end;
If at this query no data fount or too many rows or something else then will the field l_rtrn_rtrn_calc_rtrn_prcnt be NULL?
Why in SQL from dual does'nt have exceptions?
Mariana


Tom Kyte
January 08, 2005 - 5:08 pm UTC

that query can return


scott@ORA9IR2> select ( select 1 from all_users ) from dual;
select ( select 1 from all_users ) from dual
*
ERROR at line 1:
ORA-01427: single-row subquery returns more than one row



but will never throw no data found:

scott@ORA9IR2> select ( select 1 from all_users where 1=0 ) from dual;

(SELECT1FROMALL_USERSWHERE1=0)
------------------------------


scott@ORA9IR2>


for the simple reason that DUAL always has a row -- it will always find "data". and scalarsubqueries are allowed to return "no data", it is considered "NULL"

Cont to SQL tunning

A reader, January 08, 2005 - 5:20 pm UTC

Hi,Tom,
you wrote above:
begin
select nvl( ( SELECT learnable_prcnt
FROM KM_TMP_PREDICT_BRANCH_EDITIONS
WHERE PROD_NO=:prod_no
AND NWPR_DATE=:p_date
AND BRANCH_NO=:p_branch
AND learnable_prcnt>=30 ),
( SELECT RTRN_PRCNT
FROM KM_TMP_RTRN_STD
WHERE PROD_NO=:prod_no
AND DAY_IN_WEEK=TO_CHAR(:p_date,'D')
AND BRANCH_NO=:p_branch ) )
into l_rtrn_rtrn_calc_rtrn_prcnt
from dual;

return l_rtrn_rtrn_calc_rtrn_prcnt;
end;


no exception blocks needed (if you get no_data_found or too_many_rows -- then
DUAL itself is "broken" and that is something you would like to find out)

and latter you gave the example
with too many rows in scalar subquery from dual
Is'nt it a contradiction?
Does this Sql work in ORacle 8i?
When you wrote "return l_rtrn_rtrn_calc_rtrn_prcnt"
you meant that this SQL IS WRITTEN IN FUNCTION?
Thank you


Tom Kyte
January 08, 2005 - 5:40 pm UTC

Not a contradiction

well written code catches exceptions it expects to recieve.

No more, no less.


Do you "expect" in any reasonable set of circumstances for that query to return too_many_rows? I cannot fathom the case whereby that would be true. In order for that to hit TOO_MANY_ROWS -- dual would have to have MORE THAN ONE row.

You *cannot* tell me you were "expecting that"

therefore, that MUST be propagated up the call stack as an unhandled exception!

There will be NO ONE in the call stack that was "expecting" dual to return more than one row -- therefore the CLIENT will get this error and the client can abort processing -- since there is an exception deep down in the database that no one EXPECTED


Bad code, that would have a too_many rows or a "when others" and would perhaps silently ignore this truly EXCEPTIONAL condition -- causing bugs in other places all over the place


You catch exceptions YOU EXPECT.

If you didn't expect it, you better not catch it, or if you do, you BETTER follow it with a RAISE to re-raise it. You hit an error that *should not have happened, you have no idea how to deal with it, all bets off -- time to call it a day"


I find people handle errors so "incorrectly". the goal is NOT to catch them all and hide them. The goal rather is to catch things YOU EXPECT (no_data_found for example, in the original code) and do something about it.

the goal IS NOT to catch them all and "dbms_output" some message and carry on as if they did not happen!!!!!


In 8i, the scalar subquery was not supported in PLSQL witout dynamic sql or a view to "hide" the construct. same with order by in a subquery/inline view, that'll not work either.

Cont to sql tuning in ORACLE 8.1.7

A reader, January 08, 2005 - 6:38 pm UTC

Hi,Tom,
In ORACLE 8I
this solution would be the best?

select * from
(SELECT learnable_prcnt, 1
FROM KM_TMP_PREDICT_BRANCH_EDITIONS
WHERE PROD_NO=:prod_no
AND NWPR_DATE=:p_date
AND BRANCH_NO=:p_branch
AND learnable_prcnt>=30
UNION ALL
SELECT RTRN_PRCNT, 2
FROM KM_TMP_RTRN_STD
WHERE PROD_NO=:prod_no
AND DAY_IN_WEEK=TO_CHAR(:p_date,'D')
AND BRANCH_NO=:p_branch
order by 2 )
where rownum = 1
What do you mean in saying ?
"but that might miss a TOO_MANY_ROWS exception that should be thrown when the
data is bad"
Thank you very much.
Mariana


Tom Kyte
January 08, 2005 - 7:25 pm UTC

you've got an order by in a subquery/inline view

In any release, the best would be to remove the function alltogether and just select it out in the view I described above!


(and think about what what too_many_rows means and how this could miss it and how that would mean you don't detect integrity issues the original approach you used would find immediately......)

Order in subquery in ORACLE 8I

A reader, January 09, 2005 - 8:08 am UTC

Hello,Tom,
I invoked with order by in a subquery:

select * into....
(select * from t_dates order by n_date desc) where rownum<=4

in PL/SQL code -Oracle8i in TOAD and it worked.
You wrote above that
In 8i, order by in a subquery/inline view,
will not work in 8i.
I am confused.
Thank you.

Tom Kyte
January 09, 2005 - 11:52 am UTC

guess I was thinking about this:


tkyte@ORA8IW> begin
2 insert into t
3 select 1 from dual order by 1;
4 end;
5 /
select 1 from dual order by 1;
*
ERROR at line 3:
ORA-06550: line 3, column 23:
PLS-00103: Encountered the symbol "ORDER" when expecting one of the following:
. , @ ; return returning <an identifier>
<a double-quoted delimited-identifier> group having intersect
minus partition start subpartition union where connect
SAMPLE_
The symbol "group was inserted before "ORDER" to continue.


tkyte@ORA8IW> insert into t
2 select 1 from dual order by 1;

1 row created.





Cont of sql tunning

Mriana, January 09, 2005 - 2:53 pm UTC

Hello,Tom,
Why only in inserts: insert into t
select 1 from dual order by 1;
the subquery order is not supported in Oracle 8i?
Why anoteher type with subquery with order is supported in Oracle 8i?
Thank you very much.
Mariana.

Tom Kyte
January 09, 2005 - 4:15 pm UTC

don't know. just is.

Continue to make a better sql

A reader, January 09, 2005 - 5:08 pm UTC

Hi,Tom,
You wrote above that the solution to define view and to make select from the view :
select .....,
nvl( (select learnable_prcnt from KM_TMP_PREDICT_BRANCH_EDITIONS
where prod_no = X.prod_no and nwp_date = X.wpr_date ..... ),
(select ...... ) )
from your_table X;

But x.prod_no and x.nwpr_date are the variables in my PL/SQL code,or may be i didn't understand?
Thank you
MARIANA


Tom Kyte
January 09, 2005 - 6:02 pm UTC

they are from "your_table X"

they are correlation variables


I was saying "instead of someone running a query:


for  A in ( select * from your_table where .... )
loop
    call_your_proceudre( a.column1, a.column2 )


they could just run that query


for A in ( select * from view where ... )
loop
    -- no need to call your function, already GOT it.



For example:

ops$tkyte@ORA9IR2> create table t1 ( x int, y int, z int );
 
Table created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create table t2 ( x int, y int, a varchar2(10) );
 
Table created.
 
ops$tkyte@ORA9IR2> create table t3 ( x int, y int, b varchar2(10) );
 
Table created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> insert into t1 select rownum, rownum, rownum from all_users;
 
24 rows created.
 
ops$tkyte@ORA9IR2> insert into t2 select x, y, 't2 ' || z from t1 where mod(x,2)=0;
 
12 rows created.
 
ops$tkyte@ORA9IR2> insert into t3 select x, y, 't3 ' || z from t1 where mod(x,2)=1;
 
12 rows created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace view v
  2  as
  3  select X.x, X.y, X.z,
  4         nvl( (select a from t2 where t2.x = X.x and t2.y = X.y),
  5              (select b from t3 where t3.x = X.x and t3.y = X.y) ) data
  6    from t1 X
  7  /
 
View created.

<b>coder will use that view, instead of this function:</b>
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace
  2  procedure p( p_x in number, p_y in number, p_data out varchar2 )
  3  as
  4  begin
  5      select DATA
  6        into p_data
  7        from ( select a data, 1
  8                 from t2
  9                where t2.x = p_x
 10                  and t2.y = p_y
 11                union all
 12               select b data, 1
 13                 from t3
 14                where t3.x = p_x
 15                  and t3.y = p_y
 16                order by 2 )
 17          where rownum = 1;
 18  end;
 19  /
 
Procedure created.
 

<b>so their code simply becomes:</b>

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> begin
  2      for c in ( select * from v where x in ( 4, 5 ) )
  3      loop
  4          dbms_output.put_line( c.x || ', ' || c.y || ', ' || c.data );
  5      end loop;
  6  end;
  7  /
4, 4, t2 4
5, 5, t3 5
 
PL/SQL procedure successfully completed.

<b>instead of:</b>

 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> declare
  2      l_data varchar2(10);
  3  begin
  4      for c in ( select * from t1 where x in ( 4, 5 ) )
  5      loop
  6          p( c.x, c.y, l_data );
  7          dbms_output.put_line( c.x || ', ' || c.y || ', ' || l_data );
  8      end loop;
  9  end;
 10  /
4, 4, t2 4
5, 5, t3 5
 
PL/SQL procedure successfully completed.
 
 

query tuning

P.Karthick, January 10, 2005 - 6:37 am UTC

hai tom,

today i was writing a query. after compleating the query i was checking the index of the tables for query tuning. the query returns sum 100000 odd records. it was taking few seconds. then i found out that i dint select a specific column which i wanted to retrive but have created the join with the table. so i included that column also in the select statement. to my surprise i found that the query returned the data just like that (i mean it was prity fast)

eg:

my first query

select a.x,a.y from a,b where a.z = b.z

my corrected query

select a.x,a.y,b.m from a,b where a.z=b.z

the second one was faster..

so can you please tell whether this two query makes any difference in performance..

iam using oracle 9i.

Thank you.




Tom Kyte
January 10, 2005 - 8:57 am UTC

you gotta compare plans.

compare the before and after plans.

mismatch datatype

Danny Chen, January 11, 2005 - 4:41 pm UTC

Tom,

create table t1 (col number(2));

Is there any different between the SQL below:

insert into t1 values('4');

insert into t1 values(4);

will it affect the performance of a SQL later?

Tom Kyte
January 11, 2005 - 4:48 pm UTC

the second one is correct, the first one is not correct.

you have a number, not a string, give numbers. you'll have the overhead of an implicit conversion.

(and make sure you use bind variables in real life)

Decode Vs. Union

Ganesh, January 12, 2005 - 4:17 am UTC

Tom,

Please suggest a better query for the below.

SQL> CREATE TABLE emp (eno NUMBER(3), ename VARCHAR2(30), join_date DATE, resign_date DATE)
  2  /

Table created.

SQL> INSERT INTO emp
  2       VALUES (1, 'A', '01-JAN-2005', NULL)
  3  /

1 row created.

SQL> INSERT INTO emp
  2       VALUES (2, 'B', '01-JAN-2005', '09-JAN-2005')
  3  /

1 row created.

SQL> INSERT INTO emp
  2       VALUES (3, 'C', '01-JAN-2005', '30-JAN-2005')
  3  /

1 row created.

SQL> COMMIT
  2  /

Commit complete.

SQL> SELECT eno,
  2         ename,
  3         'Active'
  4    FROM emp
  5   WHERE SYSDATE BETWEEN join_date AND NVL (resign_date, SYSDATE)
  6  UNION
  7  SELECT eno,
  8         ename,
  9         'Not Active'
 10    FROM emp
 11   WHERE SYSDATE NOT BETWEEN join_date AND NVL (resign_date, SYSDATE)
 12  /

       ENO ENAME                          'ACTIVE'
---------- ------------------------------ ----------
         1 A                              Active
         2 B                              Not Active
         3 C                              Active

SQL> SELECT eno,
  2         ename,
  3         DECODE (  DECODE (SIGN (SYSDATE - join_date), 1, 1, 0)
  4                 + DECODE (SIGN (NVL (resign_date, SYSDATE + 1) - SYSDATE), 1, 1, 0),
  5                 2, 'Active',
  6                 'Not Active'
  7                ) "Active"
  8    FROM emp
  9  /

       ENO ENAME                          Active
---------- ------------------------------ ----------
         1 A                              Active
         2 B                              Not Active
         3 C                              Active

SQL> 

Regards,
Ganesh 

Tom Kyte
January 12, 2005 - 8:47 am UTC

you did the work for me. what's wrong with your last very simple query.

you could use CASE of course to make it more readable

case when .... then ....
when ... then....
else ...
end

Query Tunning

Muhammad Riaz Shahid, January 17, 2005 - 1:52 am UTC

Hello Tom !

Consider the example:

create table t(ac_no number(9), fis_dt date, bud_amt1 number(10,2),bud_amt2 number(10,2), bud_amt3 number(10,2));

insert into t values(123,sysdate, 100,200,300);
insert into t values(456,sysdate, 900,300,400);
commit;

Here is the query:

select ac_no, add_months(fis_dt,0), bud_amt1 from t
union all
select ac_no, add_months(fis_dt,1), bud_amt2 from t
union all
select ac_no, add_months(fis_dt,2), bud_amt3 from t
/

It causes 3 FTS to T....i thought we can optimize this one using some decode(max(....)) function. Can you give me a clue ?

Tom Kyte
January 17, 2005 - 8:21 am UTC

if you need three rows, instead of a single row/ac_no with 3 pairs of values -- you either have to

a) union all as you are doing
b) cartesian product this to a 3 row table to output each row 3 times
c) use a pipelined function


you have A), you can search this site for pipelined to see "how to c" and here is b:

ops$tkyte@ORA9IR2> select ac_no,  add_months(fis_dt,r) fis_dt, decode(r,0,bud_amt1,1,bud_amt2,bud_amt3) bud_amt
  2    from t,
  3         (select 0 r from dual union all select 1 from dual union all select 2 from dual )
  4  /
 
     AC_NO FIS_DT       BUD_AMT
---------- --------- ----------
       123 17-JAN-05        100
       456 17-JAN-05        900
       123 17-FEB-05        200
       456 17-FEB-05        300
       123 17-MAR-05        300
       456 17-MAR-05        400
 
6 rows selected.
 

sort for cartesian join (?)

Alberto Dell'Era, January 17, 2005 - 10:13 am UTC

> b) cartesian product this to a 3 row table to output each row 3 times

It may get a bit expensive since it seems that the table gets ordered in memory:

create table t (x) as select rownum from all_objects where rownum <= 10000;

exec dbms_stats.gather_table_stats (user,'t');

explain plan for
select t.x
from t, (select 1 r from dual union all select 2 from dual);

select * from table (dbms_xplan.display);

In 9.2.0.6:

--------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
--------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 163M| 467M| 65366 |
| 1 | MERGE JOIN CARTESIAN| | 163M| 467M| 65366 |
| 2 | VIEW | | 16336 | | 22 |
| 3 | UNION-ALL | | | | |
| 4 | TABLE ACCESS FULL| DUAL | 8168 | | 11 |
| 5 | TABLE ACCESS FULL| DUAL | 8168 | | 11 |
| 6 | BUFFER SORT | | 10000 | 30000 | 65366 |
| 7 | TABLE ACCESS FULL | T | 10000 | 30000 | 4 |
--------------------------------------------------------------------

In 10.1.0.3:

-----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 20000 | 60000 | 14 (0)| 00:00:01 |
| 1 | MERGE JOIN CARTESIAN| | 20000 | 60000 | 14 (0)| 00:00:01 |
| 2 | VIEW | | 2 | | 4 (0)| 00:00:01 |
| 3 | UNION-ALL | | | | | |
| 4 | FAST DUAL | | 1 | | 2 (0)| 00:00:01 |
| 5 | FAST DUAL | | 1 | | 2 (0)| 00:00:01 |
| 6 | BUFFER SORT | | 10000 | 30000 | 14 (0)| 00:00:01 |
| 7 | TABLE ACCESS FULL | T | 10000 | 30000 | 5 (0)| 00:00:01 |
-----------------------------------------------------------------------------

Better in 10g since the cardinality of dual is right,
hence the cardinality of the result set is right too (20,000),
which may be critical if the result set had to be further processed.

But the plan is the same, and it implies a buffer sort of T;
why sorting and then merge joining, especially since the CBO
understands that it is a cartesian product (it says "MERGE JOIN CARTESIAN") ?

Or is this perhaps a "fake" sort, an artifacts of "explain plan" ?
(btw i have dumped the plans from v$sql_plan and they are the same).

Tom Kyte
January 17, 2005 - 11:01 am UTC

it is not being sorted, since there is no key for the join.

there is no sort in this case, there is a buffer (since it knows I'll have to access the same row over and over)

Alberto Dell'Era, January 17, 2005 - 11:14 am UTC

>there is no sort in this case, there is a buffer (since it knows I'll have to
>access the same row over and over)

So in essence it uses the "merge join engine", but disabling the sorting on the two joined sets - and the disabling of the sorts doesn't get reflected on the displayed plan (should read "BUFFER NOSORT", in a manner) ?

Thanks!

Tom Kyte
January 17, 2005 - 11:18 am UTC

yes


Tune the query

A reader, February 11, 2005 - 12:05 pm UTC

Tom,
i have the query ran for more than one hour and used 52 millions logical reads.
the trace shows the index range scan used 1,605,385,980 rows. the table pa_reources is only 6110 rows.
apperently it does too much un-necessary work. please advise on tune the query.

The following are the table sizes:

PA_PROJECTS_ALL
22371

PA_resources
6110

PA_TASKS
723577

P2PA_EXPENDITURES_IMPORT_STG
362270


SELECT
UPPER(P.PROJECT_TYPE) PTYPE,
'PRJ_'||UPPER(S.PROJECT_NUMBER) PROJECT,
'PRJ_'||UPPER(S.PROJECT_NUMBER)||'_TSK_'||UPPER(T.TASK_NUMBER) ACTIVITY,
'EROC_'||UPPER(S.CEFMS_FOA_CODE) EROC,
'ORG_'||UPPER(S.COST_ORG_CODE) RES,
'APS_'||S.APPROP_DEPT_CODE||'_'||S.APPROP_SYMBOL APPROP,
DECODE(SUBSTR(S.ACCOUNT_PERIOD,5,2),
'01','JAN_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'02','FEB_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'03','MAR_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'04','APR_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'05','MAY_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'06','JUN_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'07','JUL_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'08','AUG_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'09','SEP_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'10','OCT_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'11','NOV_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'12','DEC_'||SUBSTR(S.ACCOUNT_PERIOD,3,2)) PERIOD,
SUM(S.PTD_BURDEN_COST+S.PTD_RAW_COST) AMOUNT,
SUM(S.PTD_QUANTITY) HOURS
FROM P2PA_EXPENDITURES_IMPORT_STG S,
APPS.PA_PROJECTS_ALL P,
APPS.PA_TASKS T,
APPS.PA_PROJECT_STATUSES S2,
APPS.PA_RESOURCES R
WHERE P.PROJECT_ID = S.PROJECT_ID
AND P.PROJECT_ID = T.PROJECT_ID
AND P.PROJECT_STATUS_CODE = S2.PROJECT_STATUS_CODE
AND ( SUBSTR(R.NAME,1,7)=S.COST_ORG_CODE or SUBSTR(R.NAME,1,6)=S.COST_ORG_CODE )
AND T.TASK_ID = S.TASK_ID
AND R.RESOURCE_TYPE_ID = '103'
AND T.TASK_ID NOT IN (SELECT DISTINCT Z.PARENT_TASK_ID FROM APPS.PA_TASKS Z WHERE Z.PARENT_TASK_ID IS NOT NULL)
AND P.TEMPLATE_FLAG <> 'Y'
AND P.PM_PROJECT_REFERENCE IS NOT NULL
AND T.TASK_NUMBER <> '1'
AND T.TASK_NUMBER <> '1.0'
AND UPPER(S2.PROJECT_STATUS_NAME) <> 'INVALID'
AND UPPER(S2.PROJECT_STATUS_NAME) <> 'UNAPPROVED - FUTURE'
AND S.TRANSACTION_SOURCE = 'CEFMS_LABOR'
GROUP BY
UPPER(P.PROJECT_TYPE),
'PRJ_'||UPPER(S.PROJECT_NUMBER),
'PRJ_'||UPPER(S.PROJECT_NUMBER)||'_TSK_'||UPPER(T.TASK_NUMBER),
'EROC_'||UPPER(S.CEFMS_FOA_CODE),
'ORG_'||UPPER(S.COST_ORG_CODE),
'APS_'||S.APPROP_DEPT_CODE||'_'||S.APPROP_SYMBOL,
DECODE(SUBSTR(S.ACCOUNT_PERIOD,5,2),
'01','JAN_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'02','FEB_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'03','MAR_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'04','APR_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'05','MAY_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'06','JUN_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'07','JUL_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'08','AUG_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'09','SEP_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'10','OCT_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'11','NOV_'||SUBSTR(S.ACCOUNT_PERIOD,3,2),
'12','DEC_'||SUBSTR(S.ACCOUNT_PERIOD,3,2))
HAVING SUM(S.PTD_BURDEN_COST+S.PTD_RAW_COST) <> 0 OR SUM(S.PTD_QUANTITY) <> 0

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.09 0.09 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 13468 4843.79 5116.61 33625 52066249 62 134665
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 13470 4843.88 5116.70 33625 52066249 62 134665

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 173 (APPS)

Rows Row Source Operation
------- ---------------------------------------------------
134665 FILTER
134869 SORT GROUP BY
270413 FILTER
270414 NESTED LOOPS
270268 HASH JOIN
709993 HASH JOIN
20768 HASH JOIN
36 TABLE ACCESS FULL PA_PROJECT_STATUSES
21430 TABLE ACCESS FULL PA_PROJECTS_ALL
717742 TABLE ACCESS FULL PA_TASKS
270554 TABLE ACCESS FULL P2PA_EXPENDITURES_IMPORT_STG
540680 TABLE ACCESS BY INDEX ROWID PA_RESOURCES
1605385980 INDEX RANGE SCAN (object id 41614)
46373 INDEX RANGE SCAN (object id 41561)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
134665 FILTER
134869 SORT (GROUP BY)
270413 FILTER
270414 NESTED LOOPS
270268 HASH JOIN
709993 HASH JOIN
20768 HASH JOIN
36 TABLE ACCESS GOAL: ANALYZED (FULL) OF
'PA_PROJECT_STATUSES'
21430 TABLE ACCESS GOAL: ANALYZED (FULL) OF
'PA_PROJECTS_ALL'
717742 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'PA_TASKS'
270554 TABLE ACCESS GOAL: ANALYZED (FULL) OF
'P2PA_EXPENDITURES_IMPORT_STG'
540680 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'PA_RESOURCES'
1605385980 INDEX GOAL: ANALYZED (RANGE SCAN) OF
'PA_RESOURCES_N1' (NON-UNIQUE)
46373 INDEX GOAL: ANALYZED (RANGE SCAN) OF 'PA_TASKS_N4'
(NON-UNIQUE)

********************************************************************************


A reader, March 09, 2005 - 11:26 am UTC

IMHO

The optimizer is incorrectly choosing Index with Nested Loop Join for PA_RESOURCES table where as FTS/Hash join might be better. Probably stats are not good and histograms might help in this case

You can even consider running the query in parallel, if you have sufficient memory and CPU

You can even consider increasing the arraysize
to say some 100 or 200

Sql Tuning

Spawn, March 15, 2005 - 3:12 am UTC

Hi Tom,

I know your time is precious but could you please help me with this one. Just some advice on what I can do. Either reconstructing the sql or something. Thanks.

select rev_rese_no, rev_reit_no, count(*) from nx_reservation_items
WHERE trunc(create_date)||'1' > TO_DATE('30-JUN-2004','DD-MON-RRRR')||'1'
having count(*) > 1
GROUP BY rev_rese_no, rev_reit_no

REV_RESE_NO REV_REIT_NO COUNT(*)
----------- ----------- ----------
2476526

Elapsed: 00:05:25.11

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=56383 Card=33352 Byt
es=400224)

1 0 FILTER
2 1 SORT (GROUP BY) (Cost=56383 Card=33352 Bytes=400224)
3 2 TABLE ACCESS (FULL) OF 'NX_RESERVATION_ITEMS' (Cost=55
249 Card=667034 Bytes=8004408)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
562097 consistent gets
503708 physical reads
104 redo size
502 bytes sent via SQL*Net to client
504 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
1 rows processed

Below are the indexes containing the create_date column and it's position in that index.

INDEX_NAME TABLE_NAME COLUMN_NAME COLUMN_POSITION
REIT_TD_REP NX_RESERVATION_ITEMS CREATE_DATE 4
TICKET_DEL_SUMM_REP NX_RESERVATION_ITEMS CREATE_DATE 5

Tom Kyte
March 15, 2005 - 8:08 am UTC

select rev_rese_no, rev_reit_no, count(*)
from nx_reservation_items
WHERE create_date > TO_DATE('30-JUN-2004','DD-MON-RRRR')
GROUP BY rev_rese_no, rev_reit_no
having count(*) > 1


One might ask "whats up with the trunc, ||'1' stuff"

what was the point of that?


if the sole goal is to make this "faster", an index on

(create_date,rev_rese_no, rev_reit_no)

would be called for.

sometime index is used

riyaz, March 24, 2005 - 9:50 am UTC

drop table t1;
drop table t2;
create table t1 (comp_code varchar2(3), control_no number(5),
loc_code varchar2(3));
alter table t1 add constraints pk_t1 primary key(comp_code, control_no);
create table t2 (comp_code varchar2(3), comp_desc varchar2(10));
alter table t2 add constraints pk_t2 primary key(comp_code);

insert into t1(select 'a',rownum,rownum from user_objects);
update t1 set comp_code='b' where rownum<5;

insert into t2 values ('a','aaaa');
insert into t2 values ('b','aaaa');
insert into t2 values ('c','aaaa');

Wrote file afiedt.buf

1 select t1.comp_code, t1.loc_code, t2.comp_desc
2 from t1,t2
3 where t1.comp_code = t2.comp_code
4* and t1.loc_code=1
> /

COM LOC COMP_DESC
--- --- ----------
b 1 bbb


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=5 Bytes=110)
1 0 NESTED LOOPS (Cost=2 Card=5 Bytes=110)
2 1 TABLE ACCESS (FULL) OF 'T2' (Cost=1 Card=1 Bytes=10)
3 1 TABLE ACCESS (FULL) OF 'T1' (Cost=1 Card=5 Bytes=60)




Statistics
----------------------------------------------------------
0 recursive calls
16 db block gets
15 consistent gets
0 physical reads
0 redo size
953 bytes sent via SQL*Net to client
762 bytes received via SQL*Net from client
4 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
1 rows processed

> ed
Wrote file afiedt.buf

1 select t1.comp_code, t1.loc_code, t2.comp_desc
2 from t1,t2
3 where t1.comp_code = t2.comp_code
4* and t1.loc_code='a'
5 /

no rows selected


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=1 Bytes=22)
1 0 NESTED LOOPS (Cost=2 Card=1 Bytes=22)
2 1 TABLE ACCESS (FULL) OF 'T1' (Cost=1 Card=1 Bytes=12)
3 1 TABLE ACCESS (BY INDEX ROWID) OF 'T2' (Cost=1 Card=1 Bytes=10)
4 3 INDEX (UNIQUE SCAN) OF 'PK_T2' (UNIQUE)




Statistics
----------------------------------------------------------
0 recursive calls
4 db block gets
4 consistent gets
0 physical reads
0 redo size
831 bytes sent via SQL*Net to client
653 bytes received via SQL*Net from client
3 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
0 rows processed

Here my question is why full scan has been done when where condition is t1.loc_code=1 (returns rows)
and using index scan when t1.loc_code='a' (which returns no rows)
My point is actually the index to be used if comp_code is there in where condition (filter),but it is not there in either of the sql. But still it is used in sql with where condition loc_code='a'

Acutally in my production, i am facing problem which is similar to the above. I have simulated with examples of t1,t2 table here. Please answer.

Tom Kyte
March 24, 2005 - 3:53 pm UTC

do you see that you are comparing string to number?

does that not concern you?

look at the output from dbms_xplan and you'll see precisely why, look at what your implicit conversions do to the predicates:

ops$tkyte@ORA10GR1> @plan "select t1.comp_code, t1.loc_code, t2.comp_desc from t1,t2 where t1.comp_code = t2.comp_code and t1.loc_code=1"
ops$tkyte@ORA10GR1> delete from plan_table;
 
5 rows deleted.
 
ops$tkyte@ORA10GR1> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select t1.comp_code, t1.loc_code, t2.comp_desc from t1,t2 where t1.comp_code = t2.comp_code and t1.loc_code=1
 
Explained.
 
ops$tkyte@ORA10GR1> select * from table(dbms_xplan.display);
 
PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------------
Plan hash value: 498178312
 
--------------------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |     1 |    16 |     4   (0)| 00:00:01 |
|   1 |  NESTED LOOPS                |       |     1 |    16 |     4   (0)| 00:00:01 |
|*  2 |   TABLE ACCESS FULL          | T1    |     1 |     6 |     3   (0)| 00:00:01 |
|   3 |   TABLE ACCESS BY INDEX ROWID| T2    |     1 |    10 |     1   (0)| 00:00:01 |
|*  4 |    INDEX UNIQUE SCAN         | PK_T2 |     1 |       |     0   (0)| 00:00:01 |
--------------------------------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
 <b>
   2 - filter(TO_NUMBER("T1"."LOC_CODE")=1)    <<<<<==== to_number(COLUMN)
   4 - access("T1"."COMP_CODE"="T2"."COMP_CODE")
 </b>
Note
-----
   - dynamic sampling used for this statement
 
21 rows selected.
 
ops$tkyte@ORA10GR1>
ops$tkyte@ORA10GR1> @plan "select t1.comp_code, t1.loc_code, t2.comp_desc from t1,t2 where t1.comp_code = t2.comp_code and t1.loc_code='1'"
ops$tkyte@ORA10GR1> delete from plan_table;
 
5 rows deleted.
 
ops$tkyte@ORA10GR1> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select t1.comp_code, t1.loc_code, t2.comp_desc from t1,t2 where t1.comp_code = t2.comp_code and t1.loc_code='1'
 
Explained.
 
ops$tkyte@ORA10GR1> select * from table(dbms_xplan.display);
 
PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------------
Plan hash value: 498178312
 
--------------------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |     1 |    16 |     4   (0)| 00:00:01 |
|   1 |  NESTED LOOPS                |       |     1 |    16 |     4   (0)| 00:00:01 |
|*  2 |   TABLE ACCESS FULL          | T1    |     1 |     6 |     3   (0)| 00:00:01 |
|   3 |   TABLE ACCESS BY INDEX ROWID| T2    |     1 |    10 |     1   (0)| 00:00:01 |
|*  4 |    INDEX UNIQUE SCAN         | PK_T2 |     1 |       |     0   (0)| 00:00:01 |
--------------------------------------------------------------------------------------
 
Predicate Information (identified by operation id):
---------------------------------------------------
 <b>
   2 - filter("T1"."LOC_CODE"='1')   <<<<<===== no conversion (
   4 - access("T1"."COMP_CODE"="T2"."COMP_CODE")
 </b>
Note
-----
   - dynamic sampling used for this statement
 
21 rows selected.




compare numbers to numbers
strings to strings
dates to dates


PERIOD 

great explanation

riyaz, March 25, 2005 - 12:32 am UTC

very sorry, When I simulated, I did it wrong. Once started tuning explain plan, it is really interesting and challanging also. (I have your book, effective design by oracle)
Let me give you the production sql itself and explain.

Actually production sql is:
@ORACLE> select distinct control_trace.comp_code comp_code, receive_location loc_code,
2 comp_mas.comp_desc comp_desc
3 from control_trace, comp_mas
4 where control_trace.comp_code = comp_mas.comp_code
5 and control_trace.move_type ='R'
6 and receive_location ='CHU';

I am trying trace for the following:

@ORACLE> select distinct control_trace.comp_code comp_code, receive_location loc_code,
2 comp_mas.comp_desc comp_desc
3 from control_trace, comp_mas
4 where control_trace.comp_code = comp_mas.comp_code
5 and control_trace.move_type ='R'
6 and receive_location ='CHU';
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=28 Card=1407 Bytes=139293)
1 0 HASH JOIN (Cost=28 Card=1407 Bytes=139293)
2 1 TABLE ACCESS (BY INDEX ROWID) OF 'CONTROL_TRACE' (Cost=2 Card=39 Bytes=1365)
3 2 INDEX (RANGE SCAN) OF 'IND_CTRACE_RECLOC' (NON-UNIQUE) (Cost=1 Card=39)
4 1 TABLE ACCESS (FULL) OF 'COMP_MAS' (Cost=25 Card=3608 Bytes=230912)




Statistics
----------------------------------------------------------
0 recursive calls
4 db block gets
527 consistent gets
235 physical reads
0 redo size
3195 bytes sent via SQL*Net to client
1219 bytes received via SQL*Net from client
7 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
51 rows processed

Explanation:
comp_mas has primary key for comp code
control_trace has primary key (comp_code + control_no)
and now I created the index for control_trace.receive_location.

After the index creation, optimizer uses the index of control_trace.receive location. ('IND_CTRACE_RECLOC' )

But it is not using the index of comp_mas.comp_code - why?
Before i created ind_ctrace_recloc, both the tables control_trace and comp_mas was in FULL scan. After creating receive location index, control_trace is using index. But still comp_mas is not using comp_mas(comp_code) - please explain. (I am fully experimenting explain plan with this,
so please answer)

Additional information.
control trace - 307152 records
comp mas - 3608 records
control_trace for location CHU - 274 (the above sql)
the above sql matching records (both table) - 51 records
the abvoe sql with distinct - 4 records

And also tell me, how to rewrite the sql without distinct.











Tom Kyte
March 25, 2005 - 7:46 am UTC

why should it use an index?

go ahead and hint it to use an index and compare the work performed by each using tkprof

the abvove trace output

riyaz, March 25, 2005 - 12:34 am UTC

the above trace output is WITHOUT distinct.

yes. full scan is faster

riyaz, March 25, 2005 - 9:27 am UTC

Yes. it takes more time. Now I clearly understood. Thanks a lot.

select /*+ RULE */ control_trace.comp_code comp_code, receive_location loc_code,
comp_mas.comp_desc comp_desc
from control_trace, comp_mas
where control_trace.comp_code = comp_mas.comp_code
and control_trace.move_type ='R'
and receive_location ='CHU';
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=HINT: RULE
1 0 NESTED LOOPS
2 1 TABLE ACCESS (FULL) OF 'COMP_MAS'
3 1 TABLE ACCESS (BY INDEX ROWID) OF 'CONTROL_TRACE'
4 3 INDEX (RANGE SCAN) OF 'PK_CONTROL_TRACE' (UNIQUE)
Statistics
----------------------------------------------------------
0 recursive calls
4 db block gets
56739 consistent gets
0 physical reads
0 redo size
2224 bytes sent via SQL*Net to client
1037 bytes received via SQL*Net from client
5 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
24 rows processed



Tom Kyte
March 25, 2005 - 6:20 pm UTC

just keep saying to youself

1) "indexes are not all goodness"
2) "fulls scans are not evil incarnate"
3) goto 1)

Not Using Primary key index

Arya, April 07, 2005 - 2:56 pm UTC

Hi Tom,

When I executed the following query and looked at the plan to my surprise it is doing full table scan on contact_persons and not using primary key index on contact_persons table. when I take out full_name from column list and use cp_id then it is using primary key index. full_name is not a indexed column. 

So my question is why is it not using primary key index ?Is this new behaviour or was it like this all the time?

SQL> select cp.cp_id, cp.full_name
       from cp, projects p
      where p.star_project_owner_cp_id = cp.cp_id
        and p.updated_by = 'harish.donthi@gsa.gov';

65 rows selected.
Elapsed: 00:00:00.03
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=374 Card=3461 Bytes=124596)
   1    0   HASH JOIN (Cost=374 Card=3461 Bytes=124596)
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'PROJECTS' (Cost=45 Card=3461 Bytes=58837)
   3    2       INDEX (RANGE SCAN) OF 'PROJ_UPDATED_BY_I' (NON-UNIQUE)(Cost=2 Card=3685)
   4    1     TABLE ACCESS (FULL) OF 'CONTACT_PERSONS' (Cost=317 Card=218114 Bytes=4144166)

Statistics
----------------------------------------------------------
         14  recursive calls
          0  db block gets
       2153  consistent gets
          4  physical reads
          0  redo size
       2258  bytes sent via SQL*Net to client
        547  bytes received via SQL*Net from client
          6  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         65  rows processed

If I create concatenated index with cp_id, full_name then it is doing primary key index scan instead of full table scan.

Thanks
Arya 

Tom Kyte
April 07, 2005 - 4:43 pm UTC

show me.

show me the other plans.

and remember

1) full scans are not evil
2) indexes are not all goodness
3) goto 1 until you believe it


it seems that the optimizer is saying "I don't want to do 3,461 index range scans (that would be 2 or 3 LIO's against the index for each of the 3,461 rows it things it will get) followed by a table access by index rowid.

the real question is why does it think 3,461 rows when there are only 65. how are stats gathered? are they accurate/upto date? is updated_by very skewed?

Not using Primary key index

Arya, April 07, 2005 - 6:05 pm UTC

Hi Tom,

I'm good follower of this site and I read many times you saying that full table scans are not evil and I do agree with that but my question is If I am joining with primary key and fetching only 65 rows then why is it going for full table scan. I have added concatenated index on cp_id and full_name columns of contact_persons table and ran the query again. Here are the results:

SQL> set autotrace traceonly
SQL> select cp.cp_id, cp.full_name
  2         from cp, projects p
  3        where p.star_project_owner_cp_id = cp.cp_id
  4          and p.updated_by = 'harish.donthi@gsa.gov';

65 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=205 Card=3461 Bytes=
          124596)

   1    0   HASH JOIN (Cost=205 Card=3461 Bytes=124596)
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'PROJECTS' (Cost=45 Car
          d=3461 Bytes=58837)

   3    2       INDEX (RANGE SCAN) OF 'PROJ_UPDATED_BY_I' (NON-UNIQUE)
           (Cost=2 Card=3685)

   4    1     INDEX (FAST FULL SCAN) OF 'CP_PK_FULL_NAME_I' (NON-UNIQU
          E) (Cost=148 Card=218114 Bytes=4144166)





Statistics
----------------------------------------------------------
         14  recursive calls
          0  db block gets
       1051  consistent gets
          0  physical reads
          0  redo size
       2257  bytes sent via SQL*Net to client
        547  bytes received via SQL*Net from client
          6  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         65  rows processed

It is using index scan so I have dropped and run again.

SQL> drop index cp_pk_full_name_i;

Index dropped.



SQL> select cp.cp_id, cp.full_name
  2         from cp, projects p
  3        where p.star_project_owner_cp_id = cp.cp_id
  4          and p.updated_by = 'harish.donthi@gsa.gov';

65 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=374 Card=3461 Bytes=
          124596)

   1    0   HASH JOIN (Cost=374 Card=3461 Bytes=124596)
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'PROJECTS' (Cost=45 Car
          d=3461 Bytes=58837)

   3    2       INDEX (RANGE SCAN) OF 'PROJ_UPDATED_BY_I' (NON-UNIQUE)
           (Cost=2 Card=3685)

   4    1     TABLE ACCESS (FULL) OF 'CONTACT_PERSONS' (Cost=317 Card=
          218114 Bytes=4144166)





Statistics
----------------------------------------------------------
         37  recursive calls
          0  db block gets
       2161  consistent gets
       1769  physical reads
          0  redo size
       2258  bytes sent via SQL*Net to client
        547  bytes received via SQL*Net from client
          6  SQL*Net roundtrips to/from client
          4  sorts (memory)
          0  sorts (disk)
         65  rows processed

SQL>

Again it goes for full table scan with out using primary key index. All the statistics are up to date. If I'm joining based on primary key then it should be using primary key am I wrong?

Thanks
Arya 

Tom Kyte
April 07, 2005 - 6:11 pm UTC

did you see the autotrace -- I tried to allude to that above.

Card=3461

the optimizer things 3,461 -- not 65


it was using an INDEX FAST FULL SCAN, which is simply using the index as if it were a skinnier version of the table is all.


the optimizer is saying "no way I'm going to goto the table 3,461 times using 3 LIO's through the index and one more for the table, full scan"

So, why does it think 3,461 when there are apparently only 65. compare a tkprof (actual rowcounts) vs the autotrace and see where they diverge.

Primary key is not used in query

arya, April 08, 2005 - 3:59 pm UTC

Hi Tom,

I'll run the query with tkprof and get back to you if I find any clue.

Thanks
arya

Not using Primary key index

Arya, April 08, 2005 - 6:34 pm UTC

Hi Tom,

I ran the query with sql_trace on but with concatenated primary key and here is the tkprof output for your review.

I request you to help me point out where is the problem.

TKPROF: Release 9.2.0.1.0 - Production on Fri Apr 8 18:22:26 2005

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: devdb_ora_2156.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

alter session set sql_trace=true


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 119 (ELEASER1)
********************************************************************************

select cp.cp_id, cp.full_name
from cp, projects p
where p.star_project_owner_cp_id = cp.cp_id
and p.updated_by = :"SYS_B_0"

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 6 0.00 0.25 115 1046 0 63
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 8 0.00 0.26 115 1046 0 63

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 119 (ELEASER1)

Rows Row Source Operation
------- ---------------------------------------------------
63 HASH JOIN
63 TABLE ACCESS BY INDEX ROWID PROJECTS
63 INDEX RANGE SCAN PROJ_UPDATED_BY_I (object id 61394)
218114 INDEX FAST FULL SCAN CP_PK_FULL_NAME_I (object id 61399)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
63 HASH JOIN
63 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF 'PROJECTS'
63 INDEX GOAL: ANALYZED (RANGE SCAN) OF 'PROJ_UPDATED_BY_I'
(NON-UNIQUE)
218114 INDEX GOAL: ANALYZED (FAST FULL SCAN) OF 'CP_PK_FULL_NAME_I'
(NON-UNIQUE)

********************************************************************************

alter session set sql_trace=false


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.00 0.00 0 0 0 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 119 (ELEASER1)



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 0 0 0
Execute 3 0.00 0.00 0 0 0 0
Fetch 6 0.00 0.25 115 1046 0 63
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 11 0.00 0.26 115 1046 0 63

Misses in library cache during parse: 2
Misses in library cache during execute: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3 0.00 0.00 0 0 0 0
Execute 3 0.00 0.00 0 0 0 0
Fetch 3 0.00 0.00 0 7 0 3
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 0.00 0.00 0 7 0 3

Misses in library cache during parse: 2

3 user SQL statements in session.
3 internal SQL statements in session.
6 SQL statements in session.
1 statement EXPLAINed in this session.
********************************************************************************
Trace file: devdb_ora_2156.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
3 user SQL statements in trace file.
3 internal SQL statements in trace file.
6 SQL statements in trace file.
5 unique SQL statements in trace file.
1 SQL statements EXPLAINed using schema:
ELEASER1.prof$plan_table
Default table was used.
Table was created.
Table was dropped.
75 lines in trace file.


Thanking you,
Arya

Tom Kyte
April 09, 2005 - 7:07 am UTC

why cursoring sharnig = similar|force is on is my first question?



Good point

Arya, April 15, 2005 - 12:10 pm UTC

Hi Tom,

Thanks for pointing out about cursor_sharing parameter since our application is j2ee my dba has put this parameter to force to enable binding I talked to him showed him all your material regarding this parameter and he has changed it to exact, still query plan shows full table scan on contact_persons table without using primary key. My guess is as first step of query it has to fetch 70,000 matching records from projects table it is doing full table scan am I right?

I have another question one of the developer has written a query with 11 table outer join for a report and I don't know how to improve performance of this query, I have looked at explain plan and it seems to be ok so can you outline some ideas regarding this query? tried to create materialized view with on commit but it has a restriction to have unique constraints on the columns invovled in joins of inner tables.

I will appreciate your invaluable help in this regard.

Thanks
Arya

Tom Kyte
April 15, 2005 - 1:18 pm UTC

since your application is j2ee doesn't mean cursor sharing should be on. it means you should be binding when appropriate in the code. google for

sql injection

you've got it big time I'd bet.



but we've been down this path. Do you see the estimated cardinalities there?

it is thinking thousands, it gets 63.

first_rows hint it I guess in this case.

what index is required for this query

sreenivasa rao, April 18, 2005 - 7:07 am UTC

Dear TOM,
 MY production database running on 9.2.0.1 version and is having table like this
SQL> SQL> desc dedup_precook_data
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 DPD_SR_NO                                 NOT NULL NUMBER
 DPD_TABLE_ID                              NOT NULL VARCHAR2(1)
 DPD_ROWID                                 NOT NULL ROWID
 DPD_UPLOADID                                       NUMBER
 DPD_STATUS                                         VARCHAR2(1)
 DPD_LOGIC1                                         NUMBER(25)
 DPD_LOGIC2_1                                       NUMBER(25)
 DPD_LOGIC2_2                                       NUMBER(25)
 DPD_LOGIC3_1                                       NUMBER(25)
 DPD_LOGIC3_2                                       NUMBER(25)
 DPD_LOGIC4_1                                       NUMBER(25)
 DPD_LOGIC4_2                                       NUMBER(25)
 DPD_LOGIC5_1                                       NUMBER(25)
 DPD_LOGIC5_2                                       NUMBER(25)
 DPD_LOGIC6_1                                       NUMBER(25)
 DPD_LOGIC6_2                                       NUMBER(25)
 DPD_LOGIC6_3                                       NUMBER(25)
 DPD_LOGIC6_4                                       NUMBER(25)
 DPD_LOGIC7                                         NUMBER(25)
 DPD_LOGIC8                                         NUMBER(38)
 DPD_LOGIC9_1                                       NUMBER(25)
 DPD_LOGIC9_2                                       NUMBER(25)
 DPD_LOGIC10_1                                      NUMBER(25)
 DPD_LOGIC10_2                                      NUMBER(25)
 DPD_LOGIC11                                        NUMBER(25)
 DPD_LOGIC12                                        NUMBER(25)
 DPD_LOGIC13                                        NUMBER(25)
 DPD_LOGIC14_1                                      NUMBER(38)
 DPD_LOGIC14_2                                      NUMBER(38)
 DPD_LOGIC15                                        NUMBER(25)
 DPD_LOGIC16                                        NUMBER(25)
 DPD_LOGIC18_1                                      NUMBER(25)
 DPD_LOGIC18_2                                      NUMBER(25)
 DPD_LOGIC18_3                                      NUMBER(25)
 DPD_LOGIC7E                                        NUMBER(25)
 DPD_LOGIC7F                                        NUMBER(25)
 DPD_LOGIC7G                                        NUMBER(25)
 DPD_LOGIC20                                        NUMBER(25)
 DPD_LOGIC20_E                                      NUMBER(25)
 DPD_LOGIC20_F                                      NUMBER(25)
 DPD_LOGIC20_G                                      NUMBER(25)
 DPD_LOGIC20_H                                      NUMBER(25)
 DPD_LOGIC20_I                                      NUMBER(25)
 DPD_LOGIC21                                        NUMBER(25)
 DPD_LOGIC22                                        NUMBER(25)
 DPD_LOGIC23                                        NUMBER(25)
 DPD_LOGIC24                                        NUMBER(25)
 DPD_LOGIC25                                        NUMBER(25)

Query running inside a job is 
INSERT INTO gtt_dedup_result
    (drm_sys_id, drm_id_num, drm_comp_appl_id, drm_customerid, drm_table_id, 
     drm_rowid, drm_uploadid)
    (SELECT seq_dedup_result.NEXTVAL, NULL, :b60, :b59, dpd_table_id, dpd_rowid, 
            dpd_uploadid
         FROM (SELECT dp.dpd_table_id dpd_table_id, dp.dpd_rowid dpd_rowid, 
                      dpd_uploadid
                   FROM dedup_precook_data dp
                   WHERE (:b58 = dp.dpd_logic1
                     OR  :b57 = dp.dpd_logic1
                     OR  :b56 = dp.dpd_logic2_1
                     OR  :b55 = dp.dpd_logic2_2
                     OR  :b56 = dp.dpd_logic2_2
                     OR  :b55 = dp.dpd_logic2_1
                     OR  :b54 = dp.dpd_logic3_1
                     AND (:b50 = dp.dpd_logic5_1
                     OR  :b49 = dp.dpd_logic5_1
                     OR  :b50 = dp.dpd_logic5_2
                     OR  :b49 = dp.dpd_logic5_2)
                     OR  :b51 = dp.dpd_logic3_2
                     AND (:b53 = dp.dpd_logic5_1
                     OR  :b52 = dp.dpd_logic5_1
                     OR  :b53 = dp.dpd_logic5_2
                     OR  :b52 = dp.dpd_logic5_2)
                     OR  :b54 = dp.dpd_logic3_1
                     AND (:b53 = dp.dpd_logic5_1
                     OR  :b52 = dp.dpd_logic5_1
                     OR  :b53 = dp.dpd_logic5_2
                     OR  :b52 = dp.dpd_logic5_2)
                     OR  :b51 = dp.dpd_logic3_2
                     AND (:b50 = dp.dpd_logic5_1
                     OR  :b49 = dp.dpd_logic5_1
                     OR  :b50 = dp.dpd_logic5_2
                     OR  :b49 = dp.dpd_logic5_2)
                     OR  :b54 = dp.dpd_logic3_2
                     AND (:b50 = dp.dpd_logic5_1
                     OR  :b49 = dp.dpd_logic5_1
                     OR  :b50 = dp.dpd_logic5_2
                     OR  :b49 = dp.dpd_logic5_2)
                     OR  :b51 = dp.dpd_logic3_1
                     AND (:b53 = dp.dpd_logic5_1
                     OR  :b52 = dp.dpd_logic5_1
                     OR  :b53 = dp.dpd_logic5_2
                     OR  :b52 = dp.dpd_logic5_2)
                     OR  :b54 = dp.dpd_logic3_2
                     AND (:b53 = dp.dpd_logic5_1
                     OR  :b52 = dp.dpd_logic5_1
                     OR  :b53 = dp.dpd_logic5_2
                     OR  :b52 = dp.dpd_logic5_2)
                     OR  :b51 = dp.dpd_logic3_1
                     AND (:b50 = dp.dpd_logic5_1
                     OR  :b49 = dp.dpd_logic5_1
                     OR  :b50 = dp.dpd_logic5_2
                     OR  :b49 = dp.dpd_logic5_2)
                     OR  :b48 = dp.dpd_logic4_1
                     OR  :b47 = dp.dpd_logic4_1
                     OR  :b46 = dp.dpd_logic4_1
                     OR  :b45 = dp.dpd_logic4_1
                     OR  :b44 = dp.dpd_logic4_2
                     OR  :b43 = dp.dpd_logic4_2
                     OR  :b42 = dp.dpd_logic4_2
                     OR  :b41 = dp.dpd_logic4_2
                     OR  :b40 = dp.dpd_logic6_1
                     OR  :b40 = dp.dpd_logic6_3
                     OR  :b39 = dp.dpd_logic6_1
                     OR  :b39 = dp.dpd_logic6_3
                     OR  :b38 = dp.dpd_logic6_1
                     OR  :b38 = dp.dpd_logic6_3
                     OR  :b37 = dp.dpd_logic6_1
                     OR  :b37 = dp.dpd_logic6_3
                     OR  :b36 = dp.dpd_logic7
                     OR  :b35 = dp.dpd_logic7
                     OR  :b34 = dp.dpd_logic20
                     OR  :b33 = dp.dpd_logic8
                     OR  :b32 = dp.dpd_logic8
                     OR  :b31 = dp.dpd_logic9_1
                     OR  :b30 = dp.dpd_logic9_1
                     OR  :b29 = dp.dpd_logic9_2
                     OR  :b28 = dp.dpd_logic9_2
                     OR  :b27 = dp.dpd_logic10_1
                     OR  :b26 = dp.dpd_logic10_1
                     OR  :b25 = dp.dpd_logic10_2
                     OR  :b24 = dp.dpd_logic10_2
                     OR  :b23 = dp.dpd_logic15
                     OR  :b22 = dp.dpd_logic15
                     OR  :b21 = dp.dpd_logic18_1
                     OR  :b20 = dp.dpd_logic18_2
                     OR  :b19 = dp.dpd_logic18_3
                     OR  :b18 = dp.dpd_logic21
                     OR  :b17 = dp.dpd_logic21
                     OR  :b16 = dp.dpd_logic21
                     OR  :b15 = dp.dpd_logic21
                     OR  :b14 = dp.dpd_logic21
                     OR  :b13 = dp.dpd_logic21
                     OR  :b18 = dp.dpd_logic22
                     OR  :b17 = dp.dpd_logic22
                     OR  :b16 = dp.dpd_logic22
                     OR  :b15 = dp.dpd_logic22
                     OR  :b14 = dp.dpd_logic22
                     OR  :b13 = dp.dpd_logic22
                     OR  :b18 = dp.dpd_logic23
                     OR  :b17 = dp.dpd_logic23
                     OR  :b16 = dp.dpd_logic23
                     OR  :b15 = dp.dpd_logic23
                     OR  :b14 = dp.dpd_logic23
                     OR  :b13 = dp.dpd_logic23
                     OR  :b12 = dp.dpd_logic7e
                     OR  :b11 = dp.dpd_logic7e
                     OR  :b10 = dp.dpd_logic7e
                     OR  :b9 = dp.dpd_logic7e
                     OR  :b8 = dp.dpd_logic7e
                     OR  :b7 = dp.dpd_logic7e
                     OR  :b6 = dp.dpd_logic7e
                     OR  :b5 = dp.dpd_logic7e
                     OR  :b4 = dp.dpd_logic7e
                     OR  :b3 = dp.dpd_logic7e
                     OR  :b2 = dp.dpd_logic7e
                     OR  :b1 = dp.dpd_logic7e)
                     AND dp.dpd_status = 'A'))
explain plan

3  INSERT STATEMENT 
2  . SEQUENCE 
1  SCB.DEDUP_PRECOOK_DATA TABLE ACCESS [FULL 

here dedup_precook_data table size is 4Gb.
Kindly advise me,how to tune this query?
is there any index recommonded?

regards,
sreenivas
 

Tom Kyte
April 18, 2005 - 7:20 am UTC

wow.

anyway, the only thing that would pop to mind would be single column bitmap indexes on each of dpd_logic7e, dpd_logic_22, ..... (the columns you and/or together)

single column, not concatenated.

and only if this 4gig table is read mostly.

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:32633204077527 <code>

see that page and read/understand the 3 pointed to articles before you issue a create bitmap index statement in your database.

thanks for the blistering speed of your site and response.

A reader, April 18, 2005 - 9:49 am UTC

Tom,really your the best


Re: what index is required for this query

Gabe, April 18, 2005 - 11:09 am UTC

Long shot … but if dp.dpd_status = 'A' is _very_ selective then an index on dpd_status may suffice.

<quote>Query running inside a job is …</quote>
If the job is infrequent then maybe the binds are a bit of overkill.


Tom Kyte
April 18, 2005 - 11:36 am UTC

good eye, I didn't match up parenthesis that spanned pages :)



single column bitmap indexes

sreenivasa rao, April 19, 2005 - 12:38 am UTC

Dear Tom,
Once again thanks for the above clarification.
could you clarify these doubts.
1a. if star_trnsformation_enabled is set to true,does all the foreign key columns need single column bitmap indexes or concatenated index on all foreign key columns
1b. would Btree indexes work for the same.

could you clarify this concept with your commanding skills.
2.i have a database with 9.2.0 having table like this.
one primary key.
10 foreign keys.
5 general columns

would it be good to enable star_transformation on the quries having these type of tables(PK,lot of FKs, and some general columns).
as you expect this table having lot of joins with it's child tables in quries..(here i am specific about general keys also.)

regards
sreenivas




Tom Kyte
April 19, 2005 - 7:23 am UTC

Any thoughts on this query it seems to be taking a long time

Juan, April 27, 2005 - 10:21 am UTC

select WORK_GROUP, WORK_GROUP_DESCRIPTION, SECTION_CODE, SECTION_DESCRIPTION, QUEUE_CODE,
QUEUE_DESCRIPTION, ALLOCATED_MACHINES, AVAILABLE_MACHINE_NUM, MOVES,
ORDERS_PER_MACHINES, UNSLOTTED_ORDERS, UNSLOTTED_TRUCKS, AVAILABLE_SLOTS,
PROBLEM_MOVES ) AS SELECT work_group,
work_group_description,
section_code,
section_description,
queue_code,
queue_description,
allocated_machines,
available_machine_num,
(moves - PROBLEM_MOVES) MOVES,
orders_per_machines,
unslotted_orders,
unslotted_trucks,
(CASE WHEN unslotted_orders = 0 OR available_slots < 0 THEN 0
ELSE NVL(available_slots ,0) END) available_slots
,PROBLEM_MOVES

FROM
(
SELECT wq.*
,NVL(m.Allocated_machines,0) Allocated_machines
,NVL(m.Available_machine_num,0) Available_machine_num
,NVL(ord.moves,0) MOVES
,NVL2(m.Available_machine_num,NVL(ord.moves,0)-NVL(PROBLEM_MOVES ,0),0)/ (CASE WHEN m.Available_machine_num = 0 OR m.Available_machine_num IS NULL THEN 1
ELSE m.Available_machine_num
END) Orders_per_machines
,NVL(ord.unslotted_orders,0) unslotted_orders
,NVL(ord.unslotted_trucks,0) unslotted_trucks
, (select slots#
from(
select s.code,COUNT(*) slots#
from yard_blocks b,sections s, sam_rows r
where b.block_type ='L'
and b.yard_id = (select yard_id from yards where yard_id = b.yard_id and active =1)
and s.slotline = b.block_name
AND r.rowno <= b.number_of_rows
AND yard_pkg.isLocationBlockedOut_FUNC(b.block_name,r.rowno) = 'N'
GROUP BY s.code

)
where code = wq.section_code) - ord.slotted_orders Available_slots
,NVL(PROBLEM_MOVES ,0) PROBLEM_MOVES

FROM
(SELECT GQ.WORK_GROUP_CODE Work_group
,G.Description Work_group_description
,s.code section_code
,s.description SECTION_DESCRIPTION
,GQ.WORK_QUEUE_CODE QUEUE_CODE
,q.description QUEUE_DESCRIPTION
FROM work_group_queues gq,Work_groups G, Work_queues Q, (select code,description FROM sections union all SELECT 'ALL', 'ALL SECTIONS' FROM DUAL) s
WHERE gq.work_group_code = g.code
AND gq.work_queue_code = q.code
) wq, (SELECT distinct NVL(section_code,'ALL') SECTION_CODE,queue_code
,COUNT(machine_id) over (partition by NVL(section_code,'ALL'), queue_code) Allocated_machines
,SUM(CASE WHEN (mo.mode_code ='ON' OR Mo.mode_code = 'NIS') AND mo.driver_username IS NOT NULL AND mo.all_sections = 'Y'
THEN 1
WHEN (mo.mode_code ='ON' OR Mo.mode_code = 'NIS') AND mo.driver_username IS NOT NULL AND mo.all_sections = 'N'
THEN 1
ELSE NULL
END) Over (partition by NVL(section_code,'ALL'), queue_code) Available_machine_num
FROM machine_orders mo) m,
((SELECT *
FROM(
SELECT DISTINCT w.section_code,
CASE WHEN w.queue_code = 'TRUCK' AND w.slotted_date IS NOT NULL THEN 'TRUCK'
WHEN w.queue_code = 'TRUCK' AND w.slotted_date IS NULL THEN null
ELSE w.queue_code
END queue_code
, count(*) over (partition by w.section_code,
CASE
WHEN w.queue_code = 'TRUCK' AND w.slotted_date IS NOT NULL
THEN 'TRUCK'
WHEN w.queue_code = 'TRUCK' AND w.slotted_date IS NULL
THEN NULL
ELSE w.queue_code
END) MOVES
, SUM(CASE WHEN w.queue_code = 'TRUCK' THEN NVL2(w.slotted_date,0,1) ELSE NULL END) over (partition by w.section_code, w.queue_code) Unslotted_orders
, SUM(CASE WHEN w.queue_code = 'TRUCK' THEN NVL2(w.slotted_date,1,0) ELSE NULL END) over (partition by w.section_code, w.queue_code) slotted_orders
, SUM(CASE WHEN w.queue_code = 'TRUCK' THEN NVL2(w.slotted_date,0,NVL((select 1 FROM gate_containers gc
where
gc.visit = w.visit
and gc.reference_id = w.visit_ref_id
and gc.voided_date is NULL
),0)
)
ELSE NULL END) OVER (PARTITION BY w.section_code,w.queue_code) UNSLOTTED_TRUCKS
, SUM(CASE WHEN w.order_problem = 'Y'
OR w.hold = 'Y'
OR w.status_code = 'I' AND w.move_type = 'D'
AND w.reefer = 1 AND w.plug_unplug = 'P'
THEN 1
ELSE 0
END) OVER (PARTITION BY w.section_code,w.queue_code)PROBLEM_MOVES
FROM
(SELECT wo.order_id,wo.queue_code,wo.slotted_date, wo.assigned_date,wo.visit,wo.visit_ref_id,wo.to_block,wo.inv_container_id
, (CASE WHEN wo.queue_code = 'TRUCK' AND wo.slotted_date IS NULL
THEN (SELECT gc.section_code FROM gate_containers gc WHERE gc.visit = wo.visit AND gc.reference_id = wo.visit_ref_id)
WHEN wo.queue_code = 'TRUCK' AND wo.slotted_date IS NOT NULL
THEN get_section_func( case when wo.move_type ='R' OR wo.move_type = 'Y'
then ic.L1
when wo.move_type = 'D' then wo.to_block
else null
end
)
ELSE NVL2( wo.machine_id
, (Select NVL(section_code,'ALL') from machine_orders mo where mo.machine_id = wo.machine_id)
, get_section_func (
CASE WHEN yard_pkg.get_block_area_FUNC(ic.L1) = 'RAIL '
THEN wo.to_block
ELSE ic.L1
END
)
)
END) SECTION_CODE
,wo.hold
,wo.order_problem
,wo.move_type
,ic.reefer
,ic.status_code
,ic.plug_unplug
FROM work_orders wo, inv_containers ic
WHERE wo.inv_container_id = ic.container_id(+)
) w
) WHERE queue_code IS NOT NULL
)
UNION ALL
(SELECT DISTINCT 'ALL',mo.queue_code,NULL, NULL,NULL,null,NULL
FROM machine_orders mo
WHERE
mo.all_sections = 'Y'
AND NOT EXISTS (SELECT 'x' FROM work_orders wo
WHERE wo.machine_id = mo.machine_id
OR wo.queue_code = mo.queue_code
)
)
UNION ALL
(SELECT DISTINCT mo.section_code,mo.queue_code,NULL, NULL,NULL,NULL,NULL
FROM machine_orders mo
WHERE
mo.all_sections = 'N'
AND NOT EXISTS (SELECT 'x' FROM work_orders wo,inv_containers ic
WHERE
wo.inv_container_id = ic.container_id(+)
AND
(CASE WHEN wo.queue_code = 'TRUCK' AND wo.slotted_date IS NULL
THEN (SELECT gc.section_code FROM gate_containers gc WHERE gc.visit = wo.visit AND gc.reference_id = wo.visit_ref_id)
WHEN wo.queue_code = 'TRUCK' AND wo.slotted_date IS NOT NULL
THEN
get_section_func( case when wo.move_type ='R' OR wo.move_type = 'Y'
then ic.L1
when wo.move_type = 'D' then wo.to_block
else null
end
)
ELSE get_section_func (
CASE WHEN yard_pkg.get_block_area_FUNC(ic.L1) = 'RAIL'
THEN wo.to_block
ELSE ic.L1
END
)
END) = mo.section_code
AND wo.queue_code = mo.queue_code
)
)

) ord
where wq.section_code = m.section_code(+)
AND wq.queue_code =m.queue_code(+)
AND wq.section_code = ord.section_code
AND wq.queue_code = ord.queue_code
)


Tom Kyte
April 27, 2005 - 10:30 am UTC

it is really "long" :) sorry -- too big to sort of look at here.


things like:

get_section_func (
CASE WHEN
yard_pkg.get_block_area_FUNC(ic.L1) = 'RAIL'
THEN
wo.to_block
ELSE ic.L1
END
)
END) = mo.section_code


won't be "fast" (calling lots of plsql from sql). I'd be looking to remove them.

How can I write in the SQL as suppose to call it?

Juan, April 27, 2005 - 12:24 pm UTC

FUNCTION isActivatedBlock_FUNC(block_name_in yard_blocks.block_name%TYPE)
RETURN BOOLEAN
IS
TYPE actblk_cur_ref IS REF CURSOR;
actblk_cur actblk_cur_ref;
v_blk_exist VARCHAR2(1) := NULL;
BEGIN
OPEN actblk_cur FOR
'SELECT ''x''
FROM yards y, yard_blocks yb
WHERE y.yard_id = yb.yard_id
AND y.active = 1
AND yb.block_name = :1'
USING block_name_in;
FETCH actblk_cur INTO v_blk_exist;
CLOSE actblk_cur;

IF v_blk_exist IS NOT NULL THEN
RETURN TRUE;
ELSE
RETURN FALSE;
END IF;

EXCEPTION
WHEN OTHERS THEN
File_Pkg.log_alert(YARDMSG,'isActivatedBlock_FUNC -- '||TO_CHAR(SQLCODE)||SQLERRM);
RETURN FALSE;

Tom Kyte
April 27, 2005 - 12:30 pm UTC

man oh man, the dreaded "when others" that doesn't let the caller know "hey, something horrible has happened". Instead it says "lets trick that guy into thinking everything is OKEY DOKEY"......

dynamic sql when none is called for....

in sql, you can


select ....,
nvl( (select 'Y' from yards y, yard_blocks yb
where ... yb.block_name = OUTER_QUERY.BLOCK_NAME), 'N' ) isactive,
....
from (whatever) OUTER_QUERY;

just use a scalar subquery. if need be, add "and rownum=1" to the scalar subquery.

query issues

whizkid, May 09, 2005 - 10:27 am UTC

Tom, we have this query which gets executed around 40 times in half an hour window (from statspack report). 

SELECT (-1) * SUM(A.POSTING_AMT) FROM ACC_POSTINGS A , AC_INTERNAL_ACCOUNTS C
WHERE A.INTERNAL_ACCOUNT_ID = C.INTERNAL_ACCOUNT_ID
AND C.SUBFACTOR_1_VAL = :B2 AND C.ACCOUNT_CATEGORY_CODE = '2111200001'
AND A.EFFECTIVE_DATE <= :B1 HAVING SUM(POSTING_AMT) < 0

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.92      28.03       5219       6099          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.92      28.04       5219       6099          0           1

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: SYS

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  FILTER
      1   SORT AGGREGATE
   3355    TABLE ACCESS BY GLOBAL INDEX ROWID OBJ#(66995) PARTITION: ROW LOCATION ROW LOCATION
   3357     NESTED LOOPS
      1      TABLE ACCESS BY INDEX ROWID OBJ#(48196)
  30881       INDEX RANGE SCAN OBJ#(48199) (object id 48199)
   3355      PARTITION RANGE ITERATOR PARTITION: KEY KEY
   3355       INDEX RANGE SCAN OBJ#(67385) PARTITION: KEY KEY (object id 67385)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  db file sequential read                      5219        0.11         26.88
  global cache cr request                      2671        0.00          0.63
  SQL*Net message from client                     2        5.12          5.12


SQL> select table_name, num_rows from dba_tables where table_name in ('ACC_POSTINGS','AC_INTERNAL_ACCOUNTS');

TABLE_NAME                       NUM_ROWS
------------------------------ ----------
AC_INTERNAL_ACCOUNTS             12975806
ACC_POSTINGS                     30870700

The ACC_POSTINGS table is partitioned on batch_id column. It is not being used in this query but it is in lots of other queries. The AC_INTERNAL_ACCOUNTS table is not partitioned. The explain plan could not be any better

SQL> explain plan for
  2  SELECT (-1) * SUM(A.POSTING_AMT) FROM ACC_POSTINGS A , AC_INTERNAL_ACCOUNTS C
  3  WHERE A.INTERNAL_ACCOUNT_ID = C.INTERNAL_ACCOUNT_ID
  4  AND C.SUBFACTOR_1_VAL = :B2 AND C.ACCOUNT_CATEGORY_CODE = '2111200001'
  5  AND A.EFFECTIVE_DATE <= :B1 HAVING SUM(POSTING_AMT) < 0
  6  /

Explained.

Elapsed: 00:00:00.10
SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------

--------------------------------------------------------------------------------------------------------------
| Id  | Operation                            |  Name                 | Rows  | Bytes | Cost  | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |                       |     1 |    44 |     8 |       |       |
|*  1 |  FILTER                              |                       |       |       |       |       |       |
|   2 |   SORT AGGREGATE                     |                       |     1 |    44 |       |       |       |
|*  3 |    TABLE ACCESS BY GLOBAL INDEX ROWID| ACC_POSTINGS          |     1 |    19 |     3 | ROWID | ROW L |
|   4 |     NESTED LOOPS                     |                       |     1 |    44 |     8 |       |       |
|*  5 |      TABLE ACCESS BY INDEX ROWID     | AC_INTERNAL_ACCOUNTS  |     1 |    25 |     5 |       |       |
|*  6 |       INDEX RANGE SCAN               | IND_ACINTACC_SF1VAL   |     3 |       |     3 |       |       |
|   7 |      PARTITION RANGE ITERATOR        |                       |       |       |       |   KEY |   KEY |
|*  8 |       INDEX RANGE SCAN               | ACC_P_IX_1            |     2 |       |     2 |   KEY |   KEY |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(SUM("A"."POSTING_AMT")<0)
   3 - filter("A"."EFFECTIVE_DATE"<=:Z)
   5 - filter("C"."ACCOUNT_CATEGORY_CODE"='2111200001')
   6 - access("C"."SUBFACTOR_1_VAL"=:Z)
   8 - access("A"."INTERNAL_ACCOUNT_ID"="C"."INTERNAL_ACCOUNT_ID")

Note: cpu costing is off

25 rows selected.

It's waiting on sequential read. Is there anything that I could do to reduce the wait time? What about partitioning the other table on INTERNAL_ACCOUNT_ID and a global index on that column? I have done that in test env but it has not made any improvement. (well it's the same enviroment)You comments will be really appreciated. This is a Oracle 9.2.0.5 2 node RAC on IBM AIX 5.2 

Tom Kyte
May 09, 2005 - 10:54 am UTC

well, the explain plan might *LOOK* ok, but the tkprof shows a real problem:

Rows Row Source Operation
------- ---------------------------------------------------
1 FILTER
1 SORT AGGREGATE
3355 TABLE ACCESS BY GLOBAL INDEX ROWID OBJ#(66995) PARTITION: ROW .....
3357 NESTED LOOPS
1 TABLE ACCESS BY INDEX ROWID OBJ#(48196)
30881 INDEX RANGE SCAN OBJ#(48199) (object id 48199)

3355 PARTITION RANGE ITERATOR PARTITION: KEY KEY
3355 INDEX RANGE SCAN OBJ#(67385) PARTITION: KEY KEY (object id 67385)


we hit the table 30,881 times -- to find a SINGLE ROW!


I don't know, but I might rather have:

C.INTERNAL_ACCOUNT_ID
AND C.SUBFACTOR_1_VAL = :B2 AND C.ACCOUNT_CATEGORY_CODE = '2111200001'

those three columns in a concatenated index -- at a glance. I'd want to avoid having to hit the table 10's of thousands of times needlessly.

cont. of above

whizkid, May 09, 2005 - 10:32 am UTC

sorry i meant to say the test enviroment is not the same.. it's a single instance.

amazing..

whizkid, May 09, 2005 - 12:30 pm UTC

words fail me.. worked like a charm.. < 1 sec.. seeing such limited information, how did you make such a brilliant suggestion? if you could share how you got idea to concatenate all the three columns, it would really help in my approach towards tuning queries in future.

Tom Kyte
May 09, 2005 - 1:40 pm UTC

1 TABLE ACCESS BY INDEX ROWID OBJ#(48196)
30881 INDEX RANGE SCAN OBJ#(48199) (object id 48199)

When I see that you got hits from the index 30,881 times

And went to the table 30,881 times...

To get a single row.....


I think "missing a column or two in the index perhaps, so we don't have to go index->table, index-> table and so on..."

tom anything thoughts on how I can improve this query

Janis, May 10, 2005 - 12:25 pm UTC

SELECT wo.order_id, ic.l1, ic.l2, ic.l3, wo.to_block, wo.to_row, wo.to_stack, ic.out_vessel_code,
ic.status_code, ic.container_id, ic.hazardous, ic.out_of_service, ic.over_dimensions,
ic.reefer, wo.manual_location, cm.ssl_owner_code, cm.lht_code, ic.gross_weight,
wo.move_type, ic.out_port_of_discharge,ic.In_mode,ic.container,ic.out_mode
FROM work_orders wo, inv_containers ic, container_masters cm
WHERE wo.queue_code = 'EXREL' AND wo.assigned_date is null AND wo.HOLD ='N'
AND wo.ORDER_PROBLEM IS NULL AND 70000 > ic.gross_weight
AND MOVE_TYPE = 'Y' AND wo.INV_CONTAINER_ID = ic.CONTAINER_ID
AND (SELECT max(yb.yard_id) FROM yard_blockouts_temp yb, tml_blockout_reasons t, Yards y
WHERE t.safety_blockout = 'Y' AND Y.ACTIVE = 1
AND ic.l1 = yb.l1 AND (ic.l2 = yb.l2 OR yb.l2 IS null)
AND y.yard_id = yb.yard_id AND yb.reason_code = t.code) is null

AND ((ic.reefer = 1 and plug_unplug = 'U') OR (ic.reefer = 0))
AND (('EXREL' = 'EXREL'
AND (SELECT count(1) FROM container_holds where container = ic.CONTAINER) = 0)
OR 'EXREL' <> 'EXREL')
AND ic.CONTAINER = cm.CONTAINER
ORDER BY wo.priority,ic.l1,ic.l2,ic.l3 asc, ic.l4 DESC



Tom Kyte
May 10, 2005 - 1:49 pm UTC

using cbo I would be tempted to replace

AND (SELECT count(1) FROM container_holds where container =
ic.CONTAINER) = 0)
OR 'EXREL' <> 'EXREL')

with

and ic.container not in ( select container
from container_holds
where container is not null )


and it looks like the other subquery is a "not in" candidate as well perhaps.

thanks!!!

A reader, May 10, 2005 - 1:53 pm UTC


Rewrite SQL

mo, May 17, 2005 - 8:09 am UTC

Hi Tom,

Is there a way to improve the SQL or any rewrite oppurtunity ? Thanks in advance.

GL_JE_HEADERS.NAME has a lots of distinct value.

GL_JE_HEADERS consists of 559130 rows
GL_JE_BATCHES consists of 220578 rows

INDEXES
GL_JE_HEADERS_U1 HEADER_ID 1
GL_JE_HEADERS_U2 NAME 1
GL_JE_HEADERS_U2 JE_BATCH_ID 2
GL_JE_BATCHES_U1 JE_BATCH_ID 1

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6694 Card=140274 Byt
es=9117810)

1 0 SORT (GROUP BY) (Cost=6694 Card=140274 Bytes=9117810)
2 1 NESTED LOOPS (Cost=3154 Card=483222 Bytes=31409430)
3 2 TABLE ACCESS (FULL) OF 'GL_JE_HEADERS' (Cost=3154 Card
=484116 Bytes=28562844)

4 2 INDEX (UNIQUE SCAN) OF 'GL_JE_BATCHES_U1' (UNIQUE)

===================SQL Statement================
select
jeh.name
from
gl.GL_JE_HEADERS jeh ,
gl.gl_je_batches bej
where
jeh.JE_HEADER_ID > 5000 and
jeh.je_batch_id = bej.je_batch_id and
jeh.JE_SOURCE NOT IN('Assets','Intercompany') and
jeh.NAME NOT IN ('Addition','Adjustment')
group by
jeh.name

=================================================

Rgds
Mo

Tom Kyte
May 17, 2005 - 9:19 am UTC

wow, I cannot believe that is using an index. did you set the optimizer_* parameters way to the left here?

you don't have hash joins disabled do you?

hint it to be ALL_ROWS and let it hash join.

Join not needed?

Todor Botev, May 17, 2005 - 1:06 pm UTC

Just a short question to the above query to clarify the data logic:

You do not select anything from "gl_je_batches". Could it be that you do not need the join with "gl_je_batches" at all?

Can the column "jeh.je_batch_id" have values other than the ones in the table "gl_je_batches". Is there any kind of foreign key between the two tables?


Thanks for your valuable input

Mo, May 18, 2005 - 4:53 am UTC

Hi Tom,

Thanks for your input. We have upgraded the database from 8.1.7.4 to 9.2.0.5 recently but never modify the optimizer_*. The optimizer engine seems like favor NL instead of HASH join. Just wonder why is the HASH join is better option over NL for my case. Is it coz of the driving table (GL_JE_BATCHES 220578 rows) which is consider big ?

Current Setting.
optimizer_index_caching integer 0
optimizer_index_cost_adj integer 100
hash_area_size integer 131072
hash_join_enabled boolean TRUE

I have gathered the plan & stat for the diff scenarios.

CURRENT PLAN (PLAN 0)
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6694 Card=140274 Byt
es=9117810)

1 0 SORT (GROUP BY) (Cost=6694 Card=140274 Bytes=9117810)
2 1 NESTED LOOPS (Cost=3154 Card=483222 Bytes=31409430)
3 2 TABLE ACCESS (FULL) OF 'GL_JE_HEADERS' (Cost=3154 Card
=484116 Bytes=28562844)

4 2 INDEX (UNIQUE SCAN) OF 'GL_JE_BATCHES_U1' (UNIQUE)


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 7019 8.85 17.36 20778 329691 0 105261
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7021 8.85 17.37 20778 329691 0 105261

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 177 (ONSEMI)

Rows Row Source Operation
------- ---------------------------------------------------
105261 SORT GROUP BY
308888 NESTED LOOPS
308888 TABLE ACCESS FULL OBJ#(33979)
308888 INDEX UNIQUE SCAN OBJ#(33939) (object id 33939)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
105261 SORT (GROUP BY)
308888 NESTED LOOPS
308888 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'GL_JE_HEADERS'
308888 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF 'GL_JE_BATCHES_U1'
(UNIQUE)


PLAN 1
USE HASH HINT (USE_HASH)

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=7890 Card=140274 Byt
es=9117810)

1 0 SORT (GROUP BY) (Cost=7890 Card=140274 Bytes=9117810)
2 1 HASH JOIN (Cost=4350 Card=483222 Bytes=31409430)
3 2 INDEX (FULL SCAN) OF 'GL_JE_BATCHES_U1' (UNIQUE) (Cost
=613 Card=220050 Bytes=1320300)

4 2 TABLE ACCESS (FULL) OF 'GL_JE_HEADERS' (Cost=3154 Card
=484116 Bytes=28562844)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 7019 8.46 19.38 20790 21415 0 105261
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7021 8.46 19.38 20790 21415 0 105261

Rows Row Source Operation
------- ---------------------------------------------------
105261 SORT GROUP BY
308888 HASH JOIN
220614 INDEX FULL SCAN OBJ#(33939) (object id 33939)
308888 TABLE ACCESS FULL OBJ#(33979)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
105261 SORT (GROUP BY)
308888 HASH JOIN
220614 INDEX GOAL: ANALYZED (FULL SCAN) OF 'GL_JE_BATCHES_U1'
(UNIQUE)
308888 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'GL_JE_HEADERS'

PLAN 2
alter session set optimizer_index_cost_adj =30;
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=5600 Card=140274 Byt
es=9117810)

1 0 SORT (GROUP BY) (Cost=5600 Card=140274 Bytes=9117810)
2 1 TABLE ACCESS (BY INDEX ROWID) OF 'GL_JE_HEADERS' (Cost=2
Card=2 Bytes=118)

3 2 NESTED LOOPS (Cost=2060 Card=483222 Bytes=31409430)
4 3 INDEX (FULL SCAN) OF 'GL_JE_BATCHES_U1' (UNIQUE) (Co
st=613 Card=220050 Bytes=1320300)

5 3 INDEX (RANGE SCAN) OF 'GL_JE_HEADERS_N1' (NON-UNIQUE
) (Cost=2 Card=6)


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 7019 22.28 66.46 23176 595352 0 105261
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7021 22.29 66.47 23176 595352 0 105261

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 177 (ONSEMI)

Rows Row Source Operation
------- ---------------------------------------------------
105261 SORT GROUP BY
308888 TABLE ACCESS BY INDEX ROWID OBJ#(33979)
779786 NESTED LOOPS
220614 INDEX FULL SCAN OBJ#(33939) (object id 33939)
559171 INDEX RANGE SCAN OBJ#(33988) (object id 33988)

Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
105261 SORT (GROUP BY)
308888 NESTED LOOPS
779786 TABLE ACCESS GOAL: ANALYZED (FULL) OF 'GL_JE_HEADERS'
220614 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF 'GL_JE_BATCHES_U1'
(UNIQUE)

Not much gain from CPU resource when changing from NL (8.85) to HASH join (8.46) but there is a major improvement in query (21415 for HASH and 329691 for NL).
When I look at the Explain Plan, the total cost for NL is smaller than HASH. Why is that so?
SELECT STATEMENT Optimizer=CHOOSE (Cost=7890) for HASH
SELECT STATEMENT Optimizer=CHOOSE (Cost=6694) for NL

I tried to force the PLAN to use the index by changing the value of optimizer_index_cost_adj=30. No luck. The performance becomes worst.

Rgds
Mo

Any thoughts on this query. It taking a few min. to run

lou, May 18, 2005 - 5:08 pm UTC

SELECT ssl_user_code,
i.container,
out_date,
cl.code LENGTH_CODE,
out_trucker_code,
decode ((SELECT ih.in_date
FROM his_containers ih
WHERE ih.container = i.container
AND ih.container_id > i.container_id
AND ih.container_id = (SELECT MIN(ihh.container_id)
FROM his_containers ihh
WHERE ihh.container_id > i.container_id
AND ihh.container = i.container)), NULL,
(SELECT ic.in_date
FROM inv_containers ic
WHERE ic.container = i.container)) IN_DATE,
decode ((SELECT ih.in_trucker_code
FROM his_containers ih
WHERE ih.container = i.container
AND ih.container_id > i.container_id
AND ih.container_id = (SELECT MIN(ihh.container_id)
FROM his_containers ihh
WHERE ihh.container_id > i.container_id
AND ihh.container = i.container)), NULL,
(SELECT ic.in_trucker_code
FROM inv_containers ic
WHERE ic.container = i.container)) IN_TRUCKER_CODE,
decode ((SELECT ih.chassis
FROM his_containers ih
WHERE ih.container = i.container
AND ih.container_id > i.container_id
AND ih.container_id = (SELECT MIN(ihh.container_id)
FROM his_containers ihh
WHERE ihh.container_id > i.container_id
AND ihh.container = i.container)), NULL,
(SELECT ic.chassis
FROM inv_containers ic
WHERE ic.container = i.container)) IN_CHASSIS
FROM HIS_containers i,
container_masters cm,
tml_container_lhts clht,
tml_container_lengths cl
WHERE i.chassis IS NULL AND
i.out_mode = 'T' AND
i.out_date BETWEEN to_date ('1-JAN-2005','DD-MON-YYYY') AND to_date ('01-FEB-2005','DD-MON-YYYY') AND
cm.container = i.container AND
cm.lht_code = clht.code AND
clht.length_code = cl.code AND
decode ((SELECT ih.container_id
FROM his_containers ih
WHERE ih.container = i.container
AND ih.container_id > i.container_id
AND ih.container_id = (SELECT MIN(ihh.container_id)
FROM his_containers ihh
WHERE ihh.container_id > i.container_id
AND ihh.container = i.container)), NULL,
(SELECT ic.container_id
FROM inv_containers ic
WHERE ic.container = i.container)) IS NOT NULL
/


Carry's method

Gaurav Chandra Pandey, May 20, 2005 - 7:10 am UTC

Hi Tom,

I have your performance book as well as Carry Milsap's oracle performance book..I want to know which method to follow..cause according to cary one should use YAPP method, instead of using traditional checking hit ratio method.

Tom Kyte
May 20, 2005 - 8:08 am UTC

not sure what you are asking.

but, if I tell you you have a 99.532% cache hit, is that

a) good
b) bad
c) neither good nor bad


you need to look at lots of things, not just a ratio, the ratio can be used by only in the context of lots of other bits of data.

SQL tuning

A reader, May 20, 2005 - 3:50 pm UTC

Hi Tom,

I was going through this particular thread on SQL tuning. It gives more insight into SQL tuning than most of the "popular" SQL Tuning books do. Keep up the good work

thanks
Anto

Alex, May 23, 2005 - 11:01 am UTC

Hi,

I am in the process of tuning some sql statements that were identified as needing some work. I'm stuck on one at the moment that runs much better on one database than the other. I'm hoping that if you look at the differences between the access paths you might be able to point me at some things to look for to account for these differences.

First the 9 second one:

18 0 TABLE ACCESS (BY INDEX ROWID) OF 'COMPLETED_REQ' (Co
st=1 Card=2 Bytes=94)

19 18 NESTED LOOPS (Cost=7512 Card=6030 Bytes=795960)
20 19 TABLE ACCESS (FULL) OF 'SCHEDULED_REQ' (Cost=534
9 Card=3604 Bytes=306340)

21 19 INDEX (RANGE SCAN) OF 'COMPLETED_REQ#PK' (UNIQUE
) (Cost=1 Card=1)

Now the 25 second version:

18 0 MERGE JOIN (Cost=4006 Card=2 Bytes=244)
19 18 TABLE ACCESS (BY INDEX ROWID) OF 'SCHEDULED_REQ' (
Cost=248 Card=3266 Bytes=277610)

20 19 INDEX (FULL SCAN) OF 'SCHEDULED_REQ#PK' (UNIQUE)
(Cost=26 Card=627108)

21 18 SORT (JOIN) (Cost=3758 Card=408010 Bytes=15096370)
22 21 TABLE ACCESS (FULL) OF 'COMPLETED_REQ' (Cost=100
1 Card=408010 Bytes=15096370)

As you can tell I omitted the first 17 steps to save space, they were identical in both plans so I only posted where the differences lye. I will try to give you more information if you need it, but I am more or less looking for your opinion on what you see. Thanks.

Tom Kyte
May 23, 2005 - 2:34 pm UTC

optimizer parameters are the same?
stats are similar?
data is logically the same?

about the suggestion above..

whizkid, May 23, 2005 - 12:29 pm UTC

</code> http://asktom.oracle.com/pls/ask/f?p=4950:61:11613347383759103782::::P61_ID:8764516459743#40489001698671 <code>

Tom, thanks to your input above, the query is able to run very fast.. but after implementing the same in production, our enqueue waits have gone up dramatically.. maybe because of the newly created index, the insert is slow?? i know this is not sufficient information for you to give any comments, what do you think I should look at? should I drop that index and look for some alternative method?

Tom Kyte
May 23, 2005 - 3:53 pm UTC

doesn't this just mean "we removed a bottleneck, so something running really slow before isn't and now we get lots more enqueue waits (locked rows, we are waiting on others to unlock the row) because we ARRIVE AT THE ROW faster"

Maybe because of the newly created index - the query is so fast that your enqueue waits went up because everyone is going *faster*


Did your overall processing rate go UP or DOWN?

(enqueue waits are row locks mostly -- they would not result from adding a non-unique index)

Alex, May 23, 2005 - 3:03 pm UTC

Tom,

Yes parameters are the same. The stats are current. The faster running DB has slightly less rows, completed_req table has 15541 fewer, scheduled_req 2583.

I tried to use a hint to get the optimizer to use the index range scan but it won't take. Is there a specific index hint for range scan like index_ffs for fast full scan?

Alex, May 23, 2005 - 3:13 pm UTC

Forget it, sorry to bother you. It's using the same plan but running in 7 seconds now. I must have missed a table when I computed stats or something.

yes..

whizkid, May 24, 2005 - 1:15 am UTC

we did remove a bottleneck, but if we see the overall performance, it has gone down. the process is like the user will add the customer, enter some details, get the account balance, issue the policy... the 3rd part of getting the account balance is really fast now.. but during the final part of issuing the policy, sometimes there are lots of enqueue waits.. when i find out the holder of the lock from v$lock, the holder is executing a query on the table on which we created the index.. yesterday we had around 90 sessions (2 nodes included) waiting for enqueue. i had to kill all the holders to get back to normal working.. the users have also started complaining that at the final submit button the system just hangs (maybe because of the enqueue wait)..

still unable to get the logic as to why do we wait for locked rows if we create a new index...

Tom Kyte
May 24, 2005 - 7:44 am UTC

the holder is holding a lock -- the query they are currently executing is "not meaningful", it is just what they are doing now. The lock they took might have been taken 10 second ago.

Print out a lock graph (say using utllockt in $ORACLE_HOME/rdbms/admin) to see the blockers and blockees

See what the BLOCKEES are waiting on -- what table, that'll give you an idea of where the locking issue is.

(you don't have unindexed foreign keys do you??)


I fully believe the index is a red herring here, it is not the issue.



You are correct!

whizkid, May 24, 2005 - 8:41 am UTC

The index was a red herring.. (I also learned a new term today!).. I found out the SQL of the blocking session and tried to analyze that.. it was taking a long time and had a missing index.. i created an index.. that query is working fast and now there are no more enqueue waits... this problem is solved .. at least i think so..

But Tom, really before creating the index that you suggested there were really no enqueue waits.. still dont understand how creating that shot up the wait events.. maybe as you said since we are getting the row faster, it is going ahead and waiting for something.. but the above index which i created (from the blocking session) was not there and no enqueue waits were there earlier.. is it because earlier the 1st query was slow, 2nd query was also slow so no difference (no enqueue).. now 1st query was fast 2nd query was slow so people had to wait.. is this it?

thanks a ton once again...

Tom Kyte
May 24, 2005 - 10:22 am UTC

you were doing something like:

run query1
modify row
run query2
do something
commit

query1 was a bottleneck, a big one. everyone was taking a long time to get through that. few would simultaneously try to get the "modify row" at the same time. one would and run query2. now query2 was slow but not nearly as bad as query1 where people spent MOST of their time. So, the number of people waiting on the enqueue was few.

you speed up query1 -- now everyone is stuck on enqueue waits.

(this is a hypothesis... a guess)

parse time

Branka, May 25, 2005 - 12:55 pm UTC

Tom,

What do you think about parse time now? I had discussion with another DBA, who insisted that parse time is not important any more, since CPU become so fast.

Thanks


Tom Kyte
May 25, 2005 - 3:26 pm UTC

hehehehe BAMM (ouch, that hurt. I fell out of my chair.)

Umm, that would be "not correct" in a big way.

tell them to find a multi-cpu machine.
then write three stored procedures:

a) one that does an
execute immediate 'insert into t t' || job_number || ' values ( ' || i || ')';

(eg: insert into t t5 values ( 1 );
insert into t t5 values ( 2 );
....)

b) one that does
execute immediate 'insert into t t' mod(i,2) ||
' values ( :x )' using i;

(eg: insert into t t0 values ( :x );
insert into t t1 values ( :x );
insert into t t0 values ( :x );

c) one that does
insert into t values ( i );


in a for loop with i running from 1 to 25,000


Now, run one of them -- measure cpu and elapsed time.
Now run two of them -- measure cpu and elapsed time.
Repeat up to say 10.

Graph it.

I did. Ask yourself why it takes as much cpu for 10 users to insert 25,000 rows
using method (C) as it did for TWO users using method (A)??

Or why 10 users using method (C) used the cpu of 4.5 users using method (B)

Or why 10 users could create 250,000 (method C) rows IN THE SAME TIME one user (method A) could create 25,000 rows?

Or why 10 users could create 250,000 rows (method C) in the same time 4 users (method B) could create 100,000 rows?


It is all about latching -- latches are a type of lock, locks are serialization devices, serialization devices inhibit scalability.


You want to kill a system, easy. Just parse as much as you can, that'll toast it right up. All you'll ever be able to prove is you always need ONE MORE CPU on such a system (and never ever get any additional performance -- you are all trying to latch the same resource, the shared pool - remember it is the SHARED pool, not BOB'S pool, not MARY'S pool -- the shared pool)


see also

</code> http://www.jlcomp.demon.co.uk/proof.html <code>


Selects on views with unions

Philihp Busby, May 27, 2005 - 3:07 pm UTC

Hi Tom,

An application we use provides a view as an abstraction layer for legacy applications. The table structures are as follows.

CREATE TABLE person (
id NUMBER(5) PRIMARY KEY,
name VARCHAR2(255)
);
CREATE UNIQUE INDEX person_pdash_idx ON person ('P-'||id);
INSERT INTO person (id,name) VALUES (20001,'Craft');
INSERT INTO person (id,name) VALUES (20001,'Dover');

CREATE TABLE company (
id NUMBER(5) PRIMARY KEY,
name VARCHAR2(255)
);
CREATE UNIQUE INDEX person_pdash_idx ON person ('C-'||id);
INSERT INTO person (id,name) VALUES (10001,'Alice');
INSERT INTO person (id,name) VALUES (10001,'Bryan');
CREATE VIEW customer_v AS
SELECT
'PERS' AS type
'P-'||p.id as id
FROM person p
UNION ALL
SELECT
'COMP' AS type
'C-'||c.id AS id
FROM company c

The indexes speed up queries like

SELECT * FROM company WHERE 'C-'||id = 'C-20001'
SELECT * FROM person WHERE 'P-'||id = 'P-10001'

but no advantage is given to the following (which happens in the *other* part of the union, and could also NEVER happen for obvious reasons)

SELECT * FROM company WHERE 'C-'||id = 'P-20001'
SELECT * FROM person WHERE 'P-'||id = 'C-10001'

When our legacy systems query the customer_v view as

SELECT *
FROM customer_v
WHERE type = 'PERS'
AND id = 'P-'||10002

which is like querying

SELECT *
FROM (
SELECT
'PERS' AS type
'P-'||p.id as id
FROM person p
UNION ALL
SELECT
'COMP' AS type
'C-'||c.id AS id
FROM company c
)
WHERE type = 'PERS'
AND id = 'P-'||10002

Since these tables themselves are accessed much from newer apps, instead of legacy apps, it would be preferable not to introduce a second 'P-' index on the Company table, and/or a second 'C-' index on Person.

Is there a way to hint to the optimizer somehow that a row *WILL NOT* be found in a unioned "branch" query of a view? In a query where type="PERS", I would like it to not attempt searching the Company table.

Tom Kyte
May 27, 2005 - 4:10 pm UTC

but it should be doing that already? 9ir2 and 10gr1 did anyhow. After fixing up your example to be what you said it was:

CREATE TABLE person (
id NUMBER(5) PRIMARY KEY,
name VARCHAR2(255)
);
CREATE UNIQUE INDEX person_pdash_idx ON person ('P-'||id);
INSERT INTO person (id,name) VALUES (20001,'Craft');
INSERT INTO person (id,name) VALUES (20002,'Dover');
exec dbms_stats.set_table_stats( user, 'PERSON', numrows=>1000000, numblks=>100000 );

CREATE TABLE company (
id NUMBER(5) PRIMARY KEY,
name VARCHAR2(255)
);
CREATE UNIQUE INDEX comp_cdash_idx ON company ('C-'||id);
INSERT INTO company (id,name) VALUES (10001,'Alice');
INSERT INTO company (id,name) VALUES (10002,'Bryan');
exec dbms_stats.set_table_stats( user, 'COMPANY', numrows=>1000000, numblks=>100000 );


CREATE or replace VIEW customer_v
AS
select 'PERS' as type, 'P-' || p.id as id, name from person p
union all
select 'COMP' as type, 'C-' || c.id as id, name from company c;


(index names, tablenames, create views etc -- were wrong).....


SELECT * FROM customer_v WHERE type = 'PERS' AND id = 'P-'||20002

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.00 0.00 0 2 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.00 0.00 0 2 0 1

Rows Row Source Operation
------- ---------------------------------------------------
1 VIEW (cr=2 r=0 w=0 time=67 us)
1 UNION-ALL (cr=2 r=0 w=0 time=60 us)
1 TABLE ACCESS BY INDEX ROWID PERSON (cr=2 r=0 w=0 time=27 us)
1 INDEX UNIQUE SCAN PERSON_PDASH_IDX (cr=1 r=0 w=0 time=14 us)(object id 42089)
0 FILTER (cr=0 r=0 w=0 time=1 us)
0 TABLE ACCESS BY INDEX ROWID COMPANY (cr=0 r=0 w=0 time=0 us)
0 INDEX UNIQUE SCAN COMP_CDASH_IDX (cr=0 r=0 w=0 time=0 us)(object id 42092)
********************************************************************************
SELECT * FROM customer_v WHERE type = 'COMP' AND id = 'C-'||10002

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.00 0.00 0 2 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.01 0.00 0 2 0 1

Rows Row Source Operation
------- ---------------------------------------------------
1 VIEW (cr=2 r=0 w=0 time=55 us)
1 UNION-ALL (cr=2 r=0 w=0 time=49 us)
0 FILTER (cr=0 r=0 w=0 time=1 us)
0 TABLE ACCESS BY INDEX ROWID PERSON (cr=0 r=0 w=0 time=0 us)
0 INDEX UNIQUE SCAN PERSON_PDASH_IDX (cr=0 r=0 w=0 time=0 us)(object id 42089)
1 TABLE ACCESS BY INDEX ROWID COMPANY (cr=2 r=0 w=0 time=27 us)
1 INDEX UNIQUE SCAN COMP_CDASH_IDX (cr=1 r=0 w=0 time=14 us)(object id 42092)


That shows it is only executing one or the other part of the plan at runtime -- the filter step is cutting out the branch that need not be executed. zero IO.

Different ways of writting same sql

Reader, May 30, 2005 - 6:00 am UTC

Suppose in our emp-dept table ,

We have a deptno in Dept table where there is no employees in Emp table.

I would like to select that deptno.

SQL> select deptno from dept where deptno not in(select distinct deptno from emp);

I want to know if there are any other alternatives to write this statment in term of cost other than the followin:

a) SCOTT@9R2> select deptno
  2  from scott.dept
  3  where not (deptno in (select distinct deptno from scott.emp));

b) SCOTT@9R2> select dept.deptno
  2  from   scott.dept, scott.emp
  3   where  dept.deptno = emp.deptno (+)
  4   and    emp.deptno is null;

c) select deptno from scott.dept where deptno not in(select distinct deptno from scott.emp);

Explain Plans for all the above SQL's
========================================

SCOTT@9R2> SPOOL SQLS.LST
SCOTT@9R2> select deptno
  2  from scott.dept
  3  where not (deptno in (select distinct deptno from scott.emp));

    DEPTNO                  
----------                  
        40                  
Execution Plan
----------------------------------------------------------   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=446694 Card=1 Bytes=                                                      26)                  1    0   MERGE JOIN (ANTI) (Cost=446694 Card=1 Bytes=26)                                                      2    1     INDEX (FULL SCAN) OF 'DEPT_PRIMARY_KEY' (UNIQUE) (Cost=2                                            
          6 Card=10000000 Bytes=130000000)                                               3    1     SORT (UNIQUE) (Cost=446668 Card=10000000 Bytes=130000000                                            
          )                 
   4    3       TABLE ACCESS (FULL) OF 'EMP' (Cost=1552 Card=10000000                                             
          Bytes=130000000)  
Statistics
----------------------------------------------------------          0  recursive calls
          0  db block gets  
          4  consistent gets
          0  physical reads 
          0  redo size      
        305  bytes sent via SQL*Net to client                                                      
        426  bytes received via SQL*Net from client                                                                2  SQL*Net roundtrips to/from client                                                                1  sorts (memory) 
          0  sorts (disk)   
          1  rows processed 

SCOTT@9R2> select dept.deptno
  2  from   scott.dept, scott.emp
  3   where  dept.deptno = emp.deptno (+)
  4   and    emp.deptno is null;

    DEPTNO                  
----------                  
        40                  
Execution Plan
----------------------------------------------------------   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=446694 Card=10000000                                            
           Bytes=260000000) 
   1    0   FILTER          
   2    1     MERGE JOIN (OUTER)                                                        3    2       INDEX (FULL SCAN) OF 'DEPT_PRIMARY_KEY' (UNIQUE) (Cost                                            
          =26 Card=10000000 Bytes=130000000)                                               4    2       SORT (JOIN) (Cost=446668 Card=10000000 Bytes=130000000                                            
          )                 
   5    4         TABLE ACCESS (FULL) OF 'EMP' (Cost=1552 Card=1000000                                            
          0 Bytes=130000000)
Statistics
----------------------------------------------------------          0  recursive calls
          0  db block gets  
          4  consistent gets
          0  physical reads 
          0  redo size      
        305  bytes sent via SQL*Net to client                                                              426  bytes received via SQL*Net from client                                                                2  SQL*Net roundtrips to/from client                                                                1  sorts (memory) 
          0  sorts (disk)   
          1  rows processed 

SCOTT@9R2> select deptno from scott.dept where deptno not in(select distinct deptno from scott.emp);

    DEPTNO                  
----------                  
        40                  
Execution Plan
----------------------------------------------------------   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=446694 Card=1 Bytes=                                            
          26)               
   1    0   MERGE JOIN (ANTI) (Cost=446694 Card=1 Bytes=26)                                                      2    1     INDEX (FULL SCAN) OF 'DEPT_PRIMARY_KEY' (UNIQUE) (Cost=2                                            
          6 Card=10000000 Bytes=130000000)                                               3    1     SORT (UNIQUE) (Cost=446668 Card=10000000 Bytes=130000000                                            
          )                 
   4    3       TABLE ACCESS (FULL) OF 'EMP' (Cost=1552 Card=10000000                                             
          Bytes=130000000)  
Statistics
----------------------------------------------------------          0  recursive calls
          0  db block gets  
          4  consistent gets
          0  physical reads 
          0  redo size      
        305  bytes sent via SQL*Net to client                                                              426  bytes received via SQL*Net from client                                                                2  SQL*Net roundtrips to/from client                                                                1  sorts (memory) 
          0  sorts (disk)   
          1  rows processed 

SCOTT@9R2> SPOOL OFF;

Actually Im tryin to practice using explain plan and know the difference.

You time is precious and any response to this will be highly appreciated; 

Tom Kyte
May 30, 2005 - 9:20 am UTC

the best way to write this is:

select deptno from dept where deptno not in (select deptno from emp);

period, plain and simple. IF deptno is NULLABLE in emp, you might

select deptno from dept where deptno not in (select deptno from emp where deptno is not null);

(else, if there is one NULL deptno in EMP, the result set is always "empty")


Looks like you disabled hash joins in your database, I would expect brutally efficient hash anti-joins, not the not as efficient for big things merge anti-join.


you have "where not exists" as well as not in and the "anti join" you coded.

You always have a "just outer join and use HAVING COUNT(emp.empno) = 0" as well

How to know if Hash Join is disabled?

Reader, May 31, 2005 - 4:32 am UTC

<QUOTE>
Looks like you disabled hash joins in your database, I would expect brutally efficient hash anti-joins, not the not as efficient for big things merge anti-join.
</QUOTE>

I would like to know how u knew that Hash joins are disabled in my DB and Im really not clear about " I would expect brutally efficient hash anti-joins, not the not as efficient for big things merge anti-join" Could u please help me in understanding this? And yeah how can I enable hash join if its disabled?

Here im pasting explain plan for one more query which is using hash joins? Im really not clear about my hash joins disabled :(

NK_DBA@orakic> select rpad(' ',2*level,' ') || name name
2 from (select dname name, deptno id, to_number(null) parent
3 from dept
4 union all
5 select ename ename, to_number(null) id, deptno parent
6 from emp )
7 start with parent is null
8 connect by prior id = parent
9 /

NAME
-----------------------------------------------------------------------
ACCOUNTING
CLARK
KING
MILLER
RESEARCH
SMITH
JONES
SCOTT
ADAMS
FORD
SALES
ALLEN
WARD
MARTIN
BLAKE
TURNER
JAMES
OPERATIONS

18 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=3104 Card=20000000 B
ytes=700000000)

1 0 CONNECT BY (WITH FILTERING)
2 1 FILTER
3 2 COUNT
4 3 VIEW (Cost=3104 Card=20000000 Bytes=700000000)
5 4 UNION-ALL
6 5 TABLE ACCESS (FULL) OF 'DEPT' (Cost=1552 Card=10
000000 Bytes=220000000)

7 5 TABLE ACCESS (FULL) OF 'EMP' (Cost=1552 Card=100
00000 Bytes=200000000)

8 1 HASH JOIN
9 8 CONNECT BY PUMP
10 8 COUNT
11 10 VIEW (Cost=3104 Card=20000000 Bytes=700000000)
12 11 UNION-ALL
13 12 TABLE ACCESS (FULL) OF 'DEPT' (Cost=1552 Card=10
000000 Bytes=220000000)

14 12 TABLE ACCESS (FULL) OF 'EMP' (Cost=1552 Card=100
00000 Bytes=200000000)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
12 consistent gets
0 physical reads
0 redo size
687 bytes sent via SQL*Net to client
437 bytes received via SQL*Net from client
3 SQL*Net roundtrips to/from client
3 sorts (memory)
0 sorts (disk)
18 rows processed

I hope to hear you and better understand about your point of view.



Tom Kyte
May 31, 2005 - 8:15 am UTC

"U" didn't know. "U" doesn't even look at this site, but "U" does get lots of requests for appearances.

I guessed -- because of the sort merges, I would expect hash operations. show parameter hash would tell you one way or the other.


are you using manual or automatic PGA memory management and what is your pga aggregate target and hash area sizes set to

dedicated server or shared server connection?

Hash Enabled or disabled?

Reader, June 01, 2005 - 2:15 am UTC

I'm extreamly sorry for using "U", I really didn't noticed it... But I will take care of it next time.

My Server's Tnsname.ora says:

# TNSNAMES.ORA Network Configuration File: /ora/oracle/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORAKIC =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = kic-compaq)(PORT = 1521))
)
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orakic)
)
)

AS1200 =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = as1200)(PORT = 1521))
)
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orakic)
)
)

ES40 =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = legatosrv)(PORT = 1521))
)
(CONNECT_DATA =
(SERVER = DEDICATED)
(SERVICE_NAME = orakic)
)
)



INST1_HTTP =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = kic-compaq)(PORT = 1521))
)
(CONNECT_DATA =
(SERVER = SHARED)
(SERVICE_NAME = MODOSE)
(PRESENTATION = </code> http://HRService <code>
)
)

EXTPROC_CONNECTION_DATA =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC))
)
(CONNECT_DATA =
(SID = PLSExtProc)
(PRESENTATION = RO)
)
)

So I guess we are using deticated server connection, I checked it from v$session and found all the connections are using Dedicated server.

In 9iR2 the default is dedicated where in 10gR1 its shared right?

Following are the parameters about PGA, HASH and others

SYS@PROD>SHOW PARAMETER WORKAREA_SIZE_POLICY

NAME TYPE VALUE
------------------------------------ ----------- -------------------
workarea_size_policy string AUTO

SYS@PROD>SHOW PARAMETER PGA

NAME TYPE VALUE
------------------------------------ ----------- -------------------
pga_aggregate_target big integer 16777216
SYS@PROD>SHOW PARAMETER HASH

NAME TYPE VALUE
------------------------------------ ----------- -------------------
hash_area_size integer 2048000
hash_join_enabled boolean FALSE

SYS@PROD>SHOW PARAMETER SHARED

NAME TYPE VALUE
------------------------------------ ----------- --------------------
hi_shared_memory_address integer 0
max_shared_servers integer 20
shared_memory_address integer 0
shared_pool_reserved_size big integer 42781900
shared_pool_size big integer 855638016
shared_server_sessions integer 563
shared_servers integer 1

Can I know what is the other way to check about PGA memory management other than show parameter WORKAREA_SIZE_POLICY?

Response to my query from your precious time will be highly appreciated. I will always treasure the information I'm getting from your forms.

Thanks a million for your time.


Tom Kyte
June 01, 2005 - 8:54 am UTC

you have a 16meg pga aggregate target, which is tiny.

that is 16meg to be used by all concurrent sessions -- total.

is that "right" for you?

sql..

whizkid, June 01, 2005 - 11:41 am UTC

any clue how can i tune the below query? dont know why it is doing a full table scan..

DELETE FROM ACC_LOGICAL_LOCKS
WHERE
LOCKED_BY_OBJECT_TYPE = :b1 AND LOCKED_BY_OBJECT_ID = :b2

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.24 2.28 2893 3211 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.24 2.28 2893 3211 0 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 5386

Rows Row Source Operation
------- ---------------------------------------------------
0 DELETE
0 TABLE ACCESS FULL ACC_LOGICAL_LOCKS


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
global cache cr request 1224 0.00 0.07
db file scattered read 527 0.03 1.91
db file sequential read 17 0.01 0.02
buffer busy waits 4 0.00 0.01
buffer busy global CR 3 0.00 0.02
SQL*Net message to client 1 0.00 0.00
SQL*Net message from client 1 25.36 25.36
row cache lock 1 0.00 0.00

the time taken is very minute but this query gets executed over 500 times in 30 minutes.. from statspack of 30 minute window..

Physical Reads Executions Reads per Exec %Total Time (s) Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
1,101,029 508 2,167.4 26.8 138.24 315.62 4242414595
Module: JDBC Thin Client
DELETE FROM ACC_LOGICAL_LOCKS WHERE LOCKED_BY_OBJECT_TYPE = :b1
AND LOCKED_BY_OBJECT_ID = :b2


Buffer Gets Executions Gets per Exec %Total Time (s) Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
1,631,797 508 3,212.2 0.9 138.24 315.62 4242414595
Module: JDBC Thin Client
DELETE FROM ACC_LOGICAL_LOCKS WHERE LOCKED_BY_OBJECT_TYPE = :b1
AND LOCKED_BY_OBJECT_ID = :b2

there's a primary key (and hence a unique index) on

ACC_LOGICAL_LOCKS(LOCKED_OBJECT_TYPE, LOCKED_OBJECT_ID)

the object is analyzed and it has 400k records..

version is 9.2.0.5

Tom Kyte
June 01, 2005 - 12:54 pm UTC

what are the datatypes of the columns, and how are the java developers binding to them?

ops$tkyte@ORA10G> create table t ( x varchar2(10), y varchar2(10), z int, primary key(x,y) );
 
Table created.
 
ops$tkyte@ORA10G> exec dbms_stats.set_table_stats(user,'T',numrows=>10000, numblks=>3211 );
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> @trace
ops$tkyte@ORA10G> alter session set events '10046 trace name context forever, level 12';
 
Session altered.
 
ops$tkyte@ORA10G> declare
  2          l_x1 number := 42;
  3          l_y1 number := 42;
  4          l_x2 varchar2(10) := 42;
  5          l_y2 varchar2(10) := 42;
  6  begin
  7          for x in ( select * from t t1 where x= l_x1 and y = l_y1 )
  8          loop
  9                  null;
 10          end loop;
 11
 12          for x in ( select * from t t2 where x= l_x2 and y = l_y2 )
 13          loop
 14                  null;
 15          end loop;
 16  end;
 17  /
 
PL/SQL procedure successfully completed.


SELECT * FROM T T1 WHERE X= :B2 AND Y = :B1
                                                                                                      
Rows     Row Source Operation
-------  ---------------------------------------------------
      0  TABLE ACCESS FULL T (cr=3 pr=0 pw=0 time=49 us)
                                                                                                      
********************************************************************************
SELECT * FROM T T2 WHERE X= :B2 AND Y = :B1
                                                                                                      
Rows     Row Source Operation
-------  ---------------------------------------------------
      0  TABLE ACCESS BY INDEX ROWID T (cr=1 pr=0 pw=0 time=28 us)
      0   INDEX UNIQUE SCAN SYS_C0017440 (cr=1 pr=0 pw=0 time=19 us)(object id 89706)
                                                                                                      


That'd be my first guess, they are doing  implicit conversions, nullifying the ability to use the index. 

A reader, June 01, 2005 - 4:48 pm UTC

Hi Whizkid,

What if you artificially increase the number of blocks for that table using dbms_stats.set_table_Stats ?

Tom Kyte
June 01, 2005 - 5:40 pm UTC

I still guess bad binds.

the rbo -- definitely would use an index.

the cbo -- almost certainly would use an index on a primary key, even on an empty table.


create table t ( x int, y int, z int, primary key(x,y) );
exec dbms_stats.gather_table_stats(user,'T');

variable x number
variable y number
exec :x := 42; :y := 55;
@trace
select * from t where x = :x and y = :y;



select *
from
t where x = :x and y = :y

Rows Row Source Operation
------- ---------------------------------------------------
0 TABLE ACCESS BY INDEX ROWID OBJ#(33728)
0 INDEX UNIQUE SCAN OBJ#(33729) (object id 33729)


datatypes are correct

whizkid, June 02, 2005 - 12:55 am UTC

hi tom,

its getting called from pl/sql package.. it's not using any implicit conversion..

lotus >desc ACC_LOGICAL_LOCKS
Name Null? Type
----------------------------------------------------- -------- ------------------------------------
LOCKED_OBJECT_TYPE NOT NULL VARCHAR2(10)
LOCKED_OBJECT_ID NOT NULL NUMBER
TIMESTAMP NOT NULL DATE
MOVEMENT_ID VARCHAR2(10)
USERNAME NOT NULL VARCHAR2(30)
SESSION_ID NOT NULL NUMBER
LOCKED_BY_OBJECT_TYPE VARCHAR2(10)
LOCKED_BY_OBJECT_ID NUMBER

i did this in sqlplus and gave the tkprof...

var b1 varchar2(20);
var b2 number;

exec :b1 := 'ACB';
exec :b2 := 15160174;

DELETE FROM ACC_LOGICAL_LOCKS
WHERE
LOCKED_BY_OBJECT_TYPE = :b1 AND LOCKED_BY_OBJECT_ID = :b2




create the correct index

Partha, June 02, 2005 - 3:47 am UTC

Hey whizkid,

--------------------------------------------------------------------
there's a primary key (and hence a unique index) on

ACC_LOGICAL_LOCKS(LOCKED_OBJECT_TYPE, LOCKED_OBJECT_ID)
------------------------------------------------------------------

The primary key is LOCKED_OBJECT_TYPE and LOCKED_OBJECT_ID, if you do not have an index on "LOCKED_BY_OBJECT_TYPE" and "LOCKED_BY_OBJECT_ID", it is going to do a FULL table scan. If you want to avoid full table scans on this (as it looks obvious based on the number of executions), you need to create an index on (LOCKED_BY_OBJECT_TYPE, LOCKED_BY_OBJECT_ID) based on your requirement.

--------------------------------------------------------------------
DELETE FROM ACC_LOGICAL_LOCKS WHERE LOCKED_BY_OBJECT_TYPE = :b1 AND LOCKED_BY_OBJECT_ID = :b2
--------------------------------------------------------------------

SQL TO TUNE

Reddy, June 02, 2005 - 9:57 am UTC

Hi Tom,

I had a table which has around 1,50,000 records and it has a very frequently executed query( say every second) which ultimately causing high CPU usage.


Query:
-----
SELECT MIN (COLUMN1)
FROM TABLE1
WHERE COLUMN2 = (SELECT MIN (COLUMNN2)
FROM TABLE1
WHERE
COLUMN3 = 5 AND
COLUMN4 BETWEEN 200 AND 300)
AND COLUMN3 = 5 AND COLUMN4 BETWEEN 200 AND 300;

here column2 is a date.
Index on column4 is getting used in the plan.

PLAN_TABLE_OUTPUT

| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 20 | 163 (0)|
| 1 | SORT AGGREGATE | | 1 | 20 | |
|* 2 | TABLE ACCESS BY INDEX ROWID | TABLE1 | 1 | 20 | 163 (0)|
|* 3 | INDEX RANGE SCAN | INDEX4 | 32722 | | 69 (0)|
| 4 | SORT AGGREGATE | | 1 | 15 | |
|* 5 | TABLE ACCESS BY INDEX ROWID| TABLE1 | 4675 | 70125 | 163 (0)|
|* 6 | INDEX RANGE SCAN | INDEX4 | 32722 | | 69 (0)|
-------------------------------------------------------------From statspack report:

Buffer Gets Executions Gets per Exec %Total Time (s) Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
1,189,308,938 4,968 239,393.9 69.8 ######## 25804.16 3961911181

How to reduce this huge number of buffergets for this query. Any better way of writing it?


Thanks,
Reddy.

Tom Kyte
June 02, 2005 - 4:52 pm UTC

isn't that just

select *
from ( select column1
from t
where column3 = 5
and column4 between 200 and 300
order by column2, column1 )
where rownum = 1;


index on (colum3,column4,column2,column1)



To Reddy

Ricky, June 02, 2005 - 10:06 am UTC

select * from (select column1
from table1
where column3 = 5
and column4 between 200 and 300
order by column2 asc , column1 asc
)where rownum <2

wouldn't the above work for you?
I believe Tom had written the above soln before for a similar qn...

Tom Kyte
June 02, 2005 - 4:52 pm UTC

thanks, did see you did that already ;)

To Reddy

Jay, June 02, 2005 - 10:27 am UTC

How about this:

select MIN(column1) KEEP (DENSE_RANK FIRST ORDER BY column2)
from table1
where column3 = 5
and column4 between 200 and 300

To Partha..

whizkid, June 02, 2005 - 10:41 am UTC

Hey Partha..

thanks a lot...! need to get my eyes checked up for missing such an obvious thing :(

OK

Kumar, June 04, 2005 - 11:27 pm UTC

Hi Tom,
Any better way to put this query??

select deptno,sal,count(*)
from emp
where sal in(select max(sal) from emp group by deptno)
group by deptno,sal

Tom Kyte
June 05, 2005 - 9:14 am UTC

depends on what question you are trying to ask :)

You are asking for a count by deptno/sal
for the set of people
that make a salary that is the same as the max salary IN ANY department

it is proabably not what you meant. Did you mean -- show me by deptno, the salary that is the max and the count of people making that salary.


Phrase as TEXT your question, your requirments. From there -- we can derive many possible queries to answer.

</code> http://asktom.oracle.com/Misc/how-to-ask-questions.html <code>

OK

Kumar, June 05, 2005 - 10:32 am UTC

Hi Tom,
My requirement is
Get the deptno,max(sal) and count of people getting it.


Tom Kyte
June 05, 2005 - 11:04 am UTC

count of people in that DEPTNO getting it

or

count of any person in any DEPTNO getting it.

you have the latter, i suspect the former is what you really want.

Index not used

reader, June 06, 2005 - 5:10 pm UTC

Following SQL is not using the index on the individual table
it took long time as the indiviudal table has 11 million records
SQL Statement from editor:


SELECT DISTINCT (h.household_id)
FROM household h,
individual i,
household_member hm
WHERE h.household_id = hm.household_id
AND i.individual_id = hm.individual_id
AND i.last_name LIKE 'L%'
AND i.first_name LIKE 'R%'
------------------------------------------------------------

Statement Id=7 Type=INDEX
Cost=1069 TimeStamp=06-06-05::16::28:38

(1) SELECT STATEMENT CHOOSE
Est. Rows: 11,541 Cost: 18,953
(9) SORT UNIQUE
Est. Rows: 11,541 Cost: 18,953
(8) HASH JOIN
Est. Rows: 11,541 Cost: 18,856
(3) PARTITION RANGE ALL
(2) TABLE ACCESS FULL COMPAS.INDIVIDUAL [Analyzed]
Blocks: 164,566 Est. Rows: 11,538 of 7,411,916 Cost: 10,031
(7) PARTITION RANGE ALL
(6) HASH JOIN
Est. Rows: 7,415,264 Cost: 7,958
(4) UNIQUE INDEX FAST FULL SCAN COMPAS.PK_HOUSEHOLD [Analyzed]
Est. Rows: 5,744,628 Cost: 1,069
(5) NON-UNIQUE INDEX FAST FULL SCAN COMPAS.HHLD_MEMB_LOCAL_02 [Analyzed]
Est. Rows: 7,415,264 Cost: 1,869

If I put the hint the cost of the query is very high but the 30% faster than the previous run.

SQL Statement from editor:


SELECT /*+ INDEX( i IDX_INDIVIDUAL_01) */ DISTINCT (h.household_id)
FROM household h,
individual i,
household_member hm
WHERE h.household_id = hm.household_id
AND i.individual_id = hm.individual_id
AND i.last_name LIKE 'L%'
AND i.first_name LIKE 'R%'
------------------------------------------------------------

Statement Id=7 Type=INDEX
Cost=1069 TimeStamp=06-06-05::17::09:06

(1) SELECT STATEMENT CHOOSE
Est. Rows: 11,541 Cost: 20,268
(9) SORT UNIQUE
Est. Rows: 11,541 Cost: 20,268
(8) HASH JOIN
Est. Rows: 11,541 Cost: 20,171
(3) TABLE ACCESS BY GLOBAL INDEX ROWID COMPAS.INDIVIDUAL [Analyzed]
Blocks: 164,566 Est. Rows: 11,538 of 7,411,916 Cost: 11,346
(2) NON-UNIQUE INDEX RANGE SCAN COMPAS.IDX_INDIVIDUAL_01 [Analyzed]
Est. Rows: 11,538 Cost: 77
(7) PARTITION RANGE ALL
(6) HASH JOIN
Est. Rows: 7,415,264 Cost: 7,958
(4) UNIQUE INDEX FAST FULL SCAN COMPAS.PK_HOUSEHOLD [Analyzed]
Est. Rows: 5,744,628 Cost: 1,069
(5) NON-UNIQUE INDEX FAST FULL SCAN COMPAS.HHLD_MEMB_LOCAL_02 [Analyzed]
Est. Rows: 7,415,264 Cost: 1,869


Tom Kyte
June 06, 2005 - 6:04 pm UTC

compare the tkprof with the autotrace (you compare). are the estimated cardinalities (autotrace) near reality (tkprof)

Index not used

reader, June 07, 2005 - 9:56 am UTC

Tom,

The tkprof without hint

SELECT DISTINCT (h.household_id)
FROM household h,
individual i,
household_member hm
WHERE h.household_id = hm.household_id
AND i.individual_id = hm.individual_id
AND i.last_name LIKE 'L%'
AND i.first_name LIKE 'R%'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.02 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1938 70.98 212.16 117549 213934 0 29054
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1940 71.00 212.18 117549 213934 0 29054

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 5

Rows Row Source Operation
------- ---------------------------------------------------
29054 SORT UNIQUE
29559 HASH JOIN
29536 PARTITION RANGE ALL PARTITION: 1 10
29536 TABLE ACCESS FULL INDIVIDUAL PARTITION: 1 10
7422325 PARTITION RANGE ALL PARTITION: 1 10
7422325 HASH JOIN
5752931 INDEX FAST FULL SCAN PK_HOUSEHOLD PARTITION: 1 10 (object id 34674)
7422325 INDEX FAST FULL SCAN HHLD_MEMB_LOCAL_02 PARTITION: 1 10 (object id 34657)

********************************************************************************

select file#
from
file$ where ts#=:1


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 6 0.01 0.00 0 0 0 0
Execute 6 0.00 0.00 0 0 0 0
Fetch 138 0.01 0.00 0 276 0 132
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 150 0.02 0.00 0 276 0 132

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
22 TABLE ACCESS BY INDEX ROWID FILE$
22 INDEX RANGE SCAN I_FILE2 (object id 42)




********************************************************************************

Tkprof with hint

SELECT /*+ INDEX( i IDX_INDIVIDUAL_01) */ DISTINCT (h.household_id)
FROM household h,
individual i,
household_member hm
WHERE h.household_id = hm.household_id
AND i.individual_id = hm.individual_id
AND i.last_name LIKE 'L%'
AND i.first_name LIKE 'R%'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1938 37.07 44.16 8133 80956 0 29054
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1940 37.08 44.17 8133 80956 0 29054

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 5

Rows Row Source Operation
------- ---------------------------------------------------
29054 SORT UNIQUE
29559 HASH JOIN
29536 TABLE ACCESS BY GLOBAL INDEX ROWID INDIVIDUAL PARTITION: ROW LOCATION ROW LOCATION
29536 INDEX RANGE SCAN IDX_INDIVIDUAL_01 (object id 34747)
7422328 PARTITION RANGE ALL PARTITION: 1 10
7422328 HASH JOIN
5752932 INDEX FAST FULL SCAN PK_HOUSEHOLD PARTITION: 1 10 (object id 34674)
7422328 INDEX FAST FULL SCAN HHLD_MEMB_LOCAL_02 PARTITION: 1 10 (object id 34657)

********************************************************************************

select file#
from
file$ where ts#=:1


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 6 0.00 0.00 0 0 0 0
Execute 6 0.00 0.00 0 0 0 0
Fetch 138 0.01 0.00 0 276 0 132
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 150 0.01 0.00 0 276 0 132

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: SYS (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
22 TABLE ACCESS BY INDEX ROWID FILE$
22 INDEX RANGE SCAN I_FILE2 (object id 42)


The plan with hint is much better than paln without hint, wondering why not using index.


Tom Kyte
June 07, 2005 - 12:54 pm UTC

I asked you to compare the GUESS (autotrace) to REALITY (tkprof)

this is not the result of you comparing the GUESS to REALITY. Are the guessed cardinalities even close to what really happens.


eg: are the statistics accurate, complete, up to date and are they giving the optimizer the right "information"

Index not used

reader, June 07, 2005 - 2:15 pm UTC

Tom,

Without hint the Autotrace estimate total Rows: 11,538 of 7,411,916 from INDIVIDUAL table full scan the estimate for the total records in the table is accurate.

The tkprof got the 29536 rows from the INDIVIDUAL table full scan.

With the hint autotrace estimate total Rows: 11,538 of 7,411,916 Cost: 11,346 from NON-UNIQUE INDEX RANGE SCAN COMPAS.IDX_INDIVIDUAL_01

The tkprof got the 29536 rows from the INDEX RANGE SCAN IDX_INDIVIDUAL_01

We are not gathereing the histograms (FACTS) on the table.

The statistics are accurate and complete. The same plan even after the following run.

BEGIN
dbms_stats.gather_schema_stats(
ownname => 'COMPAS',
cascade => TRUE,
estimate_percent => 25,
degree => 5,
method_opt => 'FOR ALL COLUMNS SIZE 1', -- no histograms only col stats
granularity => 'ALL'
);

END;

Tom Kyte
June 07, 2005 - 2:24 pm UTC

any special optimizer parameters set?

index not used

reader, June 07, 2005 - 4:57 pm UTC

No not a single one,
it is 9.2.0.6 database

Tom Kyte
June 07, 2005 - 6:05 pm UTC

have you gathered system statistics, so the database has a better understand of the characteristics of your system (anything to avoid setting a parameter)

unclear about ...

Gabe, June 07, 2005 - 8:55 pm UTC

Regarding these last posts … index not getting picked up aside, I would be curious to know:

1. What’s the definition of that index?

2. ‘household_member’ seems to be the intersection table between ‘household’ and ‘individual’ … assuming the FK constraints are in place … why join with ‘household’ at all? One can get the ‘household_id’s from ‘household_member’

3. As a side note … what exactly is the use of getting a list of 30K ids?

4. Would a query like:

select individual_id from individual i
where i.last_name like 'L%'
and i.first_name like 'R%'

pick that index? That should bring back 30K out of 7.5M rows.

5. Would rewriting the query as:

select … from household_member where exists (…)

make any difference?



unclear

reader, June 07, 2005 - 10:59 pm UTC

Gabe,
The quey is the subquery of the big SQL. 

SELECT   LPAD (TRIM (tps.membership_number), 11, '0') member_num,
         tps.account_individuals NAME, tps.date_of_births bday, tps.ages age,
         tps.address address, tps.phone_numbers phone_num,
         TO_CHAR (tps.household_id) hhld_id
    FROM individual i,     
   (SELECT 
           pkg_person_search.fn_get_current_member_num (h1.household_id) membership_number,
           pkg_person_search.fn_get_household_members (h1.household_id) account_individuals,
           pkg_person_search.fn_get_hhld_mem_birth_date (h1.household_id) date_of_births,
           pkg_person_search.fn_get_hhld_mem_age (h1.household_id) ages,
           pkg_person_search.fn_get_household_address (h1.household_id) address,
           pkg_person_search.fn_get_household_phone_nums (h1.household_id) phone_numbers,
           h1.household_id household_id,
           pkg_person_search.fn_get_result_order_indv_id (h1.household_id) sort_individual_id
      FROM household h1
     WHERE h1.household_id IN (
              SELECT household_id
                FROM (SELECT /*+ INDEX( i IDX_INDIVIDUAL_01) */ DISTINCT (h.household_id)
                                 FROM household h,
                                      individual i,
                                      household_member hm
                                WHERE h.household_id = hm.household_id
                                  AND i.individual_id = hm.individual_id
                                  AND i.last_name LIKE 'L%'
                                  AND i.first_name LIKE 'R%')
               WHERE ROWNUM < 253)) tps
   WHERE tps.sort_individual_id = i.individual_id
ORDER BY i.last_name, i.first_name   

If I remove the Household reference still the plan is same not using index. The system stats is not gathered for the database and not sure the impact of doing so, as this is production OLTP system.



SQL> SELECT DISTINCT (hm.household_id)
  2    FROM  individual i,
  3          household_member hm
  4   WHERE i.individual_id = hm.individual_id
  5     AND i.last_name LIKE 'L%'
  6     AND i.first_name LIKE 'R%';

29061 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=12666 Card=11541 Byt
          es=484722)

   1    0   SORT (UNIQUE) (Cost=12666 Card=11541 Bytes=484722)
   2    1     HASH JOIN (Cost=12580 Card=11541 Bytes=484722)
   3    2       PARTITION RANGE (ALL)
   4    3         TABLE ACCESS (FULL) OF 'INDIVIDUAL' (Cost=10031 Card
          =11538 Bytes=288450)

   5    2       PARTITION RANGE (ALL)
   6    5         INDEX (FAST FULL SCAN) OF 'HHLD_MEMB_LOCAL_02' (NON-
          UNIQUE) (Cost=1869 Card=7415264 Bytes=126059488)
 

Tom Kyte
June 08, 2005 - 8:20 am UTC

WHERE h1.household_id IN (
SELECT household_id
FROM (SELECT /*+ INDEX( i IDX_INDIVIDUAL_01) */ DISTINCT (h.household_id)
FROM household h,
individual i,
household_member hm
WHERE h.household_id = hm.household_id
AND i.individual_id = hm.individual_id
AND i.last_name LIKE 'L%'
AND i.first_name LIKE 'R%')
WHERE ROWNUM < 253)

that is a random data generator??

you take the first random 253 holdhold ids?? that -- that seems "strange"

but seems that household shouldn't even be in there doesn't it? I mean, just household_member is more than sufficient to get the household_id?

still unclear ...

Gabe, June 07, 2005 - 11:48 pm UTC

...
what about my #1 and #4?

6. OLTP? ... what are those tables partitioned by?

7. It seems a bit wasteful to have all that big join only to throw away all but 252 households. I don't think that rownum can be pushed up because of the DISTINCT ... may work though if you rewrite as I suggested in #5 with "select where exists"

If #4 does a FS you have a problem right there ... if it works OK then you can force that part to somehow materialize as the very first step in the overall execution ... essentially getting the big predicates to work first ... and then there is the rownum (!?!?!) would be nice to have this one kick in early on.

PS. I don't think you should give Tom bits and pieces of a query. At least mention it.


Tom Kyte
June 08, 2005 - 8:21 am UTC

I agree with the PS, this changes lots of thoughts...

reader, June 08, 2005 - 9:46 am UTC

Thanks Gabe and Tom for your suggestions. Here is my input.

#1 def. of index

CREATE INDEX compas.idx_individual_01 ON compas.individual
(
last_name ASC,
first_name ASC
)
PCTFREE 10
TABLESPACE ts_individual_01_x
/

#4 won't work as we need household_id and it is not available in individual table

#6 individual table partitioned by individual_id, all other tables partitioned by household_id
data is well distributed across the partitions

#7 I am sorry, I didn't get the #7, "I don't think that rownum can be pushed up because of the
DISTINCT" could you please elaborate little bit.

PS. I thought we had problem with subquery so instead of giving the big one I had just
mentioned the subquery. But query mentioned in the last note was full query, same as following.


SELECT LPAD (TRIM (tps.membership_number), 11, '0') member_num,
tps.account_individuals NAME, tps.date_of_births bday, tps.ages age,
tps.address address, tps.phone_numbers phone_num,
TO_CHAR (tps.household_id) hhld_id
FROM individual i,
(SELECT pkg_person_search.fn_get_current_member_num
(h1.household_id)
membership_number,
pkg_person_search.fn_get_household_members
(h1.household_id)
account_individuals,
pkg_person_search.fn_get_hhld_mem_birth_date
(h1.household_id)
date_of_births,
pkg_person_search.fn_get_hhld_mem_age (h1.household_id) ages,
pkg_person_search.fn_get_household_address
(h1.household_id)
address,
pkg_person_search.fn_get_household_phone_nums
(h1.household_id)
phone_numbers,
h1.household_id household_id,
pkg_person_search.fn_get_result_order_indv_id
(h1.household_id)
sort_individual_id
FROM household h1
WHERE h1.household_id IN (
SELECT household_id
FROM (SELECT /*+ INDEX( i IDX_INDIVIDUAL_01) */
DISTINCT (h.household_id)
FROM household h,
individual i,
household_member hm
WHERE h.household_id = hm.household_id
AND i.individual_id = hm.individual_id
AND i.last_name LIKE 'L%'
AND i.first_name LIKE 'R%')
WHERE ROWNUM < 253)) tps
WHERE tps.sort_individual_id = i.individual_id
ORDER BY i.last_name, i.first_name;


reader, June 08, 2005 - 9:50 am UTC

Just add the following,
Yes household_member is more than sufficient to get the household_id.

Tom Kyte
June 08, 2005 - 10:31 am UTC

do that.

FROM household h1
WHERE h1.household_id IN (
SELECT household_id
FROM (SELECT DISTINCT (h.household_id)
FROM household h
where individual_id in
(select individual_id
from individual
where last_name LIKE 'L%'
AND first_name LIKE 'R%')
)
WHERE ROWNUM < 253)) tps


still seems "random", that distinct makes you wait till they are all retrieved, then you distinct them and just keep the first couple random ones.

DISTINCT

reader, June 08, 2005 - 11:27 am UTC

Thanks a lot,
We need to present only 253 records to the users, DISTINCT is requird to remove duplicates from the household_member table. Is there any way we can avoid it?




Tom Kyte
June 08, 2005 - 11:33 am UTC

I understand why the distinct is needed (that comes from the model), but it just seems so very strange to get 253 'random' ones.

tomorrow, same data -- different results are possible, just due to a change in the plan.


i would definitely LOSE all of the plsql functions -- 100%

but I bet if you rip this query apart, you could use your knowledge of the data to get it to a two table join between individual and household.

You find households based on individuals (but lost the individual data) and join that back to individuals again.... I really think there is room for improvement there, but you and your knowledge of the data model, what the plsql functions do -- they are what is needed.

reader, June 08, 2005 - 12:25 pm UTC

Thanks,
The PL/SQL function is nothing but the small business logic to get the more detail about the household, for example the following function called in that query,

FUNCTION fn_get_current_member_num (p_HouseholdID IN NUMBER)

RETURN VARCHAR2

IS

v_MemNum VARCHAR2(11);

BEGIN
SELECT hp.membership_number || '-' || hp.association_id
INTO v_MemNum
FROM household_profile hp
WHERE hp.household_id = p_HouseholdID
AND TRUNC (SYSDATE) BETWEEN hp.hhold_profile_start_date AND hp.hhold_profile_stop_date
-- AND SYSDATE BETWEEN hp.hhold_profile_start_date AND NVL(hp.hhold_profile_stop_date,SYSDATE)
-- AND NVL(hp.delete_ind,'N') = 'N';
AND hp.delete_ind = 'N';

RETURN v_MemNum;

END fn_get_current_member_num;



Tom Kyte
June 08, 2005 - 1:08 pm UTC

drop them, use scalar subqueries.

select ...., (select ht.membership_number || .... ), ( select .... )
from ...

reader, June 08, 2005 - 1:39 pm UTC

That will to reduce the context switching right? Just curious what other benefits?
Thanks a lot for your help and time


Tom Kyte
June 08, 2005 - 1:53 pm UTC

context switch gone.

procedural code = slower than just letting sql do it.

possible scalar subquery caching.

opportunity to take 1 or 2 or 3 of these and turn them into a single scalar subquery (rather than hit table T 5 times, just hit it once).

reader, June 08, 2005 - 2:17 pm UTC

Great, I will do it, Thanks a lot

to ?reader? ...

Gabe, June 08, 2005 - 2:58 pm UTC

If I could say few things here (one question for Tom in there) …

A. The partitioning is likely not helping here at all … quite the opposite really. I think one should do a post-mortem to figure out if partitioning (and the way it is implemented) is doing more damage than good. Less than 10M households and individuals are still manageable without partitions.

B. The PL/SQL could be dealt with … but after resolving the inner part that deals with bringing the 252 households. The options here are: scalar subqueries (as already suggested) or one pl/sql call returning an object with all those elements or even straight joins …

C. It is not clear to me if a two table join between household with individual would suffice … the individual_id returned by the “pkg_person_search.fn_get_result_order_indv_id” call may not necessarily be one extracted by the innermost query (that is, may not be one of the L%andR% people). But if possible, yes, by all means have the smallest number of tables involved in the query.

D. There still is the issue of that query #4 (now appearing in the rewrite suggested by Tom) … I know you need the household_id … but my point was that, if that query didn’t pick the index then there likely is something wrong in there (statistics, histograms … something). A plan using an index to bring 30K out of the 7.5M records seems highly desirable. Giving that we now know the index definition … Tom, do you think adding “individual_id” as the third column to that index would make sense?

There is also the option of an FBI on:
(substr(last_name,1,1), first_name,1,1), individual_id)
plus the rewriting of course. But maybe that’s too much for now.

E. My rumblings on #7 about rewriting the inner part with an “exists” had to do with getting that rownum predicate in as soon as possible … the drawback is that it requires touching “household” … that is, assuming household(household_id) is a PK, something like:

select h.household_id
from household h
where exists ( select null
from household_member hm
,individual i
where hm.household_id = h.household_id
and hm.individual_id = i.individual_id
and i.last_name like 'L%'
and i.first_name like 'R%'
)
and rownum < 253

In retrospect, the extra trip to household may do more damage … just another option. Getting an efficient filtering of individuals by name as the very first step seems to be the most promising option.

I'll just leave it here.
Cheers.

Tom Kyte
June 08, 2005 - 4:59 pm UTC

(c) correct, that is why I put the ball right back in their court - using their knowledge of the model, this is probably something that can be simplified. we don't have the details.



Single row Join

DBA, June 08, 2005 - 3:07 pm UTC

Hi Tom,
Here is my sql -

select A.*
from TableA A,
security_table X
where X.agency_ind = 'AgencyA'
and X.operid = USER

Here, security_table has agency_ind+operid as a unique key and so, it will fetch only one row, satisfy the condition and return the data from TableA.

This works fine and I get the data extremely fast. But, my concern is, if I do the same with a view, the sql dies. Here is what I am doing -

If I run -

select A.*
from ViewA A

- it runs very fast.

If I run -

select A.*
from ViewA A,
security_table X
where X.agency_ind = 'AgencyA'
and X.operid = USER

- it goes forever though security_table fetches a single row.

Is it because of cartesian product with single row? Pl explain.

Thanks


Tom Kyte
June 08, 2005 - 9:59 pm UTC

what does the plan look like

I cannot tell because I don't have the schema, or the data.

many small SQLs or 1 big SQL

A reader, June 13, 2005 - 10:58 am UTC

Tom,

As a general practise, within a pl/sql procedure/function is it better (performance wise) to write 5-6 small SQLs or write a single big SQL query?

What i mean is which following method is better?

------------------------------------------------
select col1 into var1
from tab1
where <>;

select col2 into var2
from tab2
where tab2.<> = var1;

select col3 into var3
from tab3
where tab3.<> = var2;

select col4 into var4
from tab4
where tab4.<> = var3;

------------------------------------------------

select col1,col2,col3,col4
from tab1,tab2,tab3,tab4
where <>;

------------------------------------------------

Please comment.

Tom Kyte
June 13, 2005 - 11:54 am UTC

do as much in a single sql statement as you can and erase as much procedural code as possible.

this is really usefull

Shyam, June 21, 2005 - 8:05 am UTC

I have problem with redo log buffer.
when i query the datbase

SQL> Select name, value from v$sysstat
  2  Where name = 'redo log space requests';

NAME       VALUE
----- ------
redo log    419 
space requests                                                 

But actually this value should be ideally be zero.How can i fix this i had made Log_buffer=1M

Any other suggestions

Regards 

Tom Kyte
June 21, 2005 - 4:50 pm UTC

419 is the number since the instance is up and running.

419 is a small number if you ask me. Don't you think it is small?

But, this is not a wait for space in the log buffer (so playing with that, won't affect this). This is not a wait for lgwr to finish a write (that is log file sync).

This is something you might see at a log switch, if we cannot switch because of checkpoint not complete, or archival required.

So, do you see any of those messags in your alert log?

query tune

whizkid, June 21, 2005 - 2:04 pm UTC

hi tom,

would be grateful if you help once again.. stuck up with these two queries

SELECT (-1) * SUM(A.POSTING_AMT)
FROM
 ACC_POSTINGS A , BJAZ_ACX_TCODE B , AC_INTERNAL_ACCOUNTS C WHERE A.BATCH_ID =
   B.BATCH_ID AND A.EVENT_NO = B.EVENT_NO AND A.POSTING_NO = B.POSTING_NO AND
  A.INTERNAL_ACCOUNT_ID = C.INTERNAL_ACCOUNT_ID AND C.SUBFACTOR_1_VAL = :B3
  AND C.ACCOUNT_CATEGORY_CODE = '3110111105' AND B.RECEIPT_NO = :B2 AND
  B.COLLECTION_NO = :B1


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse       18      0.00       0.00          0          0          0           0
Execute     24      0.01       0.00          0          0          0           0
Fetch       24     65.60      64.08          1   10844907          0          24
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       66     65.61      64.09          1   10844907          0          24

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 5386     (recursive depth: 1)

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE
  74594   NESTED LOOPS
  74595    NESTED LOOPS
  74595     TABLE ACCESS BY GLOBAL INDEX ROWID BJAZ_ACX_TCODE PARTITION: ROW LOCATION ROW LOCATION
  74595      INDEX RANGE SCAN RCPT_COLL_IDX (object id 67452)
  74595     PARTITION RANGE ITERATOR PARTITION: KEY KEY
  74595      TABLE ACCESS BY LOCAL INDEX ROWID ACC_POSTINGS PARTITION: KEY KEY
  74595       INDEX RANGE SCAN ACC_P_PK PARTITION: KEY KEY (object id 67376)
  74594    INDEX RANGE SCAN IDX_SUB1_ACCTCD_INTAC (object id 97599)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  global cache cr request                        34        0.00          0.01
  db file sequential read                         1        0.00          0.00


and 

SELECT INTERNAL_ACCOUNT_ID
FROM
 AC_INTERNAL_ACCOUNTS WHERE SUBFACTOR_1_VAL = TO_CHAR(NVL(:B1,0)) AND
  ACCOUNT_CATEGORY_CODE ='3110111105' FOR UPDATE NOWAIT


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse       18      0.00       0.00          0          0          0           0
Execute    449    164.08     160.19          0    4615714        461           0
Fetch      449    164.63     160.59          0    4615712          0         449
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      916    328.71     320.78          0    9231426        461         449

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 5386     (recursive depth: 1)

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  FOR UPDATE
      2   CONCATENATION
      0    FILTER
      0     TABLE ACCESS BY INDEX ROWID AC_INTERNAL_ACCOUNTS
      0      INDEX RANGE SCAN IDX_AC_INT_ACC_SUBVAL1 (object id 96138)
      2    FILTER
      2     TABLE ACCESS BY INDEX ROWID AC_INTERNAL_ACCOUNTS
 505688      INDEX RANGE SCAN IDX_AC_INT_ACC_SUBVAL1 (object id 96138)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  global cache cr request                         1        0.00          0.00
  global cache null to x                          1        0.00          0.00

the table ac_internal_accounts has the following indexes 
SQL> l
  1  select table_name, index_name, column_name, column_position
  2  from dba_ind_columns where table_name = 'AC_INTERNAL_ACCOUNTS'
  3* order by 2, 4
SQL> /

TABLE_NAME                     INDEX_NAME                COLUMN_NAME               COLUMN_POSITION
------------------------------ ------------------------- ------------------------- ---------------
AC_INTERNAL_ACCOUNTS           AC_IA_PK                  INTERNAL_ACCOUNT_ID                     1
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 COMPANY_ID                              1
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 SWIFT_CODE                              2
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 ACCOUNT_CATEGORY_CODE                   3
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 SUBFACTOR_1_VAL                         4
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 SUBFACTOR_2_VAL                         5
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 SUBFACTOR_3_VAL                         6
AC_INTERNAL_ACCOUNTS           AC_IA_UK1                 SUBFACTOR_4_VAL                         7
AC_INTERNAL_ACCOUNTS           IDX_AC_INT_ACC_SUBVAL1    SUBFACTOR_1_VAL                         1
AC_INTERNAL_ACCOUNTS           IDX_AC_INT_ACC_SUBVAL2    SUBFACTOR_2_VAL                         1
AC_INTERNAL_ACCOUNTS           IDX_SUB1_ACCTCD_INTAC     INTERNAL_ACCOUNT_ID                     1
AC_INTERNAL_ACCOUNTS           IDX_SUB1_ACCTCD_INTAC     ACCOUNT_CATEGORY_CODE                   2
AC_INTERNAL_ACCOUNTS           IDX_SUB1_ACCTCD_INTAC     SUBFACTOR_1_VAL                         3
AC_INTERNAL_ACCOUNTS           IND_AC_INT_ACC_CATCODE    ACCOUNT_CATEGORY_CODE                   1

what new index could i add to speed up the response for these queries? 

Tom Kyte
June 21, 2005 - 5:24 pm UTC

2 TABLE ACCESS BY INDEX ROWID AC_INTERNAL_ACCOUNTS
505688 INDEX RANGE SCAN IDX_AC_INT_ACC_SUBVAL1 (object id 96138


that should be a red flag. Look at that index and you figure out what you can add to it so that you do not get 505,688 FALSE POSITIVES that result in only 2 rows from the table.


eg:

you have a predicate like "where x = :x and y = :y and z = :z"

you have a index on X only.

You run the query with :x = 100 and :y = 1. There are 505,688 rows with x = 100, only 2 of them have Y = 1. You needed to have indexed (x,y) not just x for this query.

A reader, June 21, 2005 - 7:21 pm UTC

Tom,

Why is the parse 18 times for the query?

Thanks.

Tom Kyte
June 21, 2005 - 11:54 pm UTC

if this is plsql, then it ran out of cursor cache space and had to be reparsed.

9205 and above - session_cached_cursors controls the size of the cache, before that open_cursors did.

Partha, June 21, 2005 - 10:47 pm UTC

Whizkid,

"what new index could i add to speed up the response for these queries? "

You're kidding right ?.

You seem to be having too many indexes (or is it indices?) in that table. It's not necessary to have indexes on all possible combination. Is this is a OLTP system or a Warehouse system ? If it is an OLTP, did you check out what impact it will have when you have to do inserts or updates on that table.

On first glance, looks like "AC_IA_UK1" index has all possible columns. Try to put the restrictive clauses ( company_id, swift_code) if possible / appropriate and allow it to use this index. You seriously need to rethink whether you need all those other exta indexes (for example idx_ac_int_acc_subval1, 2, etc).

And regarding parsing 18 times, it could be soft parse, when being called repetitively by opening and closing cursor (not sure).

parse count

whizkid, June 22, 2005 - 6:12 am UTC

hi tom,

this is being called from PL/SQL and we are on 9205. So does this mean that the session_cached_cursors value is too small? We have set it to 300. This is actually a batch job that gets run once in a while. So is it ok or should I increase the value?

tom, on concatenated column indexes, how exactly should we decide on the order of the columns? does it also matter? suppose :x returns 550000 rows and :y returns 2 rows. show should the index be on (x, y) or (y, x) or any order and no difference. i was under the impression that the leading edge column should have minimum number of rows?


Partha,

We have an OLTP system and have monitored for inserts / updates. there are no problems during that. but we have selects on this table using all possible permutations and this being a big table, it takes a lot of time to get the results.

Tom Kyte
June 22, 2005 - 7:09 am UTC

look at this holistically...

how much time did you spend in this case parsing? it doesn't seem to be an issue here.


do you have access to Expert One on One Oracle? I cover the order of columns in the index. If the only query is "where x = :x and y = :y", the order of the columns isn't really relevant.

You are quoting a big big myth that the leading edge should be "most selective"

Re: parse count

whizkid, June 22, 2005 - 7:17 am UTC

well.. not that i look at it, it does not take any time in parsing at all.. guess I got an attack of CTD. :-)

I do not have your Expert One on One Oracle. :-( Is it possible for you to paste the appropriate extract here?

thanks.



Tom Kyte
June 22, 2005 - 7:25 am UTC

basically, you choose the order of columns in the index based on the QUESTIONS you ask.


where x = :x and y = :y
where x > :x and y = :y

that would lead me to want an index on (y,x), REGARDLESS of the distinctness of either. that index would be best for both.


where x = :x
where x = :x and y = :y
where x = :x and y = :y and z = :z

would lead me to want an index in (x,y,z), REGARDLESS of the distinctness of x,y,z. That single index would be useful for all three


you look at the QUESTIONS asked and based on that pick the index of choice. The book just showed how the index on (x,y) or (y,x) used with the predicate where x = :x and y = :y performance identically regardless of the distinctness of either.

performance issue when loading data

shyam, June 22, 2005 - 1:50 pm UTC

Tom when loading data for evry 10 mins it is generating 1.2 GB of log.over all for loading it is taking 12 hours to load.

pl let me know what should i do to decrease the loading time.loading is not done with exp imp or sqlloader i is done using .net procedure.



Tom Kyte
June 23, 2005 - 1:42 pm UTC

like I said elsewhere for this question

you are probably doing this slow by slow (row by row) and not really taking advantage of any database feature whatsoever

but given the inputs we have here, that is all anyone could say.


1.2 gig of log is pretty small for a 12 hour load.




A reader, June 27, 2005 - 2:25 pm UTC

Hi Tom,

We have a situation like this:

Table t1 has some indexes.

The query was intially using all the indexes.

But, later we had copied that data into a

new table and built all the indexes. Since then,

the query has stopped using indexes. Could you guide

us what could be the reason? We have sufficient amount

of data for CBO to use indexes.

Thanks.

Tom Kyte
June 27, 2005 - 2:50 pm UTC

likely culprit is the clustering factor is very different after the reorg of the table.

but, are you sure indexes would be your "fast=true" switch here, suggest you hint it for a test -- indexes are not always the best thing.

Florin, June 29, 2005 - 5:29 am UTC

Hi,

I have a table with 2 million records and the application needs the following:

select count(*) ,max(RUN_NO) from TRB1_SUB_APPL_CNTRL;

This query is taking 1-2 seconds which is too much.

There is n index on RUN_NO but still is doing full scan on the index (because of the count).

There is any way to improve this query?

Many thanks in advance.



Tom Kyte
June 29, 2005 - 9:02 am UTC

1-2 seconds to count millions of records and this is a problem? hmm

unless you maintain the count somewhere, well, don't know what to tell you.

Florin, June 29, 2005 - 5:30 am UTC

Hi,

I have a table with 2 million records and the application needs the following:

select count(*) ,max(RUN_NO) from TRB1_SUB_APPL_CNTRL;

This query is taking 1-2 seconds which is too much.

There is an index on RUN_NO but still is doing full scan on the index (because of the count).

There is any way to improve this query?

Many thanks in advance.



Florin, July 02, 2005 - 6:13 am UTC

Hi,

Well you're right, actually the query is :

select count(*) ,max(RUN_NO)into :b0,:b1 from TRB1_SUB_APPL_CNTRL;

Doing full scan on its PK.

Do you have any suggestions for improvement?

Thanks a lot!

Tom Kyte
July 02, 2005 - 9:33 am UTC

ask the author of the query why counting all of the rows is actually relevant to the processing or if it is just a number stuffed on the bottom of a report no one looks at (preference 1)

investigate materialized views if you find this number actually "means" something and is retrieved frequently.


(I'd lay odds that the number isn't actually relevant, it is just "there". And as Cary Millsap says "the best way to speed something up is to not do it at all")

OK

Raju, July 04, 2005 - 10:00 pm UTC

Hi Tom,
I tried a query which must return table names like
file$,source$,user$,fet$,uet$,trigger$ etc. as follows

SQL > select name from v$fixed_table
where name like '%$'

But this returns x$tables only and does not return tables
what I expected.
How to write a query for my requirement?

Do we need to use any escape sequences in that query???


Tom Kyte
July 05, 2005 - 7:25 am UTC

file$, source$ and such are real tables, not fixed tables.

query the dictionary for them


ops$tkyte@ORA9IR2> select table_name from dba_tables where table_name like '%$';
 
TABLE_NAME
------------------------------
SEG$
CLU$
OBJ$
FILE$
..... 

Thanks

Raju, July 05, 2005 - 9:55 pm UTC

Hi Tom,
Thanks for your reply.
What is the difference between real tables and fixed tables??
I am not aware of this.
Please let me know.

Tom Kyte
July 06, 2005 - 7:37 am UTC

fixed tables are in memory views of SGA regions typically.

Tuning

Anil Pant, July 07, 2005 - 9:00 am UTC

Hello,
We have a query which is taking 5-7 minutes to run. I dont have access to generate the statistics and also cannot take a tkprof.
How best can I improve the performance of the query?

Iam working on Oracle 9i and I dont have much idea about the server configuration.

SELECT consumers.cons_seq_nbr
FROM rel_type,
third_pty_rel,
cons_third_pty_rel,
consumers,
cons_ctct,
contact,
ctct_addr,
address,
cust_site
WHERE rel_type.third_pty_seq_nbr = ln_var1 AND
consumers.external_cons_nbr = ls_var2 AND
(consumers.cons_sts_type = ls_ACTIVE OR consumers.cons_sts_type = ls_BLOCKED) AND
third_pty_rel.rltn_nbr = ln_var3 AND
third_pty_rel.sts_type = ls_ACTIVE AND
rel_type.third_pty_rel_type = ls_var4 AND
rel_type.rel_type_seq_nbr = third_pty_rel.rel_type_seq_nbr AND
third_pty_rel.third_pty_rel_seq_nbr = cons_third_pty_rel.third_pty_rel_seq_nbr AND
cons_third_pty_rel.cons_seq_nbr = consumers.cons_seq_nbr AND
consumers.cons_seq_nbr = cons_ctct.cons_seq_nbr (+) AND
cons_ctct.cons_ctct_prmy_ind (+) = ls_Y AND
cons_ctct.ctct_seq_nbr = contact.ctct_seq_nbr (+) AND
contact.ctct_seq_nbr = ctct_addr.ctct_seq_nbr (+) AND
ctct_addr.ctct_addr_prmy_ind (+) = ls_Y AND
ctct_addr.addr_seq_nbr = address.addr_seq_nbr (+) AND
consumers.cust_seq_nbr = cust_site.cust_seq_nbr

Below is the explain plan output

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=1279 Card=1 Bytes=132)
1 0 NESTED LOOPS (OUTER) (Cost=1279 Card=1 Bytes=132)
2 1 NESTED LOOPS (OUTER) (Cost=1278 Card=1 Bytes=126)
3 2 NESTED LOOPS (OUTER) (Cost=1274 Card=1 Bytes=112)
4 3 NESTED LOOPS (OUTER) (Cost=1273 Card=1 Bytes=106)
5 4 NESTED LOOPS (Cost=1270 Card=1 Bytes=92)
6 5 NESTED LOOPS (Cost=1269 Card=1 Bytes=87)
7 6 NESTED LOOPS (Cost=1267 Card=1 Bytes=57)
8 7 NESTED LOOPS (Cost=1263 Card=1 Bytes=45)
9 8 TABLE ACCESS (BY INDEX ROWID) OF 'REL_TYPE' (Cost=5 Card=1 Bytes=21)

10 9 INDEX (RANGE SCAN) OF 'FK_REL_TYPE' (NON-UNIQUE) (Cost=4 Card=1)
11 8 TABLE ACCESS (BY INDEX ROWID) OF 'THIRD_PTY_REL' (Cost=1258 Card=1 Bytes=24)
12 11 INDEX (RANGE SCAN) OF 'FK_THIRD_PTY_REL_3' (NON-UNIQUE) (Cost=11 Card=12)
13 7 TABLE ACCESS (BY INDEX ROWID) OF 'CONS_THIRD_PTY_REL' (Cost=4 Card=1 Bytes=12)
14 13 INDEX (RANGE SCAN) OF 'FK_CONS_THIRD_PTY_REL_1' (NON-UNIQUE) (Cost=3 Card=1)
15 6 TABLE ACCESS (BY INDEX ROWID) OF 'CONSUMERS' (Cost=2 Card=1 Bytes=30)
16 15 INDEX (UNIQUE SCAN) OF 'PK_CONSUMERS' (UNIQUE) (Cost=1 Card=278)
17 5 INDEX (RANGE SCAN) OF 'FK_CUST_SITE_2' (NON-UNIQUE) (Cost=1 Card=1 Bytes=5)
18 4 TABLE ACCESS (BY INDEX ROWID) OF 'CONS_CTCT' (Cost=3 Card=1 Bytes=14)
19 18 INDEX (RANGE SCAN) OF 'FK_CONS_CTCT_2' (NON-UNIQUE) (Cost=2 Card=1)
20 3 INDEX (UNIQUE SCAN) OF 'PK_CONTACT' (UNIQUE) (Cost=1 Card=1 Bytes=6)
21 2 TABLE ACCESS (BY INDEX ROWID) OF 'CTCT_ADDR' (Cost=4 Card=1 Bytes=14)
22 21 INDEX (RANGE SCAN) OF 'FK_CTCT_ADDR2' (NON-UNIQUE) (Cost=3 Card=1)
23 1 INDEX (UNIQUE SCAN) OF 'PK_ADDRESS' (UNIQUE) (Cost=1 Card=1 Bytes=6)




About the tables

REL_TYPE - 58490000 rows
CONSUMERS - 10970000 rows
THIRD_PTY_REL - 76880000 rows



Tom Kyte
July 07, 2005 - 9:51 am UTC

are the card= values in the autotrace even REMOTELY accurate. If they are, this would not be a 5-7 minute query.

Thks

Anil Pant, July 08, 2005 - 1:28 am UTC

Does it mean I need to analyze the tables or is there anything else to be done ?

Tom Kyte
July 08, 2005 - 7:29 am UTC

no, you need to look at the generated plan and using your intimate knowledge of your data say "those numbers look accurate" or "those numbers are way off"

Tuning SQL - The practical approach ?

SVS, July 09, 2005 - 4:13 pm UTC

Hi Tom

I am aware that for SQL Tuning there is no methodology which exists and you have suggested to read the following

</code> http://download-west.oracle.com/docs/cd/A87860_01/doc/server.817/a76965/toc.htm

from cover to cover and

http://download-west.oracle.com/docs/cd/A87860_01/doc/server.817/a76992/toc.htm <code>

as well

Someone the other day asked me the following question

What if my query is running perfectly fine as of yesterday but today all of a sudden its not as per the expected result. What are the steps that you would follow ?

My answer to which was that I would

Step 1 : See the Explain Plan for that statement.
Step 2 : Gather the Statistics for the objects being referenced by the query.
Step 3 : Check if we got any performance gain.
Step 4 : I would then enable Tracing for the Session and apply TKPROF to it.
Step 5 : Check the output generated by TKPROF looking for the problem area.
Step 6 : Apply corrective action. e.g. use of Bind variables, use of Bulk Binding, etc.

Please correct me if I am wrong or let me know if I am missing anything.

Would really appreciate if you could put the Steps that you would generally follow.

Thanks

SVS

Tom Kyte
July 10, 2005 - 9:12 am UTC

step 6 is a little more open than that

basically "something changed", you need to find out what.

Could be the query was running "fine" yesterday because it returned 100 rows.
Today it returns 100,000.

It could still be "fine, but different" - your data changed.

could be the query was running "fine" yesterday, bad to day, returns same number of rows but some index that was selective yesterday became unselective as your data changed (where x = ? and y = ? -- you had index on x, but not x,y. Yesterday you had 50 rows where x = 10, and 5 of those rows had y = 10. Today you have 50,000 rows where x =10 and 5 still have y = 10, same number of rows returned but some 49,950 extra table access by index rowids added to the execution path)

but in general, yes 1..5

Tuning SQL - The practical approach ?

A reader, July 10, 2005 - 5:04 pm UTC

Tom

Many thanks for answering Tom.....

One more question :)

What would the areas that YOU would look upon AS SOON AS your eyes set on any Explain plan ?? And also a short briefing on how working on those areas could improve the performance ?

Really appreciate your work Tom....

SVS

Tom Kyte
July 10, 2005 - 5:21 pm UTC

hard to say -- sort of a "blink" operation (based on the book "blink")...

in fact, this question leads to a book :) I look for the obvious first and foremost - and what is the obvious? Well, if I had to tell you that, it wouldn't be obvious.

I wouldn't be looking at the explain plan in isolation -- I'd want the tkprof as well and if available (could be with 10g.... and even before if you kept it) last weeks information as well.

maybe one of the first things I'd do if it wasn't "obvious", would be to verify the card= in the plans are even remotely close to the actuals from the tkprof.

A reader, July 10, 2005 - 5:33 pm UTC

Tom

I didn't quite get this "verify
the card= in the plans are even remotely close to the actuals from the tkprof"

SVS

Doing a join vs PLSQL table

Ravi Kumar, July 13, 2005 - 3:45 am UTC

Hi Tom

I am a big fan of you :)

I just want to know.. will it be better to avoid a join in a cursor if there is a huge diffrence in the number of records of both tables.

for example.. we need to join DEPT and EMP table in a CURSOR. And If EMP table has millions of records and dept table has only 4 records. then will it be better to avoid the join and collect the information of DEPT table in a PL/SQL collection and process that for each employee by looping through that collection.

OR if there is any other way out for this.

Thanks & Regards
Ravi Kumar

Tom Kyte
July 13, 2005 - 11:06 am UTC

if you can do it in SQL, do it.

databases were born to

a) join
b) be written to


do not be afraid to ask them to do either of those things and avoid trying to "take it easy on the database", it really does things like JOINING data really well. It is it's goal in life.

rewrite of "( (a AND b) OR (c AND d) )" predicate

A reader, July 14, 2005 - 7:47 am UTC

dear tom,

i have a select statement containing two "( (a AND b) OR (c AND d) )" clauses in the predicate. the execution plan tells us that the statement is beeing rewritten to a union all one. this repetitive access seems to be very inefficient. any idea to rewrite and avoid this?


SQL> SELECT   p1.portid equ_port, l.linkid LINK, p2.portid mdf_port,
  2           cc.crossconnectionid xconn, p3.portid tada_mdf_port
  3      FROM port p1,
  4           port p2,
  5           port p3,
  6           LINK l,
  7           crossconnection cc,
  8           shelf sh1,
  9           slot sl1,
 10           cardinslot cis1,
 11           card c
 12     WHERE p1.port2node = :b1
 13       AND p1.port2porttype = :b2
 14       AND (   (l.link2sourceport = p1.portid AND l.link2destport = p2.portid)
 15            OR (l.link2sourceport = p2.portid AND l.link2destport = p1.portid)
 16           )
 17       AND p2.port2provisionstatus = :b3
 18       AND (   (cc.cc2aport = p2.portid AND cc.cc2zport = p3.portid)
 19            OR (cc.cc2aport = p3.portid AND cc.cc2zport = p2.portid)
 20           )
 21       AND p3.port2provisionstatus = :b3
 22       AND p3.NAME LIKE '%.%.%.%\_%-%' ESCAPE '\'
 23       AND p1.port2card = c.cardid
 24       AND c.card2provisionstatus IN (:b5 * :b6, :b7, :b8, :b9, :b10)
 25       AND p1.port2card = cis1.cardinslot2card
 26       AND cis1.cardinslot2slot = sl1.slotid
 27       AND sl1.slot2shelf = sh1.shelfid
 28  ORDER BY sh1.shelfnumber, sl1.slotnumber, p1.portnumber
 29  /

Es wurden keine Zeilen ausgewählt

Abgelaufen: 00:00:00.00

Ausführungsplan
----------------------------------------------------------
   0        SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=92 Card=4 Bytes=508)
   1      0   SORT (ORDER BY) (Cost=92 Card=4 Bytes=508)
   2      1     CONCATENATION
   3      2       NESTED LOOPS (Cost=22 Card=1 Bytes=127)
   4      3         NESTED LOOPS (Cost=20 Card=1 Bytes=100)
   5      4           NESTED LOOPS (Cost=17 Card=1 Bytes=85)
   6      5             NESTED LOOPS (Cost=15 Card=1 Bytes=74)
   7      6               NESTED LOOPS (Cost=13 Card=1 Bytes=60)
   8      7                 NESTED LOOPS (Cost=12 Card=1 Bytes=53)
   9      8                   NESTED LOOPS (Cost=11 Card=1 Bytes=43)
  10      9                     NESTED LOOPS (Cost=9 Card=1 Bytes=33)
  11     10                       TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=8 Card=1 Bytes=22)
  12     11                         INDEX (RANGE SCAN) OF 'PORT_PC_FK_I' (NON-UNIQUE) (Cost=3 Card=1)
  13     10                       TABLE ACCESS (BY INDEX ROWID) OF 'CARD' (Cost=1 Card=34847 Bytes=383317)
  14     13                         INDEX (UNIQUE SCAN) OF 'CARD_PK' (UNIQUE)
  15      9                     TABLE ACCESS (BY INDEX ROWID) OF 'CARDINSLOT' (Cost=2 Card=78480 Bytes=784800)
  16     15                       INDEX (RANGE SCAN) OF 'CIS_CARD_FK_I' (NON-UNIQUE) (Cost=1 Card=78480)
  17      8                   TABLE ACCESS (BY INDEX ROWID) OF 'SLOT' (Cost=1 Card=226444 Bytes=2264440)
  18     17                     INDEX (UNIQUE SCAN) OF 'SLOT_PK' (UNIQUE)
  19      7                 TABLE ACCESS (BY INDEX ROWID) OF 'SHELF' (Cost=1 Card=5030 Bytes=35210)
  20     19                   INDEX (UNIQUE SCAN) OF 'SHELF_PK' (UNIQUE)
  21      6               TABLE ACCESS (BY INDEX ROWID) OF 'LINK' (Cost=2 Card=257386 Bytes=3603404)
  22     21                 INDEX (RANGE SCAN) OF 'LINK_PORT_CONNECTED_AT_THE_A_1' (NON-UNIQUE) (Cost=1 Card=257
            386)

  23      5             TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=80714 Bytes=887854)
  24     23               INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=80714)
  25      4           TABLE ACCESS (BY INDEX ROWID) OF 'CROSSCONNECTION' (Cost=3 Card=101601 Bytes=1524015)
  26     25             INDEX (RANGE SCAN) OF 'CCON_PORT_FK2_I' (NON-UNIQUE) (Cost=2 Card=101601)
  27      3         TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=4036 Bytes=108972)
  28     27           INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=4036)
  29      2       NESTED LOOPS (Cost=22 Card=1 Bytes=127)
  30     29         NESTED LOOPS (Cost=20 Card=1 Bytes=100)
  31     30           NESTED LOOPS (Cost=17 Card=1 Bytes=85)
  32     31             NESTED LOOPS (Cost=15 Card=1 Bytes=74)
  33     32               NESTED LOOPS (Cost=13 Card=1 Bytes=60)
  34     33                 NESTED LOOPS (Cost=12 Card=1 Bytes=53)
  35     34                   NESTED LOOPS (Cost=11 Card=1 Bytes=43)
  36     35                     NESTED LOOPS (Cost=9 Card=1 Bytes=33)
  37     36                       TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=8 Card=1 Bytes=22)
  38     37                         INDEX (RANGE SCAN) OF 'PORT_PC_FK_I' (NON-UNIQUE) (Cost=3 Card=1)
  39     36                       TABLE ACCESS (BY INDEX ROWID) OF 'CARD' (Cost=1 Card=34847 Bytes=383317)
  40     39                         INDEX (UNIQUE SCAN) OF 'CARD_PK' (UNIQUE)
  41     35                     TABLE ACCESS (BY INDEX ROWID) OF 'CARDINSLOT' (Cost=2 Card=78480 Bytes=784800)
  42     41                       INDEX (RANGE SCAN) OF 'CIS_CARD_FK_I' (NON-UNIQUE) (Cost=1 Card=78480)
  43     34                   TABLE ACCESS (BY INDEX ROWID) OF 'SLOT' (Cost=1 Card=226444 Bytes=2264440)
  44     43                     INDEX (UNIQUE SCAN) OF 'SLOT_PK' (UNIQUE)
  45     33                 TABLE ACCESS (BY INDEX ROWID) OF 'SHELF' (Cost=1 Card=5030 Bytes=35210)
  46     45                   INDEX (UNIQUE SCAN) OF 'SHELF_PK' (UNIQUE)
  47     32               TABLE ACCESS (BY INDEX ROWID) OF 'LINK' (Cost=2 Card=257386 Bytes=3603404)
  48     47                 INDEX (RANGE SCAN) OF 'LINK_PORT_CONNECTED_AT_THE_A_1' (NON-UNIQUE) (Cost=1 Card=257
            386)

  49     31             TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=80714 Bytes=887854)
  50     49               INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=80714)
  51     30           TABLE ACCESS (BY INDEX ROWID) OF 'CROSSCONNECTION' (Cost=3 Card=101601 Bytes=1524015)
  52     51             INDEX (RANGE SCAN) OF 'CCON_PORT_FK_I' (NON-UNIQUE) (Cost=2 Card=101601)
  53     29         TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=4036 Bytes=108972)
  54     53           INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=4036)
  55      2       NESTED LOOPS (Cost=22 Card=1 Bytes=127)
  56     55         NESTED LOOPS (Cost=20 Card=1 Bytes=100)
  57     56           NESTED LOOPS (Cost=17 Card=1 Bytes=85)
  58     57             NESTED LOOPS (Cost=15 Card=1 Bytes=74)
  59     58               NESTED LOOPS (Cost=13 Card=1 Bytes=60)
  60     59                 NESTED LOOPS (Cost=12 Card=1 Bytes=53)
  61     60                   NESTED LOOPS (Cost=11 Card=1 Bytes=43)
  62     61                     NESTED LOOPS (Cost=9 Card=1 Bytes=33)
  63     62                       TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=8 Card=1 Bytes=22)
  64     63                         INDEX (RANGE SCAN) OF 'PORT_PC_FK_I' (NON-UNIQUE) (Cost=3 Card=1)
  65     62                       TABLE ACCESS (BY INDEX ROWID) OF 'CARD' (Cost=1 Card=34847 Bytes=383317)
  66     65                         INDEX (UNIQUE SCAN) OF 'CARD_PK' (UNIQUE)
  67     61                     TABLE ACCESS (BY INDEX ROWID) OF 'CARDINSLOT' (Cost=2 Card=78480 Bytes=784800)
  68     67                       INDEX (RANGE SCAN) OF 'CIS_CARD_FK_I' (NON-UNIQUE) (Cost=1 Card=78480)
  69     60                   TABLE ACCESS (BY INDEX ROWID) OF 'SLOT' (Cost=1 Card=226444 Bytes=2264440)
  70     69                     INDEX (UNIQUE SCAN) OF 'SLOT_PK' (UNIQUE)
  71     59                 TABLE ACCESS (BY INDEX ROWID) OF 'SHELF' (Cost=1 Card=5030 Bytes=35210)
  72     71                   INDEX (UNIQUE SCAN) OF 'SHELF_PK' (UNIQUE)
  73     58               TABLE ACCESS (BY INDEX ROWID) OF 'LINK' (Cost=2 Card=257386 Bytes=3603404)
  74     73                 INDEX (RANGE SCAN) OF 'LINK_PORT_FK_I' (NON-UNIQUE) (Cost=1 Card=257386)
  75     57             TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=80714 Bytes=887854)
  76     75               INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=80714)
  77     56           TABLE ACCESS (BY INDEX ROWID) OF 'CROSSCONNECTION' (Cost=3 Card=101601 Bytes=1524015)
  78     77             INDEX (RANGE SCAN) OF 'CCON_PORT_FK2_I' (NON-UNIQUE) (Cost=2 Card=101601)
  79     55         TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=4036 Bytes=108972)
  80     79           INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=4036)
  81      2       NESTED LOOPS (Cost=22 Card=1 Bytes=127)
  82     81         NESTED LOOPS (Cost=20 Card=1 Bytes=100)
  83     82           NESTED LOOPS (Cost=17 Card=1 Bytes=85)
  84     83             NESTED LOOPS (Cost=15 Card=1 Bytes=74)
  85     84               NESTED LOOPS (Cost=13 Card=1 Bytes=60)
  86     85                 NESTED LOOPS (Cost=12 Card=1 Bytes=53)
  87     86                   NESTED LOOPS (Cost=11 Card=1 Bytes=43)
  88     87                     NESTED LOOPS (Cost=9 Card=1 Bytes=33)
  89     88                       TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=8 Card=1 Bytes=22)
  90     89                         INDEX (RANGE SCAN) OF 'PORT_PC_FK_I' (NON-UNIQUE) (Cost=3 Card=1)
  91     88                       TABLE ACCESS (BY INDEX ROWID) OF 'CARD' (Cost=1 Card=34847 Bytes=383317)
  92     91                         INDEX (UNIQUE SCAN) OF 'CARD_PK' (UNIQUE)
  93     87                     TABLE ACCESS (BY INDEX ROWID) OF 'CARDINSLOT' (Cost=2 Card=78480 Bytes=784800)
  94     93                       INDEX (RANGE SCAN) OF 'CIS_CARD_FK_I' (NON-UNIQUE) (Cost=1 Card=78480)
  95     86                   TABLE ACCESS (BY INDEX ROWID) OF 'SLOT' (Cost=1 Card=226444 Bytes=2264440)
  96     95                     INDEX (UNIQUE SCAN) OF 'SLOT_PK' (UNIQUE)
  97     85                 TABLE ACCESS (BY INDEX ROWID) OF 'SHELF' (Cost=1 Card=5030 Bytes=35210)
  98     97                   INDEX (UNIQUE SCAN) OF 'SHELF_PK' (UNIQUE)
  99     84               TABLE ACCESS (BY INDEX ROWID) OF 'LINK' (Cost=2 Card=257386 Bytes=3603404)
 100     99                 INDEX (RANGE SCAN) OF 'LINK_PORT_FK_I' (NON-UNIQUE) (Cost=1 Card=257386)
 101     83             TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=80714 Bytes=887854)
 102    101               INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=80714)
 103     82           TABLE ACCESS (BY INDEX ROWID) OF 'CROSSCONNECTION' (Cost=3 Card=101601 Bytes=1524015)
 104    103             INDEX (RANGE SCAN) OF 'CCON_PORT_FK_I' (NON-UNIQUE) (Cost=2 Card=101601)
 105     81         TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cost=2 Card=4036 Bytes=108972)
 106    105           INDEX (UNIQUE SCAN) OF 'PORT_PK' (UNIQUE) (Cost=1 Card=4036)




Statistiken
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         64  consistent gets
          0  physical reads
          0  redo size
        240  bytes sent via SQL*Net to client
       1378  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          0  rows processed 

Tom Kyte
July 14, 2005 - 11:01 am UTC

his repetitive access seems to be very
inefficient....


why do you say that? It looks pretty awesome from where I am sitting.

rewrite of "( (a AND b) OR (c AND d) )" predicate

A reader, July 14, 2005 - 11:36 am UTC

dear tom,

looking at the execution plan we see that it is scanning the _same_ data (blocks) for four times. and there are plenty of rows in play. the reason for the low statistic count is that i couldn't find a working parameter configuration leading to a result set > 0.

i think this statement would be more effective if i could reduce this four time data scanning to one. to you see any way to do this? maybe using analytical functions? btw: we are running on oracle ee 8.1.7.4 at the moment.

Tom Kyte
July 14, 2005 - 12:42 pm UTC

how do you see the _SAME_ data blocks

I see basically that your or was expanded out rather efficiently to use the indexes on DIFFERENT sets of blocks.

You are not seeing "four scans" of data, you are seeing four index probes to rapidly find your 4 bits of information.

rewrite of "( (a AND b) OR (c AND d) )" predicate

A reader, July 15, 2005 - 4:48 am UTC

dear tom,

i think my inital or clauses will be internally rewritten from

...
AND ( (a AND b) OR (c AND d) )
AND ( (e AND f) OR (g AND h) )
...

to

...
AND (a AND b)
AND (e AND f)
UNION ALL
AND (a AND b)
AND (g AND h)
UNION ALL
AND (c AND d)
AND (e AND f)
UNION ALL
AND (c AND d)
AND (g AND h)
...

so, each side of an OR will be scanned for two times! this scanning is done on the same blocks as it is the same predicate!?

Tom Kyte
July 15, 2005 - 7:44 am UTC

please explain to me how you think the plan should look. tell me, what would be *more efficient* than the or expansion.

you tell us the algorithm you think will be best here.

OR expansion in this case looks "really good" to me.

you would not be revisiting all of the same blocks here.

rewrite of "( (a AND b) OR (c AND d) )" predicate

A reader, July 15, 2005 - 9:51 am UTC

reading once and reusing the result set as analytics do, eg. when using grouping sets?

tom, that's exactly the point! i am asking _you_ if i can rewrite this query to avoid rereading.

Tom Kyte
July 15, 2005 - 5:56 pm UTC

and I keep saying "plan looks awesome"

or expansion like this is OK, it is what you WANT to happen.

what cuases CONCATENATION

PINGU, July 22, 2005 - 10:45 am UTC

Hi

I have this query

SELECT *
FROM pa_expenditure_items itm,
pa_expenditure_items itm1,
pa_cost_distribution_lines cdl
WHERE itm.expenditure_item_id = :b2
AND itm1.expenditure_item_id = itm.adjusted_expenditure_item_id
AND DECODE(itm1.cost_distributed_flag, 'S',
DECODE(itm1.cost_dist_rejection_code, NULL, 'Y', 'N'), 'N', 'N', 'Y') = 'Y'
AND cdl.expenditure_item_id = itm.adjusted_expenditure_item_id
AND cdl.reversed_flag IS NULL
AND cdl.line_num_reversed IS NULL
AND cdl.line_type = :b3
AND cdl.line_num = (SELECT MAX(cdl1.line_num)
FROM pa_cost_distribution_lines cdl1
WHERE cdl1.expenditure_item_id = cdl.expenditure_item_id
AND cdl1.line_type = cdl.line_type
AND cdl1.reversed_flag IS NULL
AND cdl1.line_num_reversed IS NULL )
AND :b65:b76 IS NOT NULL
AND :b66:b78 IS NOT NULL
AND :b91 IS NULL
AND itm.adjusted_expenditure_item_id IS NOT NULL
AND NOT EXISTS
(
SELECT NULL
FROM pa_cost_distribution_lines cdl3
WHERE cdl3.expenditure_item_id = :b2
AND DECODE (cdl3.line_type, 'C', cdl3.cr_code_combination_id, cdl3.dr_code_combination_id) = :b93
AND cdl3.billable_flag = :b42
AND cdl3.line_type = DECODE (:b3, 'R', DECODE (:b48, 'N', 'I', :b3), :b3) -- CAUSES CONCAT
AND cdl3.line_num_reversed IS NULL
AND cdl3.reversed_flag IS NULL
)

it has this plan


-----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
-----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 855 | 24 |
| 1 | FILTER | | | | |
| 2 | SORT GROUP BY | | 1 | 855 | 24 |
| 3 | FILTER | | | | |
| 4 | NESTED LOOPS | | 1 | 855 | 11 |
| 5 | NESTED LOOPS | | 1 | 835 | 8 |
| 6 | NESTED LOOPS | | 1 | 642 | 5 |
| 7 | TABLE ACCESS BY INDEX ROWID| PA_EXPENDITURE_ITEMS_ALL | 1 | 321 | 3 |
| 8 | INDEX UNIQUE SCAN | PA_EXPENDITURE_ITEMS_U1 | 1 | | 2 |
| 9 | TABLE ACCESS BY INDEX ROWID| PA_EXPENDITURE_ITEMS_ALL | 1 | 321 | 2 |
| 10 | INDEX UNIQUE SCAN | PA_EXPENDITURE_ITEMS_U1 | 1 | | 1 |
| 11 | TABLE ACCESS BY INDEX ROWID | PA_COST_DISTRIBUTION_LINES_ALL | 1 | 193 | 3 |
| 12 | INDEX RANGE SCAN | PA_COST_DISTRIBUTION_LINES_U1 | 1 | | 2 |
| 13 | TABLE ACCESS BY INDEX ROWID | PA_COST_DISTRIBUTION_LINES_ALL | 1 | 20 | 3 |
| 14 | INDEX RANGE SCAN | PA_COST_DISTRIBUTION_LINES_U1 | 1 | | 2 |
| 15 | CONCATENATION | | | | |
| 16 | FILTER | | | | |
| 17 | TABLE ACCESS BY INDEX ROWID | PA_COST_DISTRIBUTION_LINES_ALL | 1 | 37 | 4 |
| 18 | INDEX RANGE SCAN | PA_COST_DISTRIBUTION_LINES_U1 | 1 | | 3 |
| 19 | FILTER | | | | |
| 20 | TABLE ACCESS BY INDEX ROWID | PA_COST_DISTRIBUTION_LINES_ALL | 1 | 37 | 4 |
| 21 | INDEX RANGE SCAN | PA_COST_DISTRIBUTION_LINES_U1 | 1 | | 3 |
-----------------------------------------------------------------------------------------------------


if I get rid of this line

AND cdl3.line_type = DECODE (:b3, 'R', DECODE (:b48, 'N', 'I', :b3), :b3) -- CAUSES CONCAT

The concatenation disappears. Why decode causes concatenation?

I also see from this thread that a simple query such as following causes a table to be scanned twice (concatenation) once by index and the other full. How so? Isnt a single full scan enough?

select * from tab_1
where a = nvl(:b1, :b2)

Tom Kyte
July 22, 2005 - 10:56 am UTC

but there could be a filter in there that causes only one side of the concatenation to take place.


so the query is really a "do THIS when this is true ELSE do this when this is false"

meaning, in the plan like this:

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=9 Card=88 Bytes=8096)
1 0 CONCATENATION
2 1 FILTER
3 2 TABLE ACCESS (FULL) OF 'POV' (Cost=3 Card=8 Bytes=736)
4 1 FILTER
5 4 TABLE ACCESS (BY INDEX ROWID) OF 'POV' (Cost=3 Card=8 Bytes=736)
6 5 INDEX (RANGE SCAN) OF 'POV_IDX' (NON-UNIQUE) (Cost=2 Card=1)


EITHER that table would be full scanned (if binds not supplied - are null, get all rows) OR use an index (binds did have a non-null value)


Why do you believe the concatenation to be evil?


AND cdl3.line_type = DECODE (:b3, 'R', DECODE (:b48, 'N', 'I', :b3),
:b3 )


IF :b3 is NULL then this becomes

and cdl3.line_type = NULL - which is never true, optimize work away, else

IF :b3 is NOT NULL then this becomes something that might be true.




A reader, August 08, 2005 - 8:48 am UTC

Hi Tom
Would you give me some advise how to tune the sql following?It's too slow.
-------------------------------------------------
select name,tonegroupid,creator,price,status,settime,downloadtimes,type,refusereason,description,loopcount,flag, feetype,

toneboxcode
from (
select name,t_toneboxinfo.tonegroupid,creator,price,status,settime,downloadtimes,type,refusereason,
description,loopcount,0 as flag, feetype, toneboxcode
from t_toneboxinfo,(select count(tonecode) loopcount,tonegroupid from t_looptone group by tonegroupid) b
where b.tonegroupid=t_toneboxinfo.tonegroupid
and not exists(select 'X' from t_toneboxinfotemp e where t_toneboxinfo.tonegroupid=e.tonegroupid)
union
select name,t_toneboxinfotemp.tonegroupid,creator,price,status,settime,downloadtimes,type,refusereason,description,

loopcount,1 as flag, feetype, toneboxcode
from t_toneboxinfotemp,(select count(tonecode) loopcount,tonegroupid from t_looptonetemp group by tonegroupid) b
where b.tonegroupid=t_toneboxinfotemp.tonegroupid
) a
where a.creator=? ORDER BY a.tonegroupid

Tom Kyte
August 08, 2005 - 7:44 pm UTC

I see a couple of patterns here (maybe I should use a notepad and write these down... I know them when I see them but ask me to list them on a whiteboard and I cannot...)

a) union -- why union? Is union needed?

A union B is sort-distinct( A+B )
A union ALL B is (A+B) -- no sort-distinct.

you see the flag column -- they are non-intersecting sets (one is all 0 the other all 1). So, unless you need to de-dup each part of the union, skip it, union all.

b) not pushing the predicate down, maybe the optimizer can/will, but... push creator = ? all of the way down.

c) never a version!!!!!! ugh. assuming 9i, I see a good case to use WITH subquery factoring

with B as (select count(tonecode), ..... )
select ....



tell me -- on average, what would the following return:

select count(*), count(distinct tonegroupid)
from t_toneboxinfo where creator = ?;

select count(*), count(distinct tonegroupid)
from t_toneboxinfotemp where creator = ?;


and do you need the union?



A reader, August 09, 2005 - 9:01 am UTC

Hi Tom

Thank you in advance for your reply.
Your advice is very helpful for me.

The database is oracle9.2.0.5,but it's a pity that we are not allowed to analyze the tables and indexes,
so RBO is used in default.

select count(*), count(distinct tonegroupid)
from t_toneboxinfo where creator = ?;

select count(*), count(distinct tonegroupid)
from t_toneboxinfotemp where creator = ?;

The first returns 50 to 60 rows on average,and the second returns 10 to 20 rows.
The only t_looptone is very large,maybe 5 million to 10 million,but others are very small.

I tune the sql as follows,it's faster then before.
Thank you again.
---------------------------------------------------------------------------

select name,tonegroupid,creator,price,status,settime,downloadtimes,type,
refusereason,description,loopcount,flag, feetype, toneboxcode
from (
select name,t_toneboxinfo.tonegroupid,creator,price,status,settime,downloadtimes,
type,refusereason,description,loopcount,0 as flag, feetype, toneboxcode
from t_toneboxinfo,(select/*+use_hash(t_toneboxinfo t_looptone)*/ count(tonecode) loopcount,tonegroupid
from t_looptone group by tonegroupid) b
where b.tonegroupid=t_toneboxinfo.tonegroupid
and not exists(select 'X' from t_toneboxinfotemp e where t_toneboxinfo.tonegroupid=e.tonegroupid)
and creator=613817
union all
select /*+use_nl(t_looptonetemp t_toneboxinfotemp) leading(t_looptonetemp)*/name,t_toneboxinfotemp.tonegroupid,creator,
price,status,settime,downloadtimes,type,refusereason,description,loopcount,1 as flag, feetype, toneboxcode
from t_toneboxinfotemp,(select count(tonecode) loopcount,tonegroupid from t_looptonetemp group by tonegroupid) b
where b.tonegroupid=t_toneboxinfotemp.tonegroupid
and creator=613817
) a
order by a.tonegroupid

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=25 Card=82 Bytes=19598)
1 0 SORT (ORDER BY) (Cost=25 Card=82 Bytes=19598)
2 1 VIEW (Cost=101 Card=82 Bytes=19598)
3 2 UNION-ALL
4 3 SORT (GROUP BY) (Cost=13 Card=81 Bytes=19683)
5 4 FILTER
6 5 HASH JOIN (Cost=8 Card=81 Bytes=19683)
7 6 TABLE ACCESS (FULL) OF 'T_TONEBOXINFO' (Cost=2 Card=1 Bytes=230)
8 6 INDEX (FAST FULL SCAN) OF 'PK_LOOPTONE' (UNIQUE) (Cost=5 Card=162054 Bytes=2106702)
9 5 INDEX (UNIQUE SCAN) OF 'PK_TONEBOXINFOTEMP' (UNIQUE) (Cost=1 Card=1 Bytes=13)
10 3 SORT (GROUP BY) (Cost=7 Card=1 Bytes=243)
11 10 NESTED LOOPS (Cost=3 Card=1 Bytes=243)
12 11 TABLE ACCESS (FULL) OF 'T_TONEBOXINFOTEMP' (Cost=2 Card=1 Bytes=230)
13 11 INDEX (RANGE SCAN) OF 'PK_LOOPTONETEMP' (UNIQUE) (Cost=1 Card=1 Bytes=13)
---------------------------------------------------------------------------

Now,I have two questions:
1.Do you mean that using 'with B as (select count(tonecode), ..... ) select ....' is faster then above?
How to convert the sql into 'with B .....'? I am not familiar with the tunning rule of 'with B .....',
Could you give an example for me?
2.I have another sql:
SELECT tonegroupid,name,tonenumber,status,price ,spname,feetype, toneboxcode
FROM (SELECT a.tonegroupid,a.name,count(a.tonegroupid) as tonenumber,a.status,a.price ,e.spname,a.feetype,a.toneboxcode
FROM t_toneboxinfo a, t_looptone b ,t_webtonelib c,t_spinfo e
WHERE a.tonegroupid = b.tonegroupid AND a.status = 3 AND a.creator=e.spcode AND b.tonecode = c.tonecode
GROUP BY a.tonegroupid,a.name, a.status,a.price,e.spname,a.feetype,a.toneboxcode
UNION
SELECT a.tonegroupid,a.name,count(b.tonegroupid) as tonenumber,a.status,a.price,e.spname,a.feetype,a.toneboxcode
FROM t_toneboxinfotemp a, t_looptonetemp b ,t_webtonelib c, t_spinfo e
WHERE a.tonegroupid = b.tonegroupid AND (a. status = 4 OR a. status = 5) AND b.tonecode = c.tonecode AND a.creator = e.spcode
GROUP BY a.tonegroupid,a.name, a.status,a.price,e.spname,a.feetype,a.toneboxcode ) d
ORDER BY d.tonegroupid

This sql give me more headache,the UNION can not throw away.
How to tune this sql? Could you give me some advice again?

Thank you very very very much.

Tom Kyte
August 09, 2005 - 10:29 am UTC

select name,tonegroupid,creator,
price,status,settime,downloadtimes,
type,refusereason,description,
(select count(tonecode)
from t_looptone
where tonegroupid = a.tonegroupid ) loopcount,
flag, feetype, toneboxcode
from ( select name,tonegroupid,creator,price,
status,settime,downloadtimes,type,
refusereason, description, 0 as flag,
feetype, toneboxcode
from t_toneboxinfo
where not exists(select null
from t_toneboxinfotemp e
where t_toneboxinfo.tonegroupid=e.tonegroupid)
and creator = ?
union all
select name,tonegroupid,creator,price,
status,settime,downloadtimes,type,
refusereason,description,1 as flag,
feetype,toneboxcode
from t_toneboxinfotemp
where creator = ?
) a
ORDER BY a.tonegroupid


Assuming index on t_looptone(tonegroupid,tonecode)



The Right Place for this....

Mark, August 18, 2005 - 10:58 am UTC

I hope...

Tom,
I read the following in the Oracle 8.1.7 Documentation:

How the CBO Chooses an Access Path

Example 4:
The following query uses a bind variable rather than a literal value for the boundary value in the WHERE clause condition:

SELECT *
FROM emp
WHERE empno < :e1;


The optimizer does not know the value of the bind variable e1. Indeed, the value of e1 may be different for each execution of the query. For this reason, the optimizer cannot use the means described in the previous example to determine selectivity of this query. In this case, the optimizer heuristically guesses a small value for the selectivity. This is an internal default value. The optimizer makes this assumption whenever a bind variable is used as a boundary value in a condition with one of the operators <, >, <=, or >=.

The optimizer's treatment of bind variables can cause it to choose different execution plans for SQL statements that differ only in the use of bind variables rather than constants. In one case in which this difference may be especially apparent, the optimizer may choose different execution plans for an embedded SQL statement with a bind variable in an Oracle precompiler program and the same SQL statement with a constant in SQL*Plus.

My Question is this:
Since the optimizer 'guesses a small value for the selectivity' as stated above, can a case be made from a SQL tuning perspective to not use bind variables when your WHERE clause has boundary operators such as >,<,>=,<=, and you are aware that the selectivity may not in fact be small? For example, if I had a table of 1 million rows with a DATE field and my predicate was

WHERE MYDATEFIELD < :B1

and :B1 = '01-MAY-2005'

and this returned a rowcount of 5, this would be highly selective, and given the small value of selectivity the optimizer defaults to with regard to BIND variables, it would seem I would get a reasonable access path.

However, if I changed the value to

:B1 = '01-AUG-2005'

and it returned over half the rowcount of the table, would not the plan be incorrect for this statement, perhaps resulting in a high amount of reads on the index to get the rowids, instead of perhaps (correctly) doing a FTS?

thanks and great answers as usual!


Tom Kyte
August 18, 2005 - 4:26 pm UTC

this is all different in 9i and above with "bind variable peeking" (search for that on this site if you are interested)

If you parse queries many times per second, you better use bind variables -- since you cannot hard parse too many queries per second (I don't care HOW many cpu's you have or HOW fast they are, lots of hard parses will literally CRIPLE you)

Bind variable peeking = random plan?

A reader, August 18, 2005 - 5:37 pm UTC

Doesn't bind variable peeking essentially give us a random plan, since we get a plan that is optimized for the values that is supplied with the execution that happen to be the first one (and therefore the one causing the hard parse)? To me such randomness doesn't seem to be desirable. But of cause if all the values for some reason are in the same interval (or otherwise have properties that would cause the same plan to be generated) peeking might be useful.

What would be really nice, would be if oracle together with the plans saved the assumtions that it have made creating the plan, and checked those assumtions when checking if a sutible plan exists in the cache. That is, every time it would do peeking and compare the value against a histogram or some internal threshold, it would transform that check into a condition on the plan. You might even let the users use a plan that seemed slightly out of range for a short while, but mark the plan as "needing a plan that better suits these values" so the plans can be computed when the processor is free. Seems like a fun little project.

Tom Kyte
August 18, 2005 - 7:05 pm UTC

not a random plan, very predicable based upon the bind variable value that was used when the query was hard parsed.

The concept is "at that point in the code, the bind variable used the first time will be representative of the bind variables to be used here all of the time, it'll either always use the index or not AT THIS POINT IN THE CODE (eg: think OLTP application, it would NOT flip from index to full scan there -- that would not be OLTP anymore)

In a warehouse, where this matters -- with histograms and all -- you may well not use a bind variable (and in that system you are not parsing hundreds/thousands of times a second, you are running queries that take many seconds/minutes/hours/days to run)



A reader, August 19, 2005 - 6:31 pm UTC

That is the strangest (re-)definition of oltp I've seen.

Even though you seldom want to go as far as a full table scan, many access paths are often possible. For example, if I let the user enter a date interval and a category, different plans will probably be appropriate depending on if the category contain many or few items and if the date interval is large or small. For the interval I might concatinate something like "round(log(10,end-start))" in a commment in the query to have different plans for different interval sizes, but the optimizer have much better knowledge or when new plans would be appropriate than I do.

Tom Kyte
August 20, 2005 - 4:51 pm UTC

<quote>
That is the strangest (re-)definition of oltp I've seen.
</quote>

who is that pointed at? I didn't see any redefinitions taking place?



In a transactional system, hard parsing is the killer. To me, bind variable peeking is the lesser of two evils:

a) choose single plan based on "generic one size fits all guesses"
b) choose single plan based on the first representative inputs we get.

A reader, August 21, 2005 - 5:10 pm UTC

> who is that pointed at?
"think OLTP application, it would NOT flip from index to full scan there -- that would not be OLTP anymore" (which, in context, is also an exaggeration since, other plans than full scan might be possible)

> In a transactional system, hard parsing is the killer.
I certanly don't disagree that that can be the case.

> To me, bind variable peeking is the lesser of two evils:
> a) choose single plan based on "generic one size fits all guesses"
> b) choose single plan based on the first representative inputs we get.
Yes, that was kind of what I said (since Oracle just define the first inputs to be representative). And then I said that it would be nice if Oracle ventured further than "the lesser of two evils" and implemented "a good solution". And then you got all defensive.
I guess we just disgree.

Tom Kyte
August 21, 2005 - 7:21 pm UTC

the point with the example was "the inputs would be representative at that point in the application, the plan would be decided on an in most cases -- not 'random' appearing".

"random appearing" would be a bit of exaggeration as well, would not you agree?

what is your "good solution"? from what I read, it sounds like "cursor_sharing=similar" doesn't it.

SQL Tuning

vj, August 22, 2005 - 12:35 am UTC

Good Morning Tom,

RATESHOPINFO is the master table from which we are trying to delete records. The primary key of this table is rateshopid. This table has 21million records. This rateshopid is referenced by AVISUSERINO and CUSTOMERINFO table, and has 10million and 1million records respectively. The AVISUSERINO and CUSTOMERINFO have columns Rateshopid1, Rateshopid2, Rateshopid3 which are referencing RATESHOPINFO table's RATESHOPID column.

The below is the procedure that we are using to delete the records:

The below procedure takes ages to execute..


CREATE OR REPLACE Procedure DELETE_RATEINFO IS
CURSOR RATESHOP_CURSOR IS SELECT RATESHOPID FROM
RATESHOPINFO;
BEGIN
FOR RATESHOP_VAL IN RATESHOP_CURSOR
LOOP
BEGIN
IF RATESHOP_VAL.RATESHOPID IS NOT
NULL
THEN
DELETE FROM RATESHOPINFO
WHERE RATESHOPID = RATESHOP_VAL.RATESHOPID;
END IF;
EXCEPTION
WHEN OTHERS THEN
NULL;
END;
END LOOP;
COMMIT;
END;

How do i tune this ?

Rgds

Tom Kyte
August 22, 2005 - 7:31 am UTC

well, how can rateshopid be NULL? it is a primary key.


"when others then null" -- hmm, just SILENTLY IGNORE ALL ERRORS. that is very suspicious. More than suspicious, I label that a bug that would never be able to leave development (if I had anything to say about it)


Insufficient data here, is it that there is an on delete cascade here? or do you just want to delete rows that are not in the others?

if the goal is to wipe out all of the data in all of the tables, just disable the fkeys, truncate, and renable them.

Alberto Dell'Era, August 22, 2005 - 6:17 am UTC

> what is your "good solution"?

I think that "a reader" was thinking about something like this:

select .. where GENDER = :gender;

column GENDER (with histogram):
value 'M' : poor selectivity -> full table scan
value 'F' : excellent selectivity -> index scan

Say the statement was optimized for :gender='M'; when :gender = 'F' pops in, the CBO may say "oh, this value hits another bin of the histogram, let's check the selectivity. Oh, it's very different, let's generate another child cursor, another plan, and use this for values hitting this bin from now on".

Sounds good *in theory*, obviously that would require making the check at every EXECUTE, which may be expensive.

Tom Kyte
August 22, 2005 - 7:40 am UTC

that is called cursor_sharing=similar and implies you *need* a soft parse every time, every single time, to find the right plan to be associated with which means "there goes scalability"

You see, it already can happen, it is the greater of three evils to me.

SQL Tuning..,

vj, August 23, 2005 - 3:27 am UTC

Thanks very much for your followup Tom,

This table is a master table and we want to delete only those records which are not referenced by other tables.

Tom's Followup:
well, how can rateshopid be NULL? it is a primary key.

"when others then null" -- hmm, just SILENTLY IGNORE ALL ERRORS. that is very
suspicious. More than suspicious, I label that a bug that would never be able
to leave development (if I had anything to say about it)


Insufficient data here, is it that there is an on delete cascade here? or do you
just want to delete rows that are not in the others?

if the goal is to wipe out all of the data in all of the tables, just disable
the fkeys, truncate, and renable them.



Tom Kyte
August 24, 2005 - 4:03 am UTC

delete from master
where primarykey not in ( select fkey from detail where fkey is not null )
and primarykey not in ( select fkey from other_detail where fkey is not null );

make sure to use the cbo.

Anders, August 23, 2005 - 8:37 am UTC

> "random appearing" would be a bit of exaggeration as well,
> would not you agree?
No, I don't think so, since which values come first depend on the user that happen to hit "submit" first. And that is sufficiently random for me. What would be an exaggeration would be for me to say that the plans for different values always differs or that they always differs by a lot.

> what is your "good solution"? from what I read, it sounds
> like "cursor_sharing=similar" doesn't it.
At one point I thought of this as "cursor_sharing=similar for binds" but I think it just confuses. So, no, I wouldn't say so. Firstly, it is my understanding that "similar" is a feture of the "auto-binding" facility, ie. "similar" automaticly turns literals into binds if the values of those literals doesn't seem to inpact the choice of plan. But I am not talking about auto-binding at all (I like to use binds since it is actually easier -- when you have the right API). Secondly, "similar" seems just to leave the (in this context) interesting literals (ei. those that can impact the plan) alone so we get a lot of hard parses and a lot of plans in the cache even though there might be very few distict plans.

> that is called cursor_sharing=similar and implies you
> *need* a soft parse every time, every single time, to find
> the right plan to be associated with which means "there
> goes scalability"
I don't think I nessesarily need fewer or more soft parses, because the conditions is attached to the sql (could be either the plan in the SGA or the cursor in the UGA), which conditions is relevant is calculated beforehand (when the sql was first hard parsed) and the conditions only concern the paramenters and therefore don't need to be parsed out of the sql string.
Of cause if the plan that matches the conditions isn't found, we would have to do some more work. But that was why I proposed to defer this work if a plan that only matched the statment but not the values was found, since that would just give us a plan that is as bad as those we are happy with today. The more specific plans might then be calculated in the periods where cpu/disk/locks isn't maxed out, instead of feeding the clockcycles to the idle-loop.

Tom Kyte
August 24, 2005 - 4:23 am UTC

random is random -- was my point, it is not random, it is very predicable based on what was first there (exaggeration calling it random, it is very predicable if you know the inputs).

My example was less exaggerated than calling this random. They were both colorful uses of examples.

In order to get a different plan (potentionally) for each execution of a query, you must PARSE IT (else the plan is fixed). Therefore, to achieve what you request would require a parse and hence cursor_sharing=similar is exactly what you are asking for -- a parse each time the query is executed.

You do not have the literals left in, you get more than one plan but not "lots" of plans with similar.

your last paragraph just described the basics of a soft parse. Find the sql in the shared pool and look at the inputs to figure out which one to actually use -- that is cursor_sharing=similar in effect.

SQL Tuning

vj, August 24, 2005 - 1:31 am UTC

Yes Tom, the objective is to delete the rows that are not referenced in the other two tables.


Tom's Followup:
well, how can rateshopid be NULL? it is a primary key.


"when others then null" -- hmm, just SILENTLY IGNORE ALL ERRORS. that is very
suspicious. More than suspicious, I label that a bug that would never be able
to leave development (if I had anything to say about it)


Insufficient data here, is it that there is an on delete cascade here? or do you
just want to delete rows that are not in the others?

if the goal is to wipe out all of the data in all of the tables, just disable
the fkeys, truncate, and renable them



Tom Kyte
August 24, 2005 - 9:08 am UTC

see above where I've already responded (and remember, I too sleep from time to time)

Alberto Dell'Era, August 24, 2005 - 10:00 am UTC

> that is called cursor_sharing=similar and implies you *need* a soft parse
> every time, every single time, to find the right plan to be associated
> with which means "there goes scalability"
> You see, it already can happen (snip)

It doesn't seem that it can happen (10.1.0.3) :

dellera@ORACLE10> -- table with a single row with x=1, all others x=99
dellera@ORACLE10> create table t (x, y)
2 as select decode (rownum,1,1,99), rpad(' ',1000)
3 from dual
4 connect by level <= 100;

Table created.

dellera@ORACLE10> create index t_x_idx on t(x);

Index created.

dellera@ORACLE10> -- collect histograms on t.x
dellera@ORACLE10> exec dbms_stats.gather_table_stats (user, 't', cascade=>true, method_opt=>'for columns x size skewonly');

PL/SQL procedure successfully completed.

dellera@ORACLE10> select endpoint_value, endpoint_number from user_histograms where table_name = 'T';

ENDPOINT_VALUE ENDPOINT_NUMBER
-------------- ---------------
1 1
99 100

2 rows selected.

dellera@ORACLE10>
dellera@ORACLE10> alter session set sql_trace=true;

Session altered.

dellera@ORACLE10>
dellera@ORACLE10> -- show that changing x from 1 to 99 changes the plan
dellera@ORACLE10> alter session set cursor_sharing=exact;

Session altered.

dellera@ORACLE10> select y from t test where x = 1;

(snip)

1 row selected.

PARSING IN CURSOR #8 len=32 dep=0 uid=58 oct=3 lid=58 tim=15252401721 hv=4231659608 ad='69eb3400'
select y from t test where x = 1
END OF STMT
STAT #8 id=1 cnt=1 pid=0 pos=1 obj=72042 op='TABLE ACCESS BY INDEX ROWID T (cr=3 pr=0 pw=0 time=78 us)'
STAT #8 id=2 cnt=1 pid=1 pos=1 obj=72043 op='INDEX RANGE SCAN T_X_IDX (cr=2 pr=0 pw=0 time=48 us)'

dellera@ORACLE10> select y from t test where x = 99;

(snip)

99 rows selected.

PARSING IN CURSOR #16 len=33 dep=0 uid=58 oct=3 lid=58 tim=15252415308 hv=846757444 ad='68e823f4'
select y from t test where x = 99
END OF STMT
STAT #16 id=1 cnt=99 pid=0 pos=1 obj=72042 op='TABLE ACCESS FULL T (cr=24 pr=0 pw=0 time=582 us)'

dellera@ORACLE10> -- but the plan doesn't change with cursor_sharing=similar
dellera@ORACLE10> alter session set cursor_sharing=similar;

Session altered.

dellera@ORACLE10> variable x number
dellera@ORACLE10> exec :x := 99;

PL/SQL procedure successfully completed.

dellera@ORACLE10> select y from t test where x = :x;

Y
------------------------------------------------------

(snip)

99 rows selected.

PARSING IN CURSOR #29 len=33 dep=0 uid=58 oct=3 lid=58 tim=15252567172 hv=1913858474 ad='698725b4'
select y from t test where x = :x
END OF STMT
STAT #29 id=1 cnt=99 pid=0 pos=1 obj=72042 op='TABLE ACCESS FULL T (cr=24 pr=0 pw=0 time=578 us)'

dellera@ORACLE10> select * from dual;

DUM
---
X

1 row selected.

dellera@ORACLE10> exec :x := 1;

PL/SQL procedure successfully completed.

dellera@ORACLE10> select y from t test where x = :x;

Y
------------------------------------------------------

(snip)

1 row selected.

PARSING IN CURSOR #17 len=33 dep=0 uid=58 oct=3 lid=58 tim=15252762501 hv=1913858474 ad='698725b4'
select y from t test where x = :x
END OF STMT
STAT #17 id=1 cnt=1 pid=0 pos=1 obj=72042 op='TABLE ACCESS FULL T (cr=19 pr=0 pw=0 time=165 us)'

The plan is the same for different values of :x - only the value of :x at parse time counts, if you parse with :x = 1 first, it is always:
STAT #29 id=1 cnt=1 pid=0 pos=1 obj=72044 op='TABLE ACCESS BY INDEX ROWID T (cr=3 pr=0 pw=0 time=94 us)'
STAT #29 id=2 cnt=1 pid=1 pos=1 obj=72045 op='INDEX RANGE SCAN T_X_IDX (cr=2 pr=0 pw=0 time=60 us)'


I've also made literals-replacing kick in by using:
select y from t test where x = :x and 1=1;
but same results.

Anything wrong
in my test case ?

==================================================

Here's the drag-and-drop-friendly script:

-- table with a single row with x=1, all others x=99
create table t (x, y)
as select decode (rownum,1,1,99), rpad(' ',1000)
from dual
connect by level <= 100;
create index t_x_idx on t(x);

-- collect histograms on t.x
exec dbms_stats.gather_table_stats (user, 't', cascade=>true, method_opt=>'for columns x size skewonly');
select endpoint_value, endpoint_number from user_histograms where table_name = 'T';

alter session set sql_trace=true;

-- show that changing x from 1 to 99 changes the plan
alter session set cursor_sharing=exact;
select y from t test where x = 1;
select y from t test where x = 99;

-- but the plan doesn't change with cursor_sharing=similar
alter session set cursor_sharing=similar;
variable x number
exec :x := 99;
select y from t test where x = :x;
select * from dual;
exec :x := 1;
select y from t test where x = :x;
select * from dual;
exit;

Tom Kyte
August 24, 2005 - 2:25 pm UTC

you weren't using literal sql -- with cursor_sharing=similar, I would be expecting you to be using literal sql and letting it take it from there.

the concept is "you would not be binding", you would be using literals in the sql statement and asking us to "parse it, with similar"

Alberto Dell'Era, August 24, 2005 - 3:16 pm UTC

> you would be using literals in the sql statement

Ok, my understanding was that you were saying that "similar" checks (peeks at) the values of the user-provided binds and not only the :"SYS_B_<number>" ones when checking for "plan similarity", but that isn't happening.

Well, one more thing learnt :) - thanks!



Similar == "no binds" for columns with histograms ?

Alberto Dell'Era, August 25, 2005 - 2:22 pm UTC

Re-using the same setup above (10.1.0.3) :

-- table with a single row with x=1, all others x=99
create table t (x, y)
as select decode (rownum,1,1,99), rpad(' ',1000)
from dual
connect by level <= 100;
create index t_x_idx on t(x);

-- collect histograms on t.x
exec dbms_stats.gather_table_stats (user, 't', cascade=>true, method_opt=>'for columns x size skewonly');
select endpoint_value, endpoint_number from user_histograms where table_name = 'T';

ENDPOINT_VALUE ENDPOINT_NUMBER
-------------- ---------------
1 1
99 100

2 rows selected.

I've submitted 10 literal-aside identical statements:

alter system flush shared_pool;

alter session set cursor_sharing=similar;
-- 10 statements:
select count(y) from t where x = 1;
select count(y) from t where x = 10;
select count(y) from t where x = 20;
select count(y) from t where x = 30;
select count(y) from t where x = 40;
select count(y) from t where x = 50;
select count(y) from t where x = 60;
select count(y) from t where x = 70;
select count(y) from t where x = 80;
select count(y) from t where x = 99;

col sql_text form a50
col value_string form a5
select s.sql_text, b.value_string, s.plan_hash_value
from v$sql_bind_capture b, v$sql s
where s.hash_value = b.hash_value
and s.address = b.address
and s.child_number = b.child_number
and s.sql_text like 'select count(y) from t where x =%';

SQL_TEXT VALUE PLAN_HASH_VALUE
-------------------------------------------------- ----- ---------------
select count(y) from t where x = :"SYS_B_0" 1 2000650825
select count(y) from t where x = :"SYS_B_0" 10 2000650825
select count(y) from t where x = :"SYS_B_0" 20 2000650825
select count(y) from t where x = :"SYS_B_0" 30 2000650825
select count(y) from t where x = :"SYS_B_0" 40 2000650825
select count(y) from t where x = :"SYS_B_0" 50 2000650825
select count(y) from t where x = :"SYS_B_0" 60 2000650825
select count(y) from t where x = :"SYS_B_0" 70 2000650825
select count(y) from t where x = :"SYS_B_0" 80 2000650825
select count(y) from t where x = :"SYS_B_0" 99 2275019856

10 children, two plans (check PLAN_HASH_VALUE).

In general, is the CBO reasoning "since column x has an histogram associated, I'm going to generate a plan for every value of the bind" (hence, it's basically ignoring the bind and pretending there's the original literal still in place) ?

So, we get the same load on the library cache (even soft parses will latch the same) using similar or exact (for columns with histograms of course).

Thanks!

Tom Kyte
August 25, 2005 - 6:35 pm UTC

yup, the concept is if the bind *could* generate a different plan (and in general, you have lots of binds in there, not just one), you want to set up a plan for the bind and match to it based on the bind.



Using rowids for easy access

Graham Oakes, September 05, 2005 - 6:44 am UTC

Hi Tom,

I've been discussing the use of rowids with a java guy at work and it got me thinking. After inserting a row in plsql is it possible to return the rowid for the newly inserted row. I guess I'm looking for something like SQL%ROWID instead of SQL%ROWCOUNT, for example.

Thanks
Graham

Tom Kyte
September 05, 2005 - 10:45 am UTC

ops$tkyte@ORA9IR2> set serveroutput on
ops$tkyte@ORA9IR2> l
  1  declare
  2  l_rowid rowid;
  3  begin
  4     insert into t values ( 1 ) returning rowid into l_rowid;
  5     dbms_output.put_line( l_rowid );
  6* end;
ops$tkyte@ORA9IR2> /
AAAK23AAGAAAATPAAB
 
PL/SQL procedure successfully completed.
 

Rowids

Graham Oakes, September 07, 2005 - 2:52 am UTC

Tom,

you rock!

Cheers
Graham

Please help

A reader, September 07, 2005 - 11:15 am UTC

Tom,

Anything thought on how to improve this query.

SELECT AVG(GREATEST(in_date,out_date) - LEAST(in_date, out_date))
INTO nTotal
FROM social_in c, visit_out v
WHERE TRUNC(in_date, 'DD') = TRUNC(date_IN, 'DD')
AND c.id = v.id
AND out_date is not null
AND c.number = 1
AND v.date_1 is null
AND substr(c.action,1,1) = substr(action_IN,1,1);


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=7464.63870823304 C
ard=1 Bytes=26)

1 0 SORT (AGGREGATE)
2 1 HASH JOIN (Cost=7464.63870823304 Card=3630 Bytes=94380)
3 2 TABLE ACCESS (FULL) OF 'VISIT_OUT' (TABLE) (Cost=6631
.35068877839 Card=2451 Bytes=51471)

4 2 INDEX (FAST FULL SCAN) OF 'GC_VISIT_IDX' (INDEX) (Cost
=820.316132086728 Card=1426684 Bytes=7133420)

Tom Kyte
September 07, 2005 - 1:47 pm UTC

sorry, i don't even know what columns come from which tables - sort of makes it difficult.





sorry

A reader, September 07, 2005 - 2:43 pm UTC

SELECT AVG(GREATEST(v.in_date,v.out_date) - LEAST(v.in_date, v.out_date))
INTO nTotal
FROM social_in c, visit_out v
WHERE TRUNC(v.in_date, 'DD') = TRUNC(date_IN, 'DD')
AND c.id = v.id
AND v.out_date is not null
AND c.number = 1
AND v.date_1 is null
AND substr(c.action,1,1) = substr(action_IN,1,1);

Tom Kyte
September 07, 2005 - 3:27 pm UTC

so - date_in and action_in, they are bind variables?




follow-up

A reader, September 07, 2005 - 3:41 pm UTC

Yes! Tom.

Tom Kyte
September 07, 2005 - 7:32 pm UTC


SELECT AVG(GREATEST(v.in_date,v.out_date) - LEAST(v.in_date, v.out_date))
INTO nTotal
FROM social_in c, visit_out v
WHERE v.in_date between TRUNC(date_IN, 'DD')
and TRUNC(date_IN, 'DD')+1-1/24/60/60 -- assuming DATE type
AND c.id = v.id
AND v.out_date is not null
AND c.number = 1
AND v.date_1 is null
AND c.action like substr(action_IN,1,1)||'%';

by removing the functions on the columns, indexes on the columns become possible to be used.

a nice index on v(in_date,out_date,date_1)
a nice index on c(id,number,action)
......

maybe.



thanks!!!!!

A reader, September 08, 2005 - 9:30 am UTC

You rock!!!..Mr. Tom!

Query is fast in 10g and slow in 9i

Sarma, September 09, 2005 - 2:04 pm UTC

Hi Tom,

I'm trying to tune a query which is slow in 9i taking 1.5 min and the same query returns in 94 msecs in 10g. When I looked at explain plan of 9i it is doing full table scans on 3 tables and in 10g it is doing index scans.

schema on 9i is imported from 10g and no of records, constraints and indexes everything same in both the databases.

Here is the query

SELECT org.name
,org.contract_nbr
,org.duns_nbr
,org.tax_id
,nbto.task_order_nbr
,elease_util.Initcap2(NVL(trim(both ' ' from cp.full_name), cp.first_name||' '||cp.last_name))
,cv.phone_nbr
,cv.email
,elease_util.Initcap2(NVL(trim(both ' ' from cp2.full_name), cp2.first_name||' '||cp2.last_name))
,cv2.phone_nbr
FROM
nbc_task_orders nbto
,organizations org
,contact_person_roles cpr
,contact_persons cp -- for leasing agent or broker
,business_roles brl
,contact_vehicles cv -- for leasing agent or broker
,contact_persons cp2 -- for national project mgr
,contact_vehicles cv2 -- for national project mgr
WHERE
nbto.project_nbr = '4MI0119'--P_PROJECT_NBR
AND UPPER(nbto.task_order_status) = 'BROKER ACTIVE'
AND org.org_id = nbto.org_id
--AND cpr.nbto_id (+)= nbto.nbto_id
AND brl.brl_id (+)= cpr.brl_id
AND cp.cp_id (+)= cpr.cp_id
AND cv.cp_id (+)= cp.cp_id
AND 'BROKER' LIKE NVL(upper(brl.name), '%')
AND cp2.cp_id (+)= org.mgr_cp_id
AND cv2.cp_id (+)= cp2.cp_id
AND cv2.primary_contact_ind (+)= 'Y'
AND rownum < 2
Here is the explain plan for 9i


SELECT STATEMENT Optimizer Mode=CHOOSE 1 1107
COUNT STOPKEY
FILTER
HASH JOIN OUTER
HASH JOIN OUTER 3 K 615 K 1100
HASH JOIN OUTER 3 K 534 K 749
MERGE JOIN CARTESIAN 3 K 442 K 65
NESTED LOOPS 1 117 2
TABLE ACCESS BY INDEX ROWID ELEASER1UAT.NBC_TASK_ORDERS 1 30 1
INDEX RANGE SCAN ELEASER1UAT.NBTO_PROJ_ORG_STATUS_I 1
TABLE ACCESS BY INDEX ROWID ELEASER1UAT.ORGANIZATIONS 1 87 1
INDEX UNIQUE SCAN ELEASER1UAT.ORG_PK 1
BUFFER SORT 314 K 2 M 64
INDEX FAST FULL SCAN ELEASER1UAT.CPR_UK 314 K 2 M 63
TABLE ACCESS FULL ELEASER1UAT.CONTACT_PERSONS 315 K 7 M 604
TABLE ACCESS FULL ELEASER1UAT.CONTACT_VEHICLES 219 K 4 M 288
TABLE ACCESS FULL ELEASER1UAT.BUSINESS_ROLES 33 297 2

Explain plan for 10g


Operation Object Name Rows Bytes Cost

SELECT STATEMENT Optimizer Mode=CHOOSE 1 12
COUNT STOPKEY
NESTED LOOPS OUTER 1 237 12
NESTED LOOPS OUTER 1 214 10
FILTER
NESTED LOOPS OUTER 1 188 9
NESTED LOOPS 1 179 8
NESTED LOOPS OUTER 1 170 6
NESTED LOOPS OUTER 1 149 4
NESTED LOOPS 1 123 3
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.NBC_TASK_ORDERS 1 31 2
INDEX RANGE SCAN ELEASER1DEV.NBTO_PROJ_ORG_STATUS_I 1 1
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.ORGANIZATIONS 1 92 1
INDEX UNIQUE SCAN ELEASER1DEV.ORG_PK 1 0
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.CONTACT_PERSONS 1 26 1
INDEX UNIQUE SCAN ELEASER1DEV.CP_PK 1 0
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.CONTACT_VEHICLES 1 21 2
INDEX RANGE SCAN ELEASER1DEV.CV_CP_FK_I 1 1
INDEX FAST FULL SCAN ELEASER1DEV.CPR_UK 50 450 2
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.BUSINESS_ROLES 1 9 1
INDEX UNIQUE SCAN ELEASER1DEV.BRL_PK 1 0
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.CONTACT_PERSONS 1 26 1
INDEX UNIQUE SCAN ELEASER1DEV.CP_PK 1 0
TABLE ACCESS BY INDEX ROWID ELEASER1DEV.CONTACT_VEHICLES 1 23 2
INDEX RANGE SCAN ELEASER1DEV.CV_CP_FK_I 1 1

I am not able to understand why is it doing unique index scan in 10g for a table business_roles which is basically a outer join.

Here are the details of tables performing full table scans ON 9I DATABASE.

TABLE_NAME NUM_ROWS BLOCKS AVG_ROW_LENGTH
CONTACT_VEHICLES 218140 1888 124
INDEX_NAME NUM_ROWS BLEVEL LEAF_BLOCKS DISTINCT_KEYS
CV_CP_FK_I 218136 1 370 218135
CV_PK 218140 1 240 218140

TABLE_NAME NUM_ROWS BLOCKS AVG_ROW_LENGTH
CONTACT_PERSONS 315240 3967 175
INDEX_NAME NUM_ROWS BLEVEL LEAF_BLOCKS DISTINCT_KEYS
CV_PK 313749 1 335 313749

TABLE_NAME NUM_ROWS BLOCKS AVG_ROW_LENGTH
BUSINESS_ROLES 33 5 69
INDEX_NAME NUM_ROWS BLEVEL LEAF_BLOCKS DISTINCT_KEYS
BRL_PK 33 0 1 33

All tables are analyzed on 9i database including indexes and indexed columns. Tried playing with index columns with size option but of no use.

These details more or less same for 10g database but there it does unique index scan on contact_persons and index scan on contact_vehicles and unique index scan on business_roles tables.

Also I ran 10053 trace on both the systems but trace files so huge not able to comprehend much from those trace files. If you permit I can upload them.

I am struggling since couple of days to find solution so your input is highly appreciated.

Thanking you,
Sarma


Tom Kyte
September 09, 2005 - 2:17 pm UTC

how do the clustering factors in the relevant indexes look.

also, are the OPTIMIZER parameters the same (10053 trace is very useful for a quick compare of that)

Query is fast in 10g and slow in 9i

Sarma, September 09, 2005 - 5:20 pm UTC

Hi Tom,

Here are the differences in init.ora parameters of both the instances.
9i 10g
partition_view_enabled false true
optimizer_dynamic_sampling 1 2
optimizer_dyn_smp_blks 32 not available
_use_nosegment_indexes false not available
optimizer_choose_permutation 0 not available
subquery_pruning_reduction_factor 50 not available
subquery_pruning_cost_factor 20 not available
sortmerge_inequality_join_off false not available
gsets_always_use_temptables false not available

Coming to the clustering Factor here's the comparision

Table:contact_vehicles cluf 9i cluf 10g
indexes
cv_cp_fk_i 4264 5870
cv_pk 4262 5868

Table:contact_persons cluf 9i cluf 10g
indexes
cp_pk 195377 196844

Table:contact_persons cluf 9i cluf 10g
indexes
brl_pk 1 1

I see the following line under base statistics section of the 9i trace file but this line is not there in 10g trace file.

HEIGHT BALANCED HISTOGRAM: #BKT: 75 #VAL: 76 under contact_persons and contact_vehicles tables.

Any idea why is it not doing full tablescan on business_roles table (eventhough it is outer join) in 10g database.

Thank you very much for quick response.

Regards
Sarma


Query is fast in 10g and slow in 9i

Sarma, September 10, 2005 - 12:45 pm UTC

Hi Tom,

More information to add I have forced hints to use index and performance is better i.e. around 600 msecs. When I tested using rule hint surprsingly it is just taking 200 msecs and doing all index scans instead of full table scans.

Thanks
Sarma

Tom Kyte
September 10, 2005 - 12:54 pm UTC

how do you gather statistics (and are the histograms the same in 9i as for 10g)

Query is fast in 10g and slow in 9i

Sarma, September 12, 2005 - 12:01 pm UTC

Hi Tom,

Here is the information.

All tables are analyzed on 9i database including indexes and indexed columns with analyze table
command. Tried playing with index columns with size option but of no use.

Here is the information regarding histograms. I did not gather statistics on 10g database
thinking as it does by default.

9i
user_tab_histograms

TABLE_NAME COLUMN_NAME ENDPOINT_NUMBER ENDPOINT_VALUE ENDPOINT_ACTUAL_VALUE

CONTACT_PERSONS CP_ID 0 1142057
CONTACT_PERSONS CP_ID 1 1673859

CONTACT_VEHICLES CP_ID 0 1141959
CONTACT_VEHICLES CP_ID 1 1578245



10g
user_tab_histograms
TABLE_NAME COLUMN_NAME ENDPOINT_NUMBER ENDPOINT_VALUE ENDPOINT_ACTUAL_VALUE

CONTACT_PERSONS CP_ID 0 1
CONTACT_PERSONS CP_ID 1 1674111

CONTACT_VEHICLES CP_ID 0 1141999
CONTACT_VEHICLES CP_ID 1 1578181
I have also update clustering factor of both the instances of tables doing full table scans.

Thanking you,
Regards
Sarma

Tom Kyte
September 12, 2005 - 2:22 pm UTC

should be using dbms_stats.

looks like the data is different in 10g versus 9i - is it?

oops ! I made mistake providing histograms info

Sarma, September 12, 2005 - 3:29 pm UTC

Hi Tom,

Sorry I made a mistake while providing histogram information I think based on that you came to conclusion that data is different but it is not it is same database we have exported and imported.

9i
user_tab_histograms

TABLE_NAME COLUMN_NAME ENDPOINT_NUMBER ENDPOINT_VALUE


CONTACT_PERSONS CP_ID 0 1
CONTACT_PERSONS CP_ID 1 1674111

CONTACT_VEHICLES CP_ID 0 1141959
CONTACT_VEHICLES CP_ID 1 1578245



10g
user_tab_histograms
TABLE_NAME COLUMN_NAME ENDPOINT_NUMBER ENDPOINT_VALUE
CONTACT_PERSONS CP_ID 0 1142057
CONTACT_PERSONS CP_ID 1 1673859

CONTACT_VEHICLES CP_ID 0 1141999
CONTACT_VEHICLES CP_ID 1 CONTACT_VEHICLES CP_ID 1

I will try to analyze with dbms_stats as mentioned by you and see wether it makes any difference.

Thank you once again for all your time.
Regards
Sarma

HASH_JOIN_ENABLED & 10G

Deepak, September 13, 2005 - 7:29 am UTC

Hi Tom,

In 10G hash_joinn_enabled parameter has been deprecated. What is the alternate to this in 10G? How does Oracle take care of the purpose in 10G?


Tom Kyte
September 13, 2005 - 12:17 pm UTC

the purpose has been removed - that functionality (to disable) has been deprecated.

Using rowids for fast lookups

Rakesh, September 14, 2005 - 5:46 am UTC

Hi Tom,

just wanted to follow up on an answer you gave someone about returning rowids for fast lookups:

ops$tkyte@ORA9IR2> set serveroutput on
ops$tkyte@ORA9IR2> l
1 declare
2 l_rowid rowid;
3 begin
4 insert into t values ( 1 ) returning rowid into l_rowid;
5 dbms_output.put_line( l_rowid );
6* end;
ops$tkyte@ORA9IR2> /
AAAK23AAGAAAATPAAB

PL/SQL procedure successfully completed.

I was wondering if their were any disadvantages with using rowids? Doing a little research has uncovered a few things I was hoping you could clarify:

1. In Steve F's PL/SQL book he advocates not bothering with ROWIDs too much becuase some people have taken it to an illogical extreme and started creating columns in a table to hold the ROWID.
2. Should we refer to UROWID instead of ROWID by default?
3. I saw this in the application developers guide form Oracle:

"Although ROWIDs are usually unique, different rows
can have the same ROWID if they are in the same data block, but in different clustered tables."

Does that mean i could get the wrong row back?

Any guidelines for usage would be welcome because i would like to make use of ROWIDs to be the default for simple lookups between java and Oracle (I'm actually the Java guy mentioned in the previous post!).

Thanks!

Tom Kyte
September 14, 2005 - 8:45 am UTC

1) i would agree, do not store a rowid in a table.

2) no, rowid is typically fine, it would take a rebuild of the table as an IOT or to access a table via a gateway to another database (non-oracle)....

3) no, it means rowids are not unique in a database, they are unique in a TABLE only.


Use rowids for short durations of time, eg, when building a stateless web application that does optimistic concurrency control checking. You would

a) select out the old data and the ROWID
b) display that on screen
c) when user hits "update", you would:

update t set column = NEW_COLUMN_VALUE, other_column = NEW_OTHER_COLUMN_VALUE
where rowid = THAT_ROWID
and column = THAT_OLD_COLUMN_VALUE
and other_column = THAT_OTHER_OLD_COLUMN_VALUE ;

if that updates a single row, you win.

If not, someone else has modified that row, you lose.


beware that in the past, rowids were "constant" for a row. The never changed. Starting in 8i with enable row movement, the rowid for a row can change IF and ONLY IF the enable row movmement is set on.

partitioned tables when you update the partition key and the row moves from partition A to partition B, the rowid will change

flashback table in 10g - the rowids will change

shrink table in 10g - the rowids will change.

Tunning request

Brinster, September 14, 2005 - 9:32 am UTC

Hello 

I join you a request and plan ;i want to avoid many full scans on several tables ;I create index on field outer jointure and the result is idem i try to use bitmap index but not possible in standard edition 
Do have you idea ?


SQL> /

        ID  PARENT_ID   POSITION SUBSTR(A.O SUBSTR(A.OPTION SUBSTR(A.OBJECT_NAME SUBST      BYTES  
---------- ---------- ---------- ---------- --------------- -------------------- ----- ---------- 
         0                   961 SELECT STA                                                197604 
         1          0          1 COUNT      STOPKEY                                               
         2          1          1 VIEW                                            SYSTE     197604 
         3          2          1 SORT       ORDER BY STOPKE                                425148 
         4          3          1 SORT       GROUP BY                                       425148 
         5          4          1 HASH JOIN                                                 425148 
         6          5          1 VIEW                       VW_NSO_1             SYS         1632 
         7          6          1 SORT       GROUP BY                                         6171 
         8          7          1 NESTED LOO                                                  6171 
         9          8          1 NESTED LOO                                                  7676 
        10          9          1 TABLE ACCE FULL            T_PASSAGERS_TOU      PAXOW        160 
        11          9          2 INDEX      RANGE SCAN      IK_PAX_UID_LIP_TOU   PAXOW        900  
        12          8          2 TABLE ACCE BY INDEX ROWID  T_LEG_RESA_TOU       PAXOW         45  
        13         12          1 INDEX      UNIQUE SCAN     PK_LRE_TOU           PAXOW             
        14          5          2 HASH JOIN  OUTER                                          771452  
        15         14          1 HASH JOIN  OUTER                                          693132  
        16         15          1 HASH JOIN                                                 622644  
        17         16          1 TABLE ACCE FULL            T_LEG_RESA_TOU       PAXOW     241010  
        18         16          2 HASH JOIN                                                 408013  
        19         18          1 TABLE ACCE FULL            T_RESERVATION_TOU    PAXOW      40675  
        20         18          2 HASH JOIN  OUTER                                          171288  
        21         20          1 HASH JOIN  OUTER                                          132431  
        22         21          1 HASH JOIN  OUTER                                           86437  
        23         22          1 TABLE ACCE FULL            T_DOSSIER_RESA_TOU   PAXOW      34892  
        24         22          2 TABLE ACCE FULL            T_PROFIL_AGENT_TOU   PAXOW     287560  
        25         21          2 TABLE ACCE FULL            T_AGENT_TOU          PAXOW     507732  
        26         20          2 TABLE ACCE FULL            T_CLIENT_TOU         PAXOW       7840  
        27         15          2 INDEX      FULL SCAN       IK_PAX_UID_LIP_TOU   PAXOW     146592  
        28         14          2 TABLE ACCE FULL            T_PASSAGERS_TOU      PAXOW       3280  





SELECT * FROM 
( SELECT RES.RES_CODE AS NUMRESA, RES.DOS_CODE AS  
NUMDOSSIER, RES.RCP_TYPETATRES AS ETAT, RES.RCP_TYPSTTRESA AS ST
ATUT, LRE.ROU_CODE AS ROUTESF, LRE.NSF_CODE AS ROUTENSF, LRE.LRE 
_DATE AS DATEDEPART, LRE.LRE_HEURE AS HEUREDEPART, LRE.LRE_IMMAT 
 AS IMMATRICULATION, LRE.RCP_LBL_VEH AS VEHICULE, LRE.LRE_NB_CAT 
1 AS NBCAT1, LRE.LRE_NB_CAT2 AS NBCAT2, LRE.LRE_NB_CAT3 AS NBCAT 
3, MAX(PAX.PAX_NOM) AS NOM, CLT.CLT_CODE AS CODECLIENT, CLT.CLT_ 
NOM AS NOMCLIENT, AGT.AGT_NOM AS NOMAGENT, AGT.AGT_CODE AS CODEA 
GENT 
FROM T_RESERVATION_TOU RES, T_LEG_RESA_TOU LRE 
LEFT OUTER JOIN T_LISTE_PAX_TOU LISTEPAX ON LRE.LRE_UID = LISTEPAX.LRE_UID 
LEFT OUTER JOIN T_PASSAGERS_TOU PAX ON LISTEPAX.PAX_UID = PAX.PAX_UID 
AND PAX.PAX_ETAT <> 'S' AND PAX.PAX_FLAG_LEAD = 'O', 
T_DOSSIER_RESA_TOU DOS LEFT OUTER JOIN T_PROFIL_AGENT_TOU PAG ON PAG.PAG_UID=DOS.PAG_UID 
AND PAG.PAG_ETAT <> 'S' LEFT OUTER JOIN T_AGENT_TOU AGT ON PAG.AGT_UID=AGT.AGT_UID AND AGT.AGT_ETAT <> 'S' 
LEFT OUTER JOIN T_CLIENT_TOU CLT ON CLT.CLT_UID=DOS.CLT_UID AND CLT.CLT_ETAT <> 'S' 
WHERE RES.RES_CODE = LRE.RES_CODE AND RES.DOS_CODE = DOS.DOS_CODE 
AND RES.RES_ETAT <> 'S' AND DOS.DOS_ETAT <> 'S' AND LRE.LRE_ETAT <> 'S' 
AND RES.RES_CODE || TO_CHAR(LRE.LRE_NUM_ORDRE) IN 
(SELECT LRE.RES_CODE || TO_CHAR(MIN(LRE.LRE_NUM_ORDRE)) FROM T_LEG_RESA_TOU LRE 
LEFT OUTER JOIN T_LISTE_PAX_TOU LISTEPAX ON LRE.LRE_UID = LISTEPAX.LRE_UID 
LEFT OUTER JOIN T_PASSAGERS_TOU PAX ON LISTEPAX.PAX_UID = PAX.PAX_UID 
AND PAX.PAX_ETAT <> 'S' AND PAX.PAX_FLAG_LEAD = 'O' WHERE LRE.LRE_ETAT <> 'S'  
AND LRE.LRE_UID IN (SELECT LISTEPAX.LRE_UID FROM T_LISTE_PAX_TOU LISTEPAX, T_PASSAGERS_TOU PAX 
WHERE LISTEPAX.PAX_UID = PAX.PAX_UID AND PAX.PAX_ETAT <> 'S' AND PAX.PAX_NOM LIKE :v0)
GROUP BY LRE.RES_CODE)  
GROUP BY (RES.RES_CODE, RES.DOS_CODE, RES.RCP_TYPETATRES, RES.RCP_TYPSTTRESA, LRE.ROU_CODE, LRE.NSF_CODE, LRE.LRE_DATE, LRE.LRE_HEURE, LRE.LRE_IMMAT, LRE.RCP_LBL_VEH, LRE.LRE_NB_CAT1, LRE.LRE_NB_CAT2, LRE.LRE_NB_CAT3,  CLT.CLT_CODE, CLT.CLT_NOM , AGT.AGT_NOM, AGT.AGT_CODE) ORDER BY DATEDEPART, HEUREDEPART )  
WHERE ROWNUM < 1002                

Tom Kyte
September 14, 2005 - 10:00 am UTC

strange to mix ansi join with old fashioned joins in the same query - that was confusing to read.


This is going to be a problem to get the first rows "fast". If we format the query to make it readable:


FROM T_RESERVATION_TOU RES,
T_LEG_RESA_TOU LRE
LEFT OUTER JOIN T_LISTE_PAX_TOU LISTEPAX
ON LRE.LRE_UID = LISTEPAX.LRE_UID
LEFT OUTER JOIN T_PASSAGERS_TOU PAX
ON LISTEPAX.PAX_UID = PAX.PAX_UID
AND PAX.PAX_ETAT <> 'S' AND PAX.PAX_FLAG_LEAD = 'O',
T_DOSSIER_RESA_TOU DOS
LEFT OUTER JOIN T_PROFIL_AGENT_TOU PAG
ON PAG.PAG_UID=DOS.PAG_UID AND PAG.PAG_ETAT <> 'S'
LEFT OUTER JOIN T_AGENT_TOU AGT
ON PAG.AGT_UID=AGT.AGT_UID AND AGT.AGT_ETAT <> 'S'
LEFT OUTER JOIN T_CLIENT_TOU CLT
ON CLT.CLT_UID=DOS.CLT_UID AND CLT.CLT_ETAT <> 'S'
WHERE RES.RES_CODE = LRE.RES_CODE
AND RES.DOS_CODE = DOS.DOS_CODE
AND RES.RES_ETAT <> 'S'
AND DOS.DOS_ETAT <> 'S'
AND LRE.LRE_ETAT <> 'S'
AND RES.RES_CODE || TO_CHAR(LRE.LRE_NUM_ORDRE) IN
(SELECT LRE.RES_CODE || TO_CHAR(MIN(LRE.LRE_NUM_ORDRE))
FROM T_LEG_RESA_TOU LRE
LEFT OUTER JOIN T_LISTE_PAX_TOU LISTEPAX
ON LRE.LRE_UID = LISTEPAX.LRE_UID
LEFT OUTER JOIN T_PASSAGERS_TOU PAX
ON LISTEPAX.PAX_UID = PAX.PAX_UID
AND PAX.PAX_ETAT <> 'S' AND PAX.PAX_FLAG_LEAD = 'O'
WHERE LRE.LRE_ETAT <> 'S'
AND LRE.LRE_UID IN
(SELECT LISTEPAX.LRE_UID
FROM T_LISTE_PAX_TOU LISTEPAX, T_PASSAGERS_TOU PAX
WHERE LISTEPAX.PAX_UID = PAX.PAX_UID
AND PAX.PAX_ETAT <> 'S'
AND PAX.PAX_NOM LIKE :v0)
GROUP BY LRE.RES_CODE)
GROUP BY (RES.RES_CODE, RES.DOS_CODE, RES.RCP_TYPETATRES, RES.RCP_TYPSTTRESA,
LRE.ROU_CODE, LRE.NSF_CODE, LRE.LRE_DATE, LRE.LRE_HEURE, LRE.LRE_IMMAT,
LRE.RCP_LBL_VEH, LRE.LRE_NB_CAT1, LRE.LRE_NB_CAT2, LRE.LRE_NB_CAT3,
CLT.CLT_CODE, CLT.CLT_NOM , AGT.AGT_NOM, AGT.AGT_CODE)
ORDER BY DATEDEPART, HEUREDEPART )


there is quite a bit going on there -- and the group by isn't going to help

There isn't alot an index could do (in order to group by, you'll typically need the entire result set).

one thing I would change (don't expect it to change much) would be:

AND RES.RES_CODE || TO_CHAR(LRE.LRE_NUM_ORDRE) IN
(SELECT LRE.RES_CODE || TO_CHAR(MIN(LRE.LRE_NUM_ORDRE))


that should definitely be:

AND (RES.RES_CODE, LRE.LRE_NUM_ORDRE) IN
(SELECT LRE.RES_CODE, MIN(LRE.LRE_NUM_ORDRE)


But with lots of "inequalities" and no equalities - and that big group by, getting this to return "fast"...


Recursive Statements consumes lot of time?

Shailesh Saraff, September 15, 2005 - 9:57 am UTC

Dear Tom,

One particular operation on our databases takes 39 seconds and SqlTrace\TkProf tells us that non recursive statements takes 1.15 seconds whereas recursive statements issued by oracle consumes 37.15 seconds.

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 107 0.09 0.10 0 3 0 0
Execute 206 1.03 1.05 2 130 268 180
Fetch 206 0.03 0.02 0 1714 0 283
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 519 1.15 1.17 2 1847 268 463

Misses in library cache during parse: 43
Misses in library cache during execute: 37
-------------------------------------------------------
OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 22265 1.39 1.17 0 0 0 0
Execute 34614 23.48 24.42 4 70946 20210 12667
Fetch 23961 12.28 11.78 11 1098480 0 16335
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 80840 37.15 37.38 15 1169426 20210 29002

Misses in library cache during parse: 42
Misses in library cache during execute: 37

How should we do to improve on this? Could you please guide us.

Thanks & Regards,

Shailesh

Tom Kyte
September 15, 2005 - 10:22 am UTC

look up in the report at the recursive SQL, don't forget - plsql that runs sql is running recursive sql so if this is from a stored procedure, it is all your code.

ops$tkyte@ORA9IR2> select 24.42/34614 from dual;
 
24.42/34614
-----------
 .000705495


pretty impressive isn't it, 0.0007 seconds per sql statement.


The only way you'll improve that -- run less SQL, look at your algorithm, if you see lots of loops over result sets with updates/inserts/deletes in the middle ask "why do we have code, could this not be a single sql statment" 

Query Performance in 9i is slow compared to 10g

Sarma, September 15, 2005 - 5:51 pm UTC

Hi Tom,

Regarding query comparision between 9i and 10g pertaining to my earlier posting, I have analyzed tables doing full table scans of my 9i schema using dbms_stats.gather_table_stats procedure with for all indexed columns option according to your suggestion, performance has increased considerably ( earlier it was taking 1.05 seconds now it is taking 10 seconds but still compared to 10g database it is slower). 10g database is taking 110 seconds to execute this query. I read Oracle has improved its cost based optimizer in 10g release may be 9i cannot achieve that.

One other question is I tried to update bunch of records by using correlated sub-query statement but it did not finish after 30 min and I had to kill the session. There are many locks and latches on this session.

Here is the sql.

update contact_persons cp
set parent_cp_id = ( select cp_parent.cp_id
from contact_persons cp_child,
project_lease_contacts plc,
contact_persons cp_parent
where plc.cp_id = cp_child.cp_id
and plc.agency_cd = cp_parent.agency_cd
and plc.brl_id = 21
and cp_child.cp_id = cp.cp_id)
So when I ran procedural code it finished in 2 minutes.

begin
for x in (select cp_id, agency_cd
from project_lease_contacts
where brl_id = 21)
loop
begin
update contact_persons
set parent_cp_id = (select cp_id
from contact_persons
where agency_cd = x.agency_cd)
where cp_id = x.cp_id;
exception
when others then
insert into log values(log_seq.nextval,'update_to_contact_persons',' update failed for agency_cd = '||x.agency_cd ||' cp_id = '||x.cp_id,sysdate);
end;
end loop;
commit;
exception
when others then
dbms_output.put_line ( ' update failed '||sqlerrm);
raise;
end;

could you please point out what am I doing wrong here?

Thanking you,
Sarma

slow sql

Alay, September 16, 2005 - 10:22 am UTC

Hi Tom,
I have been asked this question in interview.
" we have a database of banking sector. we need to generate daily report and for that we have a readymade script which contain SQL query to generate daily report. One day suddenly this query perform very slowly. What could be reason behind that? As a database administrator how would you solve this issue? "

Can you tell me the answer?

Tom Kyte
September 16, 2005 - 1:33 pm UTC

I'd ask "what changed" and start working from there.

The answer is always "nothing" at first, but then it comes out.... "statistics were gathered", "data was loaded"...

Something changed...

either that or trace it, look at it, tune it.

OK

Sam Augustine, September 17, 2005 - 1:47 pm UTC

Hi Tom,
Suppose if I have an Index on empno column,

i)Is it mandatory that WHERE Clause must be present to
use the index??

ii)will the index be used when I use conditions like

empno < 1000 or empno > 1000 or empno <= 1000

iii)on what occasions will the index won't be used??

Please do reply.




Tom Kyte
September 17, 2005 - 11:40 pm UTC

i) no, we can use the index for various things -- index fast full scan for example.

if you have an index on t(x,y,z) and you

select x,z from t;

it is likely we'd use the index as a "skinny version of the table" and fast full scan it.

ii) maybe, maybe not.

say ALL rows were such that empno < 1000 - it won't use an index range scan probably to find them (statistics will tell it whether to use the index or not)





Tom, Please explain

Kishor Bhalwankar, September 21, 2005 - 12:08 pm UTC

Tom,
Thanks in advance.
Can you please explain, why this query is taking longer time to execute (it is taking more than 10Hrs to execute (terminated before completing) ?

Thanks and Regards
Kishor Bhalwankar

SELECT
count(*)
FROM EQ_EQUIPMENTS eqp , EQ_EQUIPMENTEVENTS eve ,EQ_EQUIPMENTSTATUS eqs
WHERE eqp.EQUIPMENT_NO=eve.EQM_EQUIPMENT_NO
AND eqp.EQUIPMENT_NO=eqs.EQM_EQUIPMENT_NO
AND eqp.MASTER_SYSTEM ='ATLAS'
AND eqp.OST_OWNEROMSID_FK = eve.OST_OWNEROMSID_FK
AND eve.EVENT_DATETM =(select max(EVENT_DATETM) from eq_equipmentevents eve1
where eqp.EQUIPMENT_NO=eve1.EQM_EQUIPMENT_NO);

SEGMENT_NAME Size Num Of rows Last analyzed
------------------------------------------------------------------------------------------------------------------------
EQ_EQUIPMENTEVENTS 1611.25 7489220 18-SEP-05
EQ_EQUIPMENTS 85.25 548670 18-SEP-05
EQ_EQUIPMENTSTATUS 47.25 522710 18-SEP-05

------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost |
-------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | | | 91824 |
| 1 | SORT AGGREGATE | | 1 | | | |
| 2 | VIEW | | 25 | | | 91824 |
|* 3 | FILTER | | | | | |
| 4 | SORT GROUP BY | | 25 | 2450 | | 91824 |
| 5 | NESTED LOOPS | | 7752K| 724M| | 32138 |
|* 6 | HASH JOIN | | 7752K| 584M| 28M| 32137 |
|* 7 | HASH JOIN | | 422K| 23M| 3520K| 16853 |
|* 8 | TABLE ACCESS FULL| EQ_EQUIPMENTS | 92230 | 2431K| | 663 |
| 9 | TABLE ACCESS FULL| EQ_EQUIPMENTEVENTS | 7174K| 218M| | 11339 |
| 10 | TABLE ACCESS FULL | EQ_EQUIPMENTEVENTS | 7174K| 136M| | 11339 |
|* 11 | INDEX UNIQUE SCAN | EQ_EQUIPMENTSTATUS_PK | 1 | 19 | | |
-------------------------------------------------------------------------------------------
Total System Global Area 4330593496 bytes
Fixed Size 748760 bytes
Variable Size 922746880 bytes
Database Buffers 3405774848 bytes
Redo Buffers 1323008 bytes

pga_aggregate_target big integer 1073741824

TABLE_NAME INDEX_NAME COLUMN_NAME COLUMN_POSITION BLEVEL LEAF_BLOCKS DISTINCT_KEYS
------------------ --------------------- --------------------- --------------- ---------- ----------- -------------
CLUSTERING_FACTOR LAST_ANAL
----------------- ---------
EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EQM_EQUIPMENT_NO 1 2 40320 97714
1
6285680 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EVENT_STATUS 2 2 40320 97714
1
6285680 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU OST_OWNEROMSID_FK 3 2 40320 97714
1
6285680 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU LASTUPDATE_DATETM 1 2 49520 426474
10
3259220 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU PONL_REF_NO 1 2 24410 173626
11
4206040 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EVENT_NO 1 2 73070 1134060
2
4600110 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EQM_EQUIPMENT_NO 2 2 73070 1134060
2
4600110 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU FAC_FACILITY_CODE_FK 1 2 39090 242907
3
5950870 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EQM_EQUIPMENT_NO 2 2 39090 242907
3
5950870 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU SBC_SUBCONDITION 1 2 48970 2
5
218800 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU OST_OWNEROMSID_FK 2 2 48970 2
5
218800 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EVENTTYPE 1 2 55180 35
6
1861190 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU STATUS 3 2 55180 35
6
1861190 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EVENTPURPOSE 2 2 55180 35
6
1861190 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU CND_CONDITIONNAME 1 2 3705 3
7
69995 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_NU EVENT_DATETM 1 2 43430 59950
9
4830700 18-SEP-05

EQ_EQUIPMENTEVENTS EQ_EQUIPMENTEVENTS_PK EVENT_SEQ 1 2 49820 7249410
3395880 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU FAC_FACILITYCODE_FK 1 2 1272 1729
1
87346 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU CND_CONDITIONNAME 1 2 2809 1
3
8477 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU EEM_RESV_CODE 1 0 1 1
4
23 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU SBC_SUBCONDITION 1 1 2 11
5
350 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU SBC_OST_OWNEROMSID_FK 2 1 2 11
5
350 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU FAC_CURRENTFACILITYCO 1 2 1859 2203
6 DE_FK
94002 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_NU FAC_FACILITYCODE_FK 2 2 1859 2203
6
94002 18-SEP-05

EQ_EQUIPMENTSTATUS EQ_EQUIPMENTSTATUS_PK EQM_EQUIPMENT_NO 1 2 2324 570733
536273 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU1 OST_OWNEROMSID_FK 1 2 2203 3117
351460 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU1 SRG_SERIALRANGE_SEQ 2 2 2203 3117
351460 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU10 COM_COMPANY_CODE 1 2 2596 54
66638 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU11 ISC_ISOCODE 1 2 2948 61
121929 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU12 SFL_SUBFLEET_CODE 1 2 3244 2
13127 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU2 STY_EQPSIZE 1 2 3263 23
57528 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU2 STY_TYPE_CODE 2 2 3263 23
57528 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU3 SRG_SERIALRANGE_SEQ 1 2 1251 2508
340400 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU4 PRI_PROCUREREF_NO 1 1 255 2052
64691 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU5 DSI_DISPOSALINSTR_ID 1 1 97 9309
17186 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU6 SHI_LISTITEM_NO 1 1 36 7590
7458 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU6 SHI_SHO_BOOKINGREF_NO 2 1 36 7590
7458 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU7 POO_POOL_CODE 1 2 3061 7
16813 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU8 COM_CODE_CURR_OPER 1 2 2994 29
22040 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_NU9 COM_CODE_PREV_OPER 1 1 114 14
9257 18-SEP-05

EQ_EQUIPMENTS EQ_EQUIPMENTS_PK EQUIPMENT_NO 1 2 2255 558778
515207 18-SEP-05


41 rows selected.



A reader, September 23, 2005 - 9:19 am UTC

Hi Tom,

Where can I find the details
to tune the Solaris kernel?

What are the parameters that
need to be configured on
Operating system and database
sides to achieve good
database performance?

Thanks.

Tom Kyte
September 23, 2005 - 8:03 pm UTC

The installation guide has the recommended settings.

before tuning, you would want to find out "what the issues" are - there are no universal set of "best settings" for anything.

Any idea how I can re-write this Function

A reader, September 26, 2005 - 4:34 pm UTC

RETURN INTEGER
IS
BEGIN
IF s_date_in IS NULL
THEN
RETURN 0;
ELSIF TRUNC(1_date,'DD') > TRUNC(NVL(1_date,SYSDATE),'DD')
THEN
RETURN 0;
ELSE

RETURN ((TRUNC(NVL(2_date_in,SYSDATE),'DD') -
TRUNC(NVL(1_date_in,SYSDATE),'DD')) + 1);
END IF;


Tom Kyte
September 27, 2005 - 9:51 am UTC

why? doesn't it do what you want?

not that it is valid -- 2_date_in, 1_date_in - not valid variable names...

follow-up

A reader, September 27, 2005 - 10:19 am UTC

Tom,

It's doing what it supposed to be doing. But I was just wondering if the trunc could have be written better.


Thanks

Tom Kyte
September 27, 2005 - 12:00 pm UTC

looks fine to me, unless you actually try to compile it ;) then it fails.

thanks!

A reader, September 28, 2005 - 9:55 am UTC


A reader, September 29, 2005 - 10:38 am UTC

Hi Tom,

Need help in improving the performance of the query/rewriting it. I did a set autotrace traceonly explain..

dtval is a date column
idflag is a char(1) column

I have an index on test(dtval) ---> idx_test_dtval

select * from
(select rownum rn, a.* from
(select to_char(dtval,'mm-dd-yyyy') dtval,
count(case when idflag = 'Y' then 1 end) val1,
count(case when idflag ='N' then 1 end) val2
from test
where dtval between '09-01-2005' and '09-02-2005'
group by to_char(dtval,'mm-dd-yyyy')
) a
)
where rn between 1 and 50
/
Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=ALL_ROWS (Cost=2092 Card=2699 Byt
es=124154)

1 0 VIEW (Cost=2092 Card=2699 Bytes=124154)
2 1 COUNT
3 2 VIEW (Cost=2092 Card=2699 Bytes=89067)
4 3 SORT (GROUP BY) (Cost=2092 Card=2699 Bytes=26990)
5 4 TABLE ACCESS (BY GLOBAL INDEX ROWID) OF 'TEST'
(TABLE) (Cost=2091 Card=2915 Bytes=29150)

6 5 INDEX (RANGE SCAN) OF 'IDX_TEST_DTVAL' (INDEX) (Cost=12 Card=2915)

Thanks.

Tom Kyte
September 30, 2005 - 8:06 am UTC

well, I have to assume dtval is a DATE since you to_char it, so why are you comparing a date to a string???!?

an index on dtval,idflag would help (instead of just dtval) - it would skip the table access by global index rowid step.

Using trunc instead of to_char will use less cpu. trunc(dtval,'dd') - not to_char. Always.

Using a top-n query would be more efficient as well. But - you haven't any sort so this is getting a RANDOM 50 rows????? where is the order by????

select *
from ( select trunc(dtval,'dd') dtval,
count(case when idflag='Y' then 1 end) val1,
count(case when idflag='N' then 1 end) val2
from test
where dtval between to_date( :x, 'mm-dd-yyyy')
and to_date( :y, 'mm-dd-yyyy')
group by trunc(dtval,'dd')
order by 1
)
where rownum <= :z;


If this is a "pagination query" - you might ask for 51..100 next - see:
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:127412348064 <code>

for the right set of inline views.

Another addition to prevous query

A reader, September 30, 2005 - 9:11 am UTC

Hi Tom,

I followed your suggestion for the previous query and it works great. My output is coming as

DTVAL VAL1 VAL2
------------------- ------------- -----------
09-01-2005 00:00:00 0 0
09-02-2005 00:00:00 0 0
09-03-2005 00:00:00 0 0
09-05-2005 00:00:00 0 2
09-06-2005 00:00:00 2 2
09-07-2005 00:00:00 5 3
09-08-2005 00:00:00 7 8

I need two alerations to this. It will be good if the time (00:00:00) does not get displayed in the output. Also is there a way to get the subtotals for val1 and val2.

Thanks a lot for your help.

Thanks.

Tom Kyte
September 30, 2005 - 10:59 am UTC

formatting a date for display -- that is when TO_CHAR should be used:


select to_char(dtval,'mm-dd-yyyy'), sum(val1), sum(val2)
from ( select trunc(dtval,'dd') dtval,
count(case when idflag='Y' then 1 end) val1,
count(case when idflag='N' then 1 end) val2
from test
where dtval between to_date( :x, 'mm-dd-yyyy')
and to_date( :y, 'mm-dd-yyyy')
group by trunc(dtval,'dd')
order by 1
)
where rownum <= :z
group by rollup( to_char(dtval,'mm-dd-yyyy') )



Thanks a lot Tom it works great !!!!! You are the best

A reader, September 30, 2005 - 1:43 pm UTC


Optimize the query

A reader, October 06, 2005 - 7:32 pm UTC

Is there any way to optimize the query to do it in a single sql query (instead of multiple queries connected by union).

---- query text in the view
select iom.iom_order_id, ckt.location_id from_ckt_loc
from iom_order iom,
activity a,
circuit ckt
where iom.iom_order_id = a.iom_order_id
and iom.service_type = 6
and a.acty_type != -1
and a.cancel_ind = 'N'
and a.component = 0 -- access
and a.component_id = ckt.circuit_id
union
select iom.iom_order_id, tsg.tsg_loc_id as from_tsg_loc
from iom_order iom,
activity a,
nodal_tsg tsg
where iom.iom_order_id = a.iom_order_id
and iom.service_type = 6
and a.acty_type != -1
and a.cancel_ind = 'N'
and a.component = 5 -- nodal_tsg
and a.component_id = tsg.nodal_tsg_id
union
select iom.iom_order_id, dn.tsg_loc_id from_nodal_dial_loc
from iom_order iom,
activity a,
nodal_dial_no dn
where iom.iom_order_id = a.iom_order_id
and iom.service_type = 6
and a.acty_type != -1
and a.cancel_ind = 'N'
and a.component = 7 -- nodal_dial_no
and a.component_id = dn.nodal_dial_no_id
union
select iom.iom_order_id, chan.d_chan_loc_id from_d_channel_loc
from iom_order iom,
activity a,
d_channel chan
where iom.iom_order_id = a.iom_order_id
and iom.service_type = 6
and a.acty_type != -1
and a.cancel_ind = 'N'
and a.component = 6 -- d_channel
and a.component_id = chan.d_channel_id

Tom Kyte
October 06, 2005 - 8:48 pm UTC

hard to say - what is the relationship between "A" and the tables chan, dn, tsg, ckt - 1:1 or 1:m?

A reader, October 06, 2005 - 9:14 pm UTC

Relationship between "A" and the tables chan, dn, tsg,
ckt is 1:1

Relation ship between "iom_order" to "Activity ("A")
is 1:M


Tom Kyte
October 07, 2005 - 7:49 am UTC

select iom.iom_order_id, ckt.location_id from_ckt_loc, <other columns here>
from iom_order iom,
activity a,
circuit ckt,
chan, dn, tsg
where iom.iom_order_id = a.iom_order_id
and iom.service_type = 6
and a.acty_type != -1
and a.cancel_ind = 'N'
and a.component = 0 -- access
and a.component_id = ckt.circuit_id(+)
and a.component_id = tsg.nodal_tsg_id(+)
and a.component_id = dn.nodal_dial_no_id(+)
and a.component_id = chan.d_channel_id(+)


Instead of getting a "row for each table", you'll get less rows - with more columns and the oclumns will have your data from each table (or NULL if no data existed).

You might have to add

and (ckt.circuit_id is not null OR tsg.nodal_tsg_id is not null or .... )

to only keep records that have a mate in at least one of the 4 tables.

Thanks for optimizing the query

A reader, October 07, 2005 - 10:29 am UTC

Tom,

I need to add (5,6,7) as below in the query predicate :

and a.component in (0,5,6,7)


Also, i need to filter out only one location id (it could have a mate in more than one tables or only one table),

select iom.iom_order_id, ckt.location_id from_ckt_loc, from_tsg_loc, from_nodal_dial_loc, from_d_channel_loc

...

How do i extract atleast one of the "location id" which is not null (it is possible only one column will have id not null and others will be null and vice-versa ?

Should i write select (select ...) on the original query.


Tom Kyte
October 07, 2005 - 9:45 pm UTC

... and a.component in (0,5,6,7) ...

that is fine..


... Also, i need to filter out only one location id ...

that I did not understand?

A reader, October 08, 2005 - 1:09 am UTC

Tom,

Sorry for the confusion.

What i meant was, say the query returns the output as

ckt.location_id,
tsg.tsg_loc_id,
dn.tsg_loc_id,
chan.d_chan_loc_id

All the above columns  (location id columns) may either have the same data value Or One column may have data value populated and others could be NULL. How do i know which location id column has data ? 

What i want is , just one location_id (no matter from which base table it comes from ). 

Other thing is, i tried executing the query but got wrong results. 

activity.component ==> stores table name as code value
                       0- access, 5-tsg, 7-dn, 6-chan

activity.component_id ==> stores the PKs of those tables.

Is it possible to make this query work (with this table design) ?

  1  select  iom.iom_order_id, a.cancel_ind, ckt.location_id from_ckt_loc, tsg.tsg_loc_id as from_tsg_loc,
  2      dn.tsg_loc_id from_nodal_dial_loc, chan.d_chan_loc_id from_d_channel_loc
  3  , a.component, a.component_id
  4   from    iom_order       iom,
  5           activity        a,
  6           circuit         ckt,
  7           d_channel chan, nodal_dial_no dn, nodal_tsg tsg
  8   where   iom.iom_order_id = a.iom_order_id
  9   and     iom.service_type = 6
 10   and     a.acty_type      != -1
 11   and     a.cancel_ind      = 'N'
 12   and     a.component in (0,5,6,7)
 13   and     a.component_id = ckt.circuit_id(+)
 14   and     a.component_id = tsg.nodal_tsg_id(+)
 15   and     a.component_id = dn.nodal_dial_no_id(+)
 16   and     a.component_id = chan.d_channel_id(+)
 17*  and     iom.iom_order_id=57130
SQL> /

IOM_ORDER_ID C FROM_CKT_LOC FROM_TSG_LOC FROM_NODAL_DIAL_LOC FROM_D_CHANNEL_LOC  COMPONENT COMPONENT_ID
------------ - ------------ ------------ ------------------- ------------------ ---------- ------------
       57130 N      1225775                                                              0        13729
       57130 N      1225775                                                              0        13730
       57130 N      1225775                                                              0        13731
       57130 N      1225775                                                              0        13732
       57130 N      1182275      1189914             1195759            1225775          6         3214
       57130 N                   1225775                                                 5        11958
       57130 N      1190474      1204594             1225775                             7         6126

7 rows selected.

SQL> 


My acutual (original query in the post) does return the correct results :

SQL> select * from nodal_location_summary_2 where iom_order_id=57130;

IOM_ORDER_ID LOCATION_ID
------------ -----------
       57130     1225775


===> nodal_location_summary_2 is the view made up of those UNION queries


// Here is the individual query results from each table

SQL> select activity_id, component, component_id, cancel_ind from activity 
  2  where iom_order_id=57130 ;

ACTIVITY_ID  COMPONENT COMPONENT_ID C
----------- ---------- ------------ -
   70010910          0        13729 N
   70010911          0        13730 N
   70010912          0        13731 N
   70010913          0        13732 N
   70010914          6         3214 N
   70010915          5        11958 N
   70010916          7         6126 N

7 rows selected.

SQL> select location_id, circuit_id from circuit where circuit_id in (13729, 13730, 13731, 13732) ;

LOCATION_ID CIRCUIT_ID
----------- ----------
    1225775      13729
    1225775      13730
    1225775      13731
    1225775      13732

SQL> select tsg_loc_id, nodal_tsg_id from nodal_tsg where nodal_tsg_id=11958 ;

TSG_LOC_ID NODAL_TSG_ID
---------- ------------
   1225775        11958

SQL> select tsg_loc_id, nodal_dial_no_id from nodal_dial_no where nodal_dial_no_id=6126 ;

TSG_LOC_ID NODAL_DIAL_NO_ID
---------- ----------------
   1225775             6126

SQL> select d_chan_loc_id, d_channel_id  from d_channel where d_channel_id=3214 ;

D_CHAN_LOC_ID D_CHANNEL_ID
------------- ------------
      1225775         3214

SQL> 


Thanks for your help. 

Tom Kyte
October 08, 2005 - 8:54 am UTC

select coalesce( c1, c2, c3, c4 ) ....


returns the first not null value from that list.

A reader, October 08, 2005 - 10:17 am UTC

Thanks tom for the solution. Coalesce works great.

But as i mentioned in the previous post, the query output is wrong.

 1  select  iom.iom_order_id, a.cancel_ind,
  2  coalesce(ckt.location_id, tsg.tsg_loc_id, dn.tsg_loc_id, chan.d_chan_loc_id) location_id,
  3  a.component, a.component_id
  4   from    iom_order       iom,
  5           activity        a,
  6           circuit         ckt,
  7           d_channel chan, nodal_dial_no dn, nodal_tsg tsg
  8   where   iom.iom_order_id = a.iom_order_id
  9   and     iom.service_type = 6
 10   and     a.acty_type      != -1
 11   and     a.cancel_ind      = 'N'
 12   and     a.component in (0,5,6,7)
 13   and     a.component_id = ckt.circuit_id(+)
 14   and     a.component_id = tsg.nodal_tsg_id(+)
 15   and     a.component_id = dn.nodal_dial_no_id(+)
 16   and     a.component_id = chan.d_channel_id(+)
 17*  and     iom.iom_order_id=57130
SQL> /

IOM_ORDER_ID C LOCATION_ID  COMPONENT COMPONENT_ID
------------ - ----------- ---------- ------------
       57130 N     1225775          0        13729
       57130 N     1225775          0        13730
       57130 N     1225775          0        13731
       57130 N     1225775          0        13732
       57130 N     1182275          6         3214
       57130 N     1225775          5        11958
       57130 N     1190474          7         6126

7 rows selected.

The query does not produce the correct results.
1225775 is the correct location_id.
 

Tom Kyte
October 08, 2005 - 10:29 am UTC

tell me why 1225775 is the "right" answer - you said "from any table"

if you have a PREFERED table - use that in the coalesce, or if the component id tells you what one is preferred, use DECODE to pull the "first right one"

A reader, October 08, 2005 - 11:16 am UTC

Tom,

Because, 1225775 is the location id stored in all component tables. the reason i think why the query produced wrong results is, each activity.component_id is matched with every other component tables without proper relation (even after specified acty.component in (0,5,6,7) )

I rewrote the query using "Scalar subqueries" and the query worked and the output is correct.

I had to use "select (select"" to "Coalesce". Is it possible to avoid "select (select" and do it in one inner select with "Coalesce" itself.


Do you have any other suggestions to optimize the query ?

 SQL> l
  1  select distinct inner.iom_order_id,
  2  coalesce(from_ckt_loc, from_tsg_loc, from_d_channel_loc, from_nodal_dial_no_loc) location_id
  3  from
  4  (select  iom.iom_order_id, a.cancel_ind, a.component, a.component_id,
  5  --coalesce(ckt.location_id, tsg.tsg_loc_id, dn.tsg_loc_id, chan.d_chan_loc_id) location_id,
  6  (select ckt.location_id from_ckt_loc from circuit ckt
  7   where a.component=0
  8   and   ckt.circuit_id=a.component_id) from_ckt_loc,
  9  (select tsg.tsg_loc_id from nodal_tsg tsg
 10   where a.component=5
 11   and tsg.nodal_tsg_id=a.component_id) from_tsg_loc,
 12  (select chan.d_chan_loc_id from d_channel chan
 13   where a.component=6
 14   and chan.d_channel_id=a.component_id) from_d_channel_loc,
 15  (select dn.tsg_loc_id from nodal_dial_no dn
 16   where a.component=7
 17   and dn.nodal_dial_no_id=a.component_id) from_nodal_dial_no_loc
 18   from    iom_order       iom,
 19           activity        a
 20   where   iom.iom_order_id = a.iom_order_id
 21   and     iom.service_type = 6
 22   and     a.acty_type      != -1
 23   and     a.cancel_ind      = 'N'
 24   and     a.component in (0,5,6,7)
 25   and     iom.iom_order_id=57130
 26* ) inner
SQL> /

IOM_ORDER_ID LOCATION_ID
------------ -----------
       57130     1225775

SQL> 


As always, thanks for your help and suggestions. 

BITMAP Index

Deepak, October 10, 2005 - 6:13 am UTC

Hi Tom,

In my DWH DB I have a table with few million rows. I have a column in the table having 15 distinct values. That column is being used in the where clause of the queries. What I am interested to know is would it be beneficial to create a bitmap index on it.

Is there any specific ratio (distincy values)/(Num of rows) at which one must consider creating bitmap indexes rather than b-tree indexes?

Tom Kyte
October 10, 2005 - 8:54 am UTC

</code> http://www.jlcomp.demon.co.uk/03_bitmap_1i.html <code>

good background material.


The answer will be "it depends" (could you see that coming :)

insufficient data to really say. If you are doing:

select * from table where that_col = <value>;

maybe yes, maybe no. depends on how well the data is clustered on this value (if the rows are near eachother in the table)....

depends on the other predicates involved.


if you are aggregating, like "counting" - it could well be very beneficial.\


But read that paper, get a better understanding of how/why they work and start from there (understanding...)

Count(*) vs Max

Ravindran B, October 20, 2005 - 12:00 pm UTC

Hi Tom,

Is there any performance gain over using Max() instead of Count(1).
My requirement is I have to count the no. of rows and update a particular field (CTR)in a table. So, is it better to use Count(*) and update the field or Select MAX(CTR)+1 and update the CTR field?

Tom Kyte
October 20, 2005 - 4:48 pm UTC

they are NOT comparable in general.


since gap free sequences are the things of dreams (my nightmares) I don't see how max(ctr) could really be equal to count(*)?


but if it, sigh, is.... meaning you serialize every transaction, max(ctr) is better than count(*) in that case.

This is a SQL/Math Challenge , anybody is welcome to give it a try !!

Frank Zhou, October 26, 2005 - 11:47 am UTC

Hi Tom,

            I have found a pretty interesting math problem posted on a company's website. I am just wondering do you have a another solution that performs faster than mine. ( This problem is not work related, I just tried it for fun :-)   )

Here is the Qustion:

Lucky Sevens 
Write a program to compute the sum of all the integers
between 1   and   POWER(10, 11) that are both divisible by seven and, when the decimal digits are reversed, are still divisible by seven. Solutions to this problem will be judged on performance or algorithmic sophistication. 

Here is my soultion:

--------------------------------------- Oracle 9I or above

SELECT  SUM(num) total
  FROM (SELECT LEVEL * 7  num FROM dual CONNECT BY LEVEL * 7 <= POWER(10, 11) )
 WHERE   MOD( TO_NUMBER( REVERSE(TO_CHAR(num))),7) = 0

Here is a simple test:

SQL> SELECT  SUM(num) total
 2  FROM (SELECT LEVEL * 7  num FROM dual CONNECT BY LEVEL * 7 <= POWER(10, 3) )
  3   WHERE   MOD( TO_NUMBER( REVERSE(TO_CHAR(num))),7) = 0
  4  /

     TOTAL
----------
     10787

SQL>

I believe the most efficient solution should be figuring out a generic formula , so that this formula can automatically determines a number that are both divisible by seven and, when the decimal digits are reversed, are still divisible by seven.  So both checking can be skipped.

Such that    1    *   formual   =   7
             2    *   formual   =  70
             3    *   formual   =  77        
Etc …..

SELECT  SUM(num) total
FROM 
(SELECT LEVEL * FORMULA  num FROM dual CONNECT BY LEVEL * 7 <= POWER(10, 11) )


Thanks,

Frank
 

difference between these 2 queries

A reader, October 26, 2005 - 3:54 pm UTC

Hi

I have two queries which are almost the same except in one outer query is inside an inline view and ther other outside. The one outside runs lighting fast but the one inside is deadly slow. I dont understand why, I cant find any documentation to explain such behaviour.

Here is the fast query with the plan:

SELECT o2.elm_objid AS objid, '1' AS wipbin_type, ' ' AS age_str, -1 AS dev,
o2.wip_objid, 2 AS elm_objid, o2.age,
o2.creation_time AS creation_date, o2.condition, o2.status, o2.title,
o2.priority, o2.id_number AS idnum, -1 AS struct_type,
owner AS x_owner, x_owner_name, x_owner_group, x_owner_group_name,
o2.x_tipo_caso AS TYPE, o2.objid, o2.NAME, o2.x_prioridad_nodo,
o2.x_proveedor_nodo, o2.x_tipo_nodo, e.objid, e.NAME,
e.x_prioridad_nodo
FROM (SELECT n.x_nodo2emplazamiento, o.elm_objid, o.wip_objid, o.age,
c.creation_time, o.condition, o.status, o.title, o.priority,
o.id_number, owner, x_owner_name, x_owner_group,
x_owner_group_name, o.x_tipo_caso, n.objid, n.NAME,
n.x_prioridad_nodo, n.x_proveedor_nodo, n.x_tipo_nodo
FROM table_x_workgroup_case o,
table_case c,
table_x_case_in ci,
table_site n
WHERE c.objid = o.elm_objid
AND c.objid = ci.x_case_in2case
AND n.objid = c.case_reporter2site) o2,
table_site e
WHERE o2.x_nodo2emplazamiento(+) = e.objid
AND o2.x_owner_name = 'ADM'

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=237 Card=24 Bytes=8040)
1 0 NESTED LOOPS (Cost=237 Card=24 Bytes=8040)
2 1 NESTED LOOPS (Cost=189 Card=24 Bytes=7488)
3 2 NESTED LOOPS (Cost=141 Card=24 Bytes=7344)
4 3 NESTED LOOPS (Cost=117 Card=24 Bytes=6984)
5 4 NESTED LOOPS (Cost=87 Card=30 Bytes=8220)
6 5 NESTED LOOPS (Cost=57 Card=30 Bytes=6990)
7 6 NESTED LOOPS (Cost=27 Card=30 Bytes=6420)
8 7 HASH JOIN (Cost=27 Card=30 Bytes=6240)
9 8 HASH JOIN (Cost=24 Card=30 Bytes=5640)
10 9 NESTED LOOPS (Cost=21 Card=30 Bytes=5040)
11 10 HASH JOIN (Cost=21 Card=30 Bytes=4860)
12 11 NESTED LOOPS (OUTER) (Cost=18 Card=30 Bytes=4260)
13 12 NESTED LOOPS (Cost=18 Card=30 Bytes=4080)
14 13 NESTED LOOPS (Cost=12 Card=2 Bytes=54)
15 14 TABLE ACCESS (FULL) OF 'TABLE_USER' (Cost=8 Card=2 Bytes=30)
16 14 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_EMPLOYEE' (Cost=2 Card=1912 Bytes=22944)
17 16 INDEX (RANGE SCAN) OF 'IND_EMPLOYEE2USER' (NON-UNIQUE) (Cost=1 Card=1912)
18 13 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CASE' (Cost=3 Card=33836 Bytes=3688124)
19 18 INDEX (RANGE SCAN) OF 'IND_CASE_OWNER2USER' (NON-UNIQUE) (Cost=2 Card=33836)
20 12 INDEX (UNIQUE SCAN) OF 'X_SERVICIOS_OBJINDEX' (UNIQUE)
21 11 TABLE ACCESS (FULL) OF 'TABLE_GBST_ELM' (Cost=2 Card=688 Bytes=13760)
22 10 INDEX (UNIQUE SCAN) OF 'GBST_ELM_OBJINDEX' (UNIQUE)
23 9 TABLE ACCESS (FULL) OF 'TABLE_GBST_ELM' (Cost=2 Card=688 Bytes=13760)
24 8 TABLE ACCESS (FULL) OF 'TABLE_GBST_ELM' (Cost=2 Card=688 Bytes=13760)
25 7 INDEX (UNIQUE SCAN) OF 'SITE_OBJINDEX' (UNIQUE)
26 6 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CASE' (Cost=1 Card=791149 Bytes=15031831)
27 26 INDEX (UNIQUE SCAN) OF 'CASE_OBJINDEX' (UNIQUE)
28 5 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_SITE' (Cost=1 Card=84370 Bytes=3459170)
29 28 INDEX (UNIQUE SCAN) OF 'SITE_OBJINDEX' (UNIQUE)
30 4 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_SITE' (Cost=1 Card=84370 Bytes=1434290)
31 30 INDEX (UNIQUE SCAN) OF 'SITE_OBJINDEX' (UNIQUE)
32 3 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_SITE' (Cost=1 Card=84370 Bytes=1265550)
33 32 INDEX (UNIQUE SCAN) OF 'SITE_OBJINDEX' (UNIQUE)
34 2 INDEX (RANGE SCAN) OF 'X_CASE_IN_X_INDEX_CASE_IN' (NON-UNIQUE) (Cost=2 Card=392788 Bytes=2356728)
35 1 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CONDITION' (Cost=2 Card=810840 Bytes=18649320)
36 35 INDEX (UNIQUE SCAN) OF 'CONDITION_OBJINDEX' (UNIQUE) (Cost=1 Card=810840)


This one below is VERY VERY slow:

SELECT o2.elm_objid AS objid, '1' AS wipbin_type, ' ' AS age_str, -1 AS dev,
o2.wip_objid, 2 AS elm_objid, o2.age,
o2.creation_time AS creation_date, o2.condition, o2.status, o2.title,
o2.priority, o2.id_number AS idnum, -1 AS struct_type,
owner AS x_owner, x_owner_name, x_owner_group, x_owner_group_name,
o2.x_tipo_caso AS TYPE, o2.objid, o2.NAME, o2.x_prioridad_nodo,
o2.x_proveedor_nodo, o2.x_tipo_nodo, o2.mobjid, o2.mname,
o2.mx_prioridad_nodo
FROM (SELECT n.x_nodo2emplazamiento, o.elm_objid, o.wip_objid, o.age,
c.creation_time, o.condition, o.status, o.title, o.priority,
o.id_number, owner, x_owner_name, x_owner_group,
x_owner_group_name, o.x_tipo_caso, n.objid, n.NAME,
n.x_prioridad_nodo, n.x_proveedor_nodo, n.x_tipo_nodo,
m.objid mobjid, m.NAME mname,
m.x_prioridad_nodo mx_prioridad_nodo
FROM table_x_workgroup_case o,
table_case c,
table_x_case_in ci,
table_site n,
table_site m
WHERE c.objid = o.elm_objid
AND c.objid = ci.x_case_in2case
AND n.objid = c.case_reporter2site
AND n.x_nodo2emplazamiento(+) = m.objid) o2
WHERE o2.x_owner_name = 'ADM'

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=309679 Card=1265550 Bytes=423959250)
1 0 FILTER
2 1 MERGE JOIN (OUTER)
3 2 SORT (JOIN) (Cost=307482 Card=1265550 Bytes=372071700)
4 3 MERGE JOIN (CARTESIAN) (Cost=5607 Card=1265550 Bytes=372071700)
5 4 NESTED LOOPS (Cost=162 Card=15 Bytes=4155)
6 5 NESTED LOOPS (Cost=132 Card=15 Bytes=3810)
7 6 NESTED LOOPS (Cost=117 Card=15 Bytes=3585)
8 7 NESTED LOOPS (Cost=57 Card=30 Bytes=6990)
9 8 NESTED LOOPS (Cost=27 Card=30 Bytes=6420)
10 9 HASH JOIN (Cost=27 Card=30 Bytes=6240)
11 10 HASH JOIN (Cost=24 Card=30 Bytes=5640)
12 11 NESTED LOOPS (Cost=21 Card=30 Bytes=5040)
13 12 HASH JOIN (Cost=21 Card=30 Bytes=4860)
14 13 NESTED LOOPS (OUTER) (Cost=18 Card=30 Bytes=4260)
15 14 NESTED LOOPS (Cost=18 Card=30 Bytes=4080)
16 15 NESTED LOOPS (Cost=12 Card=2 Bytes=54)
17 16 TABLE ACCESS (FULL) OF 'TABLE_USER' (Cost=8 Card=2 Bytes=30)
18 16 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_EMPLOYEE' (Cost=2 Card=1912 Bytes=22944)
19 18 INDEX (RANGE SCAN) OF 'IND_EMPLOYEE2USER' (NON-UNIQUE) (Cost=1 Card=1912)
20 15 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CASE' (Cost=3 Card=33836 Bytes=3688124)
21 20 INDEX (RANGE SCAN) OF 'IND_CASE_OWNER2USER' (NON-UNIQUE) (Cost=2 Card=33836)
22 14 INDEX (UNIQUE SCAN) OF 'X_SERVICIOS_OBJINDEX' (UNIQUE)
23 13 TABLE ACCESS (FULL) OF 'TABLE_GBST_ELM' (Cost=2 Card=688 Bytes=13760)
24 12 INDEX (UNIQUE SCAN) OF 'GBST_ELM_OBJINDEX' (UNIQUE)
25 11 TABLE ACCESS (FULL) OF 'TABLE_GBST_ELM' (Cost=2 Card=688 Bytes=13760)
26 10 TABLE ACCESS (FULL) OF 'TABLE_GBST_ELM' (Cost=2 Card=688 Bytes=13760)
27 9 INDEX (UNIQUE SCAN) OF 'SITE_OBJINDEX' (UNIQUE)
28 8 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CASE' (Cost=1 Card=791149 Bytes=15031831)
29 28 INDEX (UNIQUE SCAN) OF 'CASE_OBJINDEX' (UNIQUE)
30 7 INDEX (RANGE SCAN) OF 'X_CASE_IN_X_INDEX_CASE_IN' (NON-UNIQUE) (Cost=2 Card=392788 Bytes=2356728)
31 6 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_SITE' (Cost=1 Card=84370 Bytes=1265550)
32 31 INDEX (UNIQUE SCAN) OF 'SITE_OBJINDEX' (UNIQUE)
33 5 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CONDITION' (Cost=2 Card=810840 Bytes=18649320)
34 33 INDEX (UNIQUE SCAN) OF 'CONDITION_OBJINDEX' (UNIQUE) (Cost=1 Card=810840)
35 4 SORT (JOIN) (Cost=5605 Card=84370 Bytes=1434290)
36 35 TABLE ACCESS (FULL) OF 'TABLE_SITE' (Cost=363 Card=84370 Bytes=1434290)
37 2 SORT (JOIN) (Cost=2197 Card=84370 Bytes=3459170)
38 37 TABLE ACCESS (FULL) OF 'TABLE_SITE' (Cost=363 Card=84370 Bytes=3459170)



The only difference is as I mentioned but I thought these sort of views can be merged?

Any idea?

Oracle 8i

Tom Kyte
October 27, 2005 - 4:49 am UTC

WHERE o2.x_nodo2emplazamiento(+) = e.objid
AND o2.x_owner_name = 'ADM'


that isn't an outer join - your queries are NIGHT and DAY different.


when you see:


where T1.column(+) ...
and T1.other_column = <value>

you know the (+) cannot be meaningful - it as if it were not there.


Because if you did the outer join, T1.other_column would be NULL and hence cannot be = <value>!!!!!!

so you are comparing apples to toaster ovens.

Kapil, November 08, 2005 - 4:57 pm UTC

Hi Tom,

Could you please help me to tune the following query's logic ? I mean, could we write it in some different way to run it faster then it does currently.

SELECT *
FROM
HSD_PMB_AR_CUST_BILL_HISTORY A WHERE A.CUSTOMER_TYPE = :b1 AND
A.CUSTOMER_ID = :b2 AND A.SEQ_GROUP_ID = :b3 AND NOT EXISTS (SELECT *
FROM HSD_PMB_AR_CUST_BILL_HISTORY B WHERE B.CUSTOMER_TYPE =
A.CUSTOMER_TYPE AND B.CUSTOMER_ID = A.CUSTOMER_ID AND B.SEQ_GROUP_ID =
A.SEQ_GROUP_ID AND B.BILLING_DATETIME > A.BILLING_DATETIME ) ORDER BY
INVOICE_NO DESC


Thanks
kaps

Tom Kyte
November 08, 2005 - 10:46 pm UTC

looks like you are trying to find the most current record for a single customer right?

select *
from (
select a.*,
max(billing_date) over () max_bd
from HSD_PMB_AR_CUST_BILL_HISTORY A
WHERE A.CUSTOMER_TYPE = :b1
AND A.CUSTOMER_ID = :b2
AND A.SEQ_GROUP_ID = :b3
)
where billing_datetime = max_db
order by invoice_no desc;



Need help

Giridhar, November 09, 2005 - 3:08 am UTC

Hi Tom,
I have one pro*c program which is performing well ( Means 99% of the responses are less than a second) on oracle 9.2.0.
For the last 10 days, only 75 to 85% of responses are less than a second. There are no changes in program for last 6 months. I compared the indexes in development with the indexes in production and found that all required indexes are available. Please advice how to proceed on finding the root cause:

1) I am not sure if LAST_DDL_TIME in ALL_OBJECTS can help us to analyze further on this problem. For some indexes, LAST_DDL_TIME is 09-NOV-05 and for other indexes it is showing previous year's values.
2) What are the points i have to verify now to find the root cause.

Thanks tom.
Giridhar





Tom Kyte
November 09, 2005 - 9:45 am UTC

turn on a trace - 10046, level 12

run the program

see what it is waiting on, see what it is doing.

Kapil, November 09, 2005 - 10:58 am UTC

Thanks a lot.

Can You Clarify Please?

Deborah, November 10, 2005 - 5:33 am UTC

Morning Tom

Above, you say that the outer join (+) is meaningless with the following construct.

where T1.column(+) ...
and T1.other_column = <value>

Makes sense. Now, all the examples I've found at your site show <value> as a literal does this mean that the following is correct for (+) or is this meaningless as well?

select ...
from a, b, c
where a.c1 = b.c1 (+)
and b.c1 = c.c1
and ...

Regards Deborah

Tom Kyte
November 11, 2005 - 11:41 am UTC

any expression.


if you outer join to b - and you make up a row in b, then b.c1 is null and NULL = c.c1 is never true (or false) - hence the outer join in that example is not "useful"

Question on NOT EXISTS expectations ...

Vladimir Sadilovskiy, November 12, 2005 - 1:27 pm UTC

Tom,

While tuning some of the queries in our system. I came across uknown to me behavior. 

1. NOT EXISTS reduces expected cardinality of the outer table to 20%. That is used as the rounded cardinality for the rest of the CBO calculations when joining outer table to other tables in a query.
2. But let aside previous fact, CBO decides to apply NOT EXIST as a filter as the last step of a query, not actually reducing cardinalities of the intemediate steps.

Do you think something could be done (besides PUSH_SUBQ)?

Thanks for sharing.

- Vladimir

create table t1 as select * from all_objects;
insert /*+ append */ into t1 select * from t1;
commit;
insert /*+ append */ into t1 select * from t1;
commit;
insert /*+ append */ into t1 select * from t1;
commit;
insert /*+ append */ into t1 select * from t1;
commit;
create table t2 as select * from all_objects;
insert /*+ append */ into t2 select * from t1;
commit;
insert /*+ append */ into t2 select * from t1;
commit;
insert /*+ append */ into t2 select * from t2;
commit;
insert /*+ append */ into t2 select * from t2;
commit;
create table t3 as select * from all_objects;
insert /*+ append */ into t3 select * from t1;
commit;

create index object_id$t1 on t1(object_id);
create index data_objecT_id$t2 on t2(data_object_id);
create index object_id$t3 on t3(object_id);

exec dbms_stats.delete_table_stats(null,tabname=>'t1');
exec dbms_stats.gather_table_stats(null,tabname=>'t1',method_opt=> 'for all columns size auto',cascade=>true);
exec dbms_stats.delete_table_stats(null,tabname=>'t2');
exec dbms_stats.gather_table_stats(null,tabname=>'t2',method_opt=> 'for all columns size auto',cascade=>true);
exec dbms_stats.delete_table_stats(null,tabname=>'t3');
exec dbms_stats.gather_table_stats(null,tabname=>'t3',method_opt=> 'for all columns size auto',cascade=>true);

explain plan for
select t1.object_name,t2.object_name
  from t1,t2
 where t1.object_id = t2.data_object_id
   and not exists
       (select null
          from t3
         where t3.object_id = t1.object_id);

set pages 999
set lines 150

select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------------
| Id  | Operation            |  Name         | Rows  | Bytes |TempSpc| Cost (%CPU)|
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |               |  1280K|    67M|       |  2598K (50)|
|*  1 |  FILTER              |               |       |       |       |            |
|*  2 |   HASH JOIN          |               |  1280K|    67M|  1008K| 38568   (5)|
|   3 |    TABLE ACCESS FULL | T1            | 24778 |   701K|       |  3656   (5)|
|*  4 |    TABLE ACCESS FULL | T2            |   895K|    22M|       | 30209   (5)|
|*  5 |   INDEX RANGE SCAN   | OBJECT_ID$T3  |    17 |    85 |       |     2  (50)|
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter( NOT EXISTS (SELECT /*+ */ 0 FROM "T3" "T3" WHERE
              "T3"."OBJECT_ID"=:B1))
   2 - access("SYS_ALIAS_1"."OBJECT_ID"="T2"."DATA_OBJECT_ID")
   4 - filter("T2"."DATA_OBJECT_ID" IS NOT NULL)
   5 - access("T3"."OBJECT_ID"=:B1)

delete from plan_table;

explain plan for
select /*+ push_subq */ t1.object_name,t2.object_name
  from t1,t2
 where t1.object_id = t2.data_object_id
   and not exists
       (select null
          from t3
         where t3.object_id = t1.object_id);

set pages 999
set lines 150

select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------------
| Id  | Operation            |  Name         | Rows  | Bytes |TempSpc| Cost (%CPU)|
-----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |               |  1280K|    67M|       | 38568   (5)|
|*  1 |  HASH JOIN           |               |  1280K|    67M|  1008K| 38568   (5)|
|*  2 |   TABLE ACCESS FULL  | T1            | 24778 |   701K|       |  3656   (5)|
|*  3 |    INDEX RANGE SCAN  | OBJECT_ID$T3  |    17 |    85 |       |     2  (50)|
|*  4 |   TABLE ACCESS FULL  | T2            |   895K|    22M|       | 30209   (5)|
-----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("SYS_ALIAS_1"."OBJECT_ID"="T2"."DATA_OBJECT_ID")
   2 - filter( NOT EXISTS (SELECT /*+ */ 0 FROM "T3" "T3" WHERE
              "T3"."OBJECT_ID"=:B1))
   3 - access("T3"."OBJECT_ID"=:B1)
   4 - filter("T2"."DATA_OBJECT_ID" IS NOT NULL)
SQL> 

CBO calculations:
SINGLE TABLE ACCESS PATH
  TABLE: T1     ORIG CDN: 495568  ROUNDED CDN: 24778  CMPTD CDN: 24778 <- 20%
...
Join order[1]:  T1[SYS_ALIAS_1]#0  T2[T2]#1
Now joining: T2[T2]#1 *******
...
Join cardinality:  1280144 = outer (24778) * inner (895900) * sel (5.7667e-05) <- why cardinality of outer is reduced if filter yet to be applied? 

Tom Kyte
November 12, 2005 - 4:36 pm UTC

what version you have there?


ops$tkyte@ORA10GR2> explain plan for
  2  select t1.object_name,t2.object_name
  3    from t1,t2
  4   where t1.object_id = t2.data_object_id
  5     and not exists
  6         (select null
  7            from t3
  8           where t3.object_id = t1.object_id);

Explained.

ops$tkyte@ORA10GR2> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------------
Plan hash value: 3875890750

-----------------------------------------------------------------------------------------------
| Id  | Operation              | Name         | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |              | 67520 |  4088K|       | 25554  
|*  1 |  HASH JOIN             |              | 67520 |  4088K|       | 25554  
|*  2 |   HASH JOIN RIGHT ANTI |              |   491 | 17185 |    13M|  5227   
|   3 |    INDEX FAST FULL SCAN| OBJECT_ID$T3 |   843K|  4118K|       |   428   
|   4 |    TABLE ACCESS FULL   | T1           |   804K|    23M|       |  2480   
|*  5 |   TABLE ACCESS FULL    | T2           |   522K|    13M|       | 20319   
-----------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("T1"."OBJECT_ID"="T2"."DATA_OBJECT_ID")
   2 - access("T3"."OBJECT_ID"="T1"."OBJECT_ID")
   5 - filter("T2"."DATA_OBJECT_ID" IS NOT NULL)

19 rows selected.
 

why the message is in bold?

Vladimir Sadilovskiy, November 12, 2005 - 1:34 pm UTC


It's 9.2.0.5

Vladimir Sadilovskiy, November 12, 2005 - 4:45 pm UTC

Do you think that is some kind of a bug or CBO setting?

Why the funny filter

Jonathan Lewis, November 22, 2005 - 11:37 am UTC

Tom emailed me a while back about this thread, but I've only just found time to comment.

I suspect there is nothing you can do except the pushsubq in this case, although you may be able to hint the optimizer into an anti-join - especially if you are running 10g.

dbms_xplan gave you a plan like this:

----------------------------------------------
| 0 | SELECT STATEMENT | |
|* 1 | HASH JOIN | |
|* 2 | TABLE ACCESS FULL | T1 |
|* 3 | INDEX RANGE SCAN | OBJECT_ID$T3 |
|* 4 | TABLE ACCESS FULL | T2 |
----------------------------------------------

And you asked why Oracle had applied the 5% early. (You said 20%, but I think you meant 1/20, i.e. 5%, which is value Oracle uses for the selectivity for 'col > {unknown}' where op is >, <, >=, <=.

My take on this is that the plan is a lie. It really ought to look like this: (Note the change in indentation on line 2)

----------------------------------------------
| 0 | SELECT STATEMENT | |
|* 1 | HASH JOIN | |
|* | FILTER | |
|* 2 | TABLE ACCESS FULL | T1 |
|* 3 | INDEX RANGE SCAN | OBJECT_ID$T3 |
|* 4 | TABLE ACCESS FULL | T2 |
----------------------------------------------

My evidence for this claim is the filter predicate you quoted for line two

filter( NOT EXISTS (SELECT /*+ */ 0 FROM "T3" "T3" WHERE "T3"."OBJECT_ID"=:B1))

Because there is a missing line in the plan, one of the critical cardinalities has to be lost - either the number of rows in the table, or the number of rows selected from the table by the filter. So Oracle isn't applying it early, it's just giving you the correct output to show you how it is applying it.





To Jonathan

Vladimir Sadilovskiy, November 25, 2005 - 11:39 pm UTC

I'm almost sure about applying filter (NOT EXISTS) at the later stages of the execution, not where it claimed to be able to cut off part of the rowset.

I verified that by analyzing actual cardinalities of each step of the plan (tkprof or plan statistics). The rows were piping to higher operations requiring rows from other tables, while "not exists" filter was supposed to cut off all rows.

I feel very uncomfortable about this behavior.

- Vladimir

Tom Kyte
November 26, 2005 - 11:58 am UTC

I agree - the filter takes place after (there were two plans - the one Jonathan seemed to refer to was the push_subq one)

Filter effects

Jonathan Lewis, November 26, 2005 - 1:51 pm UTC

Tom is correct, the plan I was talking about was the one with the push_subq which you had followed with the extracts from the 10053 trace.

The 'notional' plan, and actual run-time activiy was what I was showing, and perhaps I should have included the cardinality column in the notional plan as well (as below):

-----------------------------------------------------------
| 0 | SELECT STATEMENT | | 1280K
|* 1 | HASH JOIN | | 1280K
|* | FILTER | | 24778
|* 2 | TABLE ACCESS FULL | T1 | 495K
|* 3 | INDEX RANGE SCAN | OBJECT_ID$T3 | 17
|* 4 | TABLE ACCESS FULL | T2 | 895K
-----------------------------------------------------------


The problem of the earlier plan in your original posting was answered by the first comment I had made (which I can't see as I edit this follow-up) which I think was roughly "that's the way it is and you can't do anything other than the push_subq'".

It just is the case that you have a predicate on T1 that the CBO uses to derive a 5% selectivity on T1 *even though* the predicate is in the form of a subquery which will operate much later.

There is a much simpler example of this in my book, chapter 9, page 208 - 210 where, as I explain, the optimizer uses the notional result from running a subquery to calculate how many times the subquery will have to be run.

This changes in 10g.


Thanks

Vladimir Sadilovskiy, November 26, 2005 - 6:49 pm UTC

Thanks Tom and Jonathan. Jonathan, I'm sure I'll enjoy your book, which is arriving in couple days.

Sql Tuning

Ratan, November 28, 2005 - 10:45 am UTC

Hi Tom,
I need your help and suggestions to tune my query.
My query is:
SELECT FACT.DC_DISPLAY_FLG DC_DISPLAY_FLG,
FACT.BUS_TEAM_KEY BUS_TEAM_KEY,
FACT.ELIM_FLG_KEY ELIM_FLG_KEY,
FACT.ORD_CUST_GA_KEY ORD_CUST_GA_KEY,
FACT.USER_CUST_GA_KEY USER_CUST_GA_KEY,
FACT.USER_CUST_CUR_SLS_TEAM_KEY USER_CUST_CUR_SLS_TEAM_KEY,
FACT.SHIP_TO_CUST_GEOG_KEY SHIP_TO_CUST_GEOG_KEY
FROM TB_GOR06312_FCT_ORD_DAILY FACT,
(
SELECT SRC.SOURCE_SYSTEM_ID,
TIM.CALENDAR_DT,
TIM.CURR_D_MIN,
TIM.CURR_D_MAX,
TIM.PREV_D_MIN,
TIM.PREV_D_MAX,
TIM.CURR_W_MIN,
TIM.CURR_W_MAX,
TIM.PREV_W_MIN,
TIM.PREV_W_MAX,
TIM.CURR_M_MIN,
TIM.CURR_M_MAX,
TIM.PREV_M_MIN,
TIM.PREV_M_MAX,
TIM.CURR_Q_MIN,
TIM.CURR_Q_MAX,
TIM.PREV_Q_MIN,
TIM.PREV_Q_MAX,
TIM.CURR_Y_MIN,
TIM.CURR_Y_MAX,
TIM.PREV_Y_MIN,
TIM.PREV_Y_MAX
FROM TB_GOR06320_LKP_LAST_PROCESSDT TIM,
TB_GOR06303_CTL_SOURCE_SYSTEMS SRC
WHERE SRC.PROJECTID = 'GOR'
) TIMSRC
WHERE FACT.SOURCE_SYSTEM_ID = TIMSRC.SOURCE_SYSTEM_ID
AND (
(FACT.ORDER_CREDIT_DT BETWEEN TIMSRC.CURR_D_MIN AND TIMSRC.CURR_D_MAX)
OR
(FACT.ORDER_CREDIT_DT BETWEEN TIMSRC.PREV_D_MIN AND TIMSRC.PREV_D_MAX)
)

In above query the fact TB_GOR06312_FCT_ORD_DAILY is having index on SOURCE_SYSTEM_ID and ORDER_CREDIT_DT but that index is not being used for this query.
With above filters if I include the condition like "SOURCE_SYSTEM_ID = 'ABC'" the index is getting used.
What colud be the reason why the index is not getting used in my above query?
All these tables analyzed on daily bases.
Help me to tune the query.
Thanks in advance.

-Ratan



Index behavior I'm not sure I understand

Mark, November 29, 2005 - 5:45 pm UTC

Hi Tom,

I have an index-related issue that is something new to me. Hope you can offer advice.

A table in our 10gR1 database has a "lockedby" column. For background on why/how we use this, please see this otn forum post of mine - </code> http://forums.oracle.com/forums/message.jspa?messageID=926205#926205 <code>

Now, a problem comes up when a user accesses the form which - in this particular case - populates the lockedby column for a large number of rows, and then selects these rows. The population of lockedby is successful, but the subsequent query, containing "where lockedby = :employeeid" hangs seemingly indefinitely, flooring the CPU. Below is a query plan from tkprof. Note the third to last line - the range scan of the index on lockedby. It is scanning a huge number of rows, considering the base table only contains 119114 rows.

I found this odd, so I dropped the index entirely and the query ran in an acceptable time. Then I got to hypothesizing... Well, maybe this index on lockedby isn't such a good idea - the lockedby column is very often 100% null. Throughout the day, the number of lockedby updates may be a dozen for user1, a hundred for user2, and very rarely, a few tens of thousand for user3. But after the user completes his/her work, the column reverts to null again for all appropriate rows. Basically, I can't anticipate what the cardinality is going to be at any given time, nor can I anticipate how many rows fall under each value.

Perhaps the volatility (for lack of a better term) of this column could confuse the optimizer - statistics will regularly become out of whack.

My questions to you are:
1. Do you think my hypothesis could be on the right track?
2. What on earth is going on with the scanning of 161882244 rows (third to last line in query plan)? Again, there are only 119114 in the base table. Perhaps I don't totally understand indexes. I should note that I ctrl-breaked the query - I don't know if that could mess up the tkprof.

Any advice appreciated.

Thanks,
Mark

Rows Row Source Operation
------- ---------------------------------------------------
0 SORT GROUP BY (cr=0 pr=0 pw=0 time=135 us)
1377 NESTED LOOPS ANTI (cr=45551601 pr=3349 pw=0 time=590019491 us)
1377 NESTED LOOPS (cr=45548847 pr=3346 pw=0 time=589905553 us)
6098 NESTED LOOPS (cr=203642 pr=2660 pw=0 time=24141357 us)
33231 NESTED LOOPS (cr=104392 pr=1848 pw=0 time=12977610 us)
17336 NESTED LOOPS (cr=22046 pr=46 pw=0 time=831200 us)
424 NESTED LOOPS (cr=3495 pr=43 pw=0 time=513310 us)
424 NESTED LOOPS (cr=1838 pr=36 pw=0 time=492517 us)
424 NESTED LOOPS (cr=268 pr=9 pw=0 time=466441 us)
424 NESTED LOOPS (cr=266 pr=9 pw=0 time=454133 us)
91 NESTED LOOPS (cr=264 pr=9 pw=0 time=313502 us)
91 HASH JOIN RIGHT ANTI (cr=82 pr=8 pw=0 time=310475 us)
1 MAT_VIEW ACCESS FULL MV_INACTIVEABS (cr=7 pr=6 pw=0 time=14444 us)
91 HASH JOIN (cr=75 pr=2 pw=0 time=293548 us)
255 INDEX FAST FULL SCAN PK_DEFABS_1 (cr=69 pr=0 pw=0 time=1220 us)(object id 105942)
216 TABLE ACCESS FULL ABSOFFICE (cr=6 pr=2 pw=0 time=5590 us)
91 INDEX UNIQUE SCAN PK_ABSCOMPANY (cr=182 pr=1 pw=0 time=5985 us)(object id 92736)
424 INDEX FULL SCAN PK_TASKTYPE_1 (cr=2 pr=0 pw=0 time=9610 us)(object id 106506)
424 INDEX UNIQUE SCAN PK_ABSTASKTYPE_1 (cr=2 pr=0 pw=0 time=8110 us)(object id 106508)
424 TABLE ACCESS BY INDEX ROWID REGION (cr=1570 pr=27 pw=0 time=119613 us)
424 INDEX UNIQUE SCAN PK_REGION1_1 (cr=1146 pr=25 pw=0 time=99881 us)(object id 108821)
0 TABLE ACCESS FULL ABSDNU (cr=720 pr=22 pw=0 time=70439 us)
424 TABLE ACCESS HASH COUNTY (cr=1657 pr=7 pw=0 time=58173 us)
17336 TABLE ACCESS HASH CITY_ZIP_IN_COUNTY (cr=18551 pr=3 pw=0 time=264369 us)
33231 TABLE ACCESS BY INDEX ROWID PROPERTY (cr=82346 pr=1802 pw=0 time=17494577 us)
33231 INDEX RANGE SCAN IDX_PROPERTY_CITYID_ZIP (cr=52111 pr=146 pw=0 time=2026345 us)(object id 105963)
6098 TABLE ACCESS BY INDEX ROWID CLIENTORDER (cr=99250 pr=812 pw=0 time=13846048 us)
32672 INDEX RANGE SCAN IDX_CLIENTORDER_PROPERTYID (cr=66578 pr=623 pw=0 time=9454921 us)(object id 93140)
1377 TABLE ACCESS BY INDEX ROWID TASK (cr=45349486 pr=686 pw=0 time=557636721 us)
161882244 INDEX RANGE SCAN IDX_TASK_LOCKEDBY (cr=1182825 pr=0 pw=0 time=326618838 us)(object id 105961)
0 TABLE ACCESS BY INDEX ROWID ORDEROUT (cr=2754 pr=3 pw=0 time=140659 us)
0 INDEX RANGE SCAN IDX_ORDEROUT_TASKID (cr=2754 pr=3 pw=0 time=106350 us)(object id 93131)




Tom Kyte
November 30, 2005 - 11:15 am UTC

this is a rather complex query plan without the query itself.

this is not a simple single table plan here. I don't really know what the predicates really are.

I can say at that outer layer of the plan like that - that index range scan in a nested loops join is being called over and over (the table joining to this one is invoking the range scan over and over).

Yes, having radically varying data in there can be an "issue".



RE: Index behavior I'm not sure I understand

Mark, November 30, 2005 - 12:32 pm UTC

Thanks for your input Tom. Below is the query itself - any useful info you could derive would be much appreciated. But if you also need create table/index statements and inserts, that'll be quite a large script - maybe I should go to Support at that point. :)

Thanks!

select at.name abstasktype,
count(*) || htmldb_item.hidden(4,r.regionid) ||
htmldb_item.hidden(6,tt.abstasktypeid) Orders,
r.county region,
da.absofficeid absoffice,
r.regionid,tt.abstasktypeid,r.stateid,
contemporary.pkg_lovr.saveregion(r.regionid) saveregion,
contemporary.pkg_lov.savetasktype(tt.abstasktypeid) savetasktype
from work.task t
inner join work.tasktype tt
on t.tasktypeid = tt.tasktypeid
inner join work.abstasktype at
on tt.abstasktypeid = at.abstasktypeid
inner join work.clientorder co
on t.clientorderid = co.clientorderid
inner join work.property p
on co.propertyid = p.propertyid
inner join location.city_zip_in_county czc
on p.cityid = czc.cityid
and p.zip = czc.zip
inner join location.v_region_ij_county r
on czc.countyid = r.countyid
inner join abstractor.defabs da
on r.regionid = da.regionid
and tt.abstasktypeid = da.abstasktypeid
inner join abstractor.absoffice ao
on da.absofficeid = ao.absofficeid
inner join abstractor.abscompany ac
on ao.abscompanyid = ac.abscompanyid
where taskid not in (select taskid from work.orderout where iscancelled=0)
and co.clientid = :p11_clientid
and lockedby = :p11_employeeid
and isdefault=1
and isapproved=1
and canceldate is NULL
and finisheddate is NULL
and (da.absofficeid, r.regionid) not in
(select absofficeid, regionid from abstractor.absDNU)
and da.absofficeid not in
(select absofficeid from abstractor.mv_inactiveabs)
group by at.name,r.county,da.absofficeid,r.regionid,tt.abstasktypeid,r.stateid order by 7,5;

Excessive rows used in range scan

Jonathan Lewis, November 30, 2005 - 1:29 pm UTC

Mark,

THe 161M rows in that index line is a combination of the driving nested loop (6,098 rows in line 4) and your comment that some users may updated a few tens of thousands of rows. Let one user update 27,000 rows, then the nested loop executes a range scan on 27,000 index entries 6,000 times for a total of 162,000,000 entries.

Your assumption is correct - the optimizer is getting confused by the volatility. It's current statistics probably tell it that there aren't many entries in the index, and that any one value will return only a few rows. (It's a little unusual for Oracle to use an index driven by a constant that late in a nested loop, rather than one that is driven by a join condition).

A possible generic solution is to include the dynamic sampling hint in the query, just for the one table:
/*+ dynamic_sampling (alias 1) */
This should at least get Oracle better stats about the table and its index when there are lots of marked rows.

There may be other strategies that would be more appropriate to address the query as a whole - but without taking some time to analyze the query I can't make any suggestions.


Thanks!

Mark, November 30, 2005 - 2:26 pm UTC

Thanks Jonathan, my questions are answered, and the dynamic sampling hint sounds very promising. I may have to pick up your book. :)

Mark

Dynamic Sampling.

Jonathan Lewis, December 01, 2005 - 2:59 am UTC

D'oh.

Dynamic Sampling won't help - it only takes place once on the hard parse (optimisation) stage, which means you'll fix the path (until it gets flushed from the library cache) at a **random** point in time, rather than fixing it for the most recently collected set of stats. (As Tom pointed out to me in a private e-mail).

Since the index is presumably useful for other queries, you can't really risk setting the statistics for that table/column/index in case it makes other queries do something silly. So the quick fix may simply be to put in a no_index() hint for that index (using the 10g syntax which allows you to describe the index rather than name it) - and check that this (a) helps when the number of marked rows is large, and (b) doesn't hurt when the number of marked rows is small.

The slower answer is to work out which other part of the query is producing the unsuitable cardinalities that makes the optimizer think this is ever a good index, and see if that issue can be addressed in a safe fashion.




Dynamic Sampling

Mark, December 02, 2005 - 11:40 am UTC

Thanks for the heads-up. I'll have to do some experimentation and see how it goes...

Mark

Bitmap Index

P.Karthick, December 05, 2005 - 8:37 am UTC

Iam new to bitmap index. When i went through oracle document i stuck up with this line..

"Each bit in the bitmap corresponds to a possible rowid. If the bit is set, then it means that the row with the corresponding rowid contains the key value."

For bitmap index it is said that row id is not stored. but i would like to know how each bit in a bitmap corrosponds to a row id how this relation between a bit in bitmap and a rowid is established.

tom can you show some example to create clarity to know how bitmap index is actually stored in database.

Thank you.

P.Karthick.

Tom Kyte
December 06, 2005 - 4:39 am UTC

</code> http://www.dbazine.com/oracle/or-articles/jlewis3 http://www.dbazine.com/oracle/or-articles/jlewis6 http://www.dbazine.com/oracle/or-articles/jlewis7 <code>

you'll want to read those.

As Jonathan wrote in the first paper:

...
In the bitmap index, every entry consists of a set of flags, a lock byte, and (in this case) four columns of data. The four columns are in fact the indexed value, a pair of rowids and a stream of bits. The pair of rowids identifies a contiguous section of the table, and the stream of bits is encoded to tell us which rows in that range of rowids hold that value.
.......


The trick with bitmaps is they take the pair of rowids (these cover some range of the table, the high-low rowid ranges) and the bitmaps together.

The rowid pair can be thought of two endpoints of a discrete set of rowids. If the i'th bit is "on" in the bitmap, they can figure out from the low/high rowid with the i'th rowid in that range is (it is just "math" at that point)

Why our responce is in bold

P.Karthick, December 05, 2005 - 8:38 am UTC


Tom Kyte
December 06, 2005 - 4:40 am UTC


#bbecause someone posted a 10053 trace that has a (hash-sign)B in it and my code turns (hash-sign)B into a bold tag and (hash-sign)b into a "no more bold" sign


Bitmap

karthick, December 08, 2005 - 10:35 am UTC

if i have a column and the values are like this..

a
b
a
b
a
b.. and so on

so here as a and b are inserted alternatively we cant have contigious block of data so is bit map index usefull in such cases or it dose some thing with this case also.

(and one more thing not relevent to this posting... while i was typing this question i wanted to see the previous follow up given by you so i hit cancel in this page it took me directly to home page. it would be better if it takes me to the follow up..)

Tom Kyte
December 08, 2005 - 11:58 am UTC

I don't know what you mean by "is bitmap index useful"


I cannot answer that, as I don't know what you do to do during data retrieval.




When NOT possible to rewrite the SQL

Suvendu, December 16, 2005 - 3:18 pm UTC

Hi Tom,

I have to tune a third party SQL statement, where I can't touch it to modify like adding HINTS. Here this query going for FTS where it is NOT using index at all taking more time on execution. But forcing the INDEX thru HINT is much more faster.
In this case I don't wants to create the materalised view on it as well as I read some document from metalink that enabling OUTLINE in session also degrades the performance where on each query execution on session, Oracle checks whether is there any PLAN STABILITY available for this query or not like so...

So, could you please, suggest me how to tune the query when not possible to touch the query?

Thanking you.

Regards,
Suvendu


bbg4@ORPMORP> SELECT SUM ("FACT_PM_PROMO".units_sold),
2 SUM ("FACT_PM_PROMO".baseline_units_sold),
SUM (((baseline_average_price) - (average_price)) * units_sold),
3 4 SUM (cents / 100), SUM (baseline_cents / 100),
5 "FACT_PM_PROMO".sku_key
FROM "FACT_PM_PROMO"
6 7 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
8 OR ("FACT_PM_PROMO".sku_key = 3114703)
OR ("FACT_PM_PROMO".sku_key = 3114710)
9 10 OR ("FACT_PM_PROMO".sku_key = 3114704)
11 OR ("FACT_PM_PROMO".sku_key = 3114711)
12 OR ("FACT_PM_PROMO".sku_key = 3114657)
13 OR ("FACT_PM_PROMO".sku_key = 3114664)
14 OR ("FACT_PM_PROMO".sku_key = 3114364)
)
15 16 GROUP BY "FACT_PM_PROMO".sku_key;

6 rows selected.

Elapsed: 00:00:43.25

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=14780 Card=8 Bytes=2
48)

1 0 SORT (GROUP BY) (Cost=14780 Card=8 Bytes=248)
2 1 PARTITION RANGE (ALL)
3 2 TABLE ACCESS (FULL) OF 'FACT_PM_PROMO' (Cost=9258 Card
=1821233 Bytes=56458223)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
96498 consistent gets
86498 physical reads
2632 redo size
1214 bytes sent via SQL*Net to client
655 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
6 rows processed

bbg4@ORPMORP>



bbg4@ORPMORP> SELECT /*+ index (FACT_PM_PROMO,FPP_BIDX_SKU)*/ SUM ("FACT_PM_PROMO".units_sold),
2 SUM ("FACT_PM_PROMO".baseline_units_sold),
SUM (((baseline_average_price) - (average_price)) * units_sold),
3 4 SUM (cents / 100), SUM (baseline_cents / 100),
5 "FACT_PM_PROMO".sku_key
FROM "FACT_PM_PROMO"
6 7 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
8 OR ("FACT_PM_PROMO".sku_key = 3114703)
9 OR ("FACT_PM_PROMO".sku_key = 3114710)
10 OR ("FACT_PM_PROMO".sku_key = 3114704)
11 OR ("FACT_PM_PROMO".sku_key = 3114711)
12 OR ("FACT_PM_PROMO".sku_key = 3114657)
OR ("FACT_PM_PROMO".sku_key = 3114664)
OR ("FACT_PM_PROMO".sku_key = 3114364)
13 14 15 )
16 GROUP BY "FACT_PM_PROMO".sku_key;

6 rows selected.

Elapsed: 00:00:00.60

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=179758 Card=8 Bytes=
248)

1 0 SORT (GROUP BY) (Cost=179758 Card=8 Bytes=248)
2 1 PARTITION RANGE (ALL)
3 2 INLIST ITERATOR
4 3 TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'FACT_PM_PROM
O' (Cost=174236 Card=1821233 Bytes=56458223)

5 4 INDEX (RANGE SCAN) OF 'FPP_BIDX_SKU' (NON-UNIQUE)
(Cost=4399 Card=1821233)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
11810 consistent gets
0 physical reads
2312 redo size
1214 bytes sent via SQL*Net to client
655 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
6 rows processed

bbg4@ORPMORP>



Tom Kyte
December 16, 2005 - 4:34 pm UTC

are the estimated cardinalities you see there even close to reality?

(i'm thinking "no, the card of 1,821,233 is way way off")



A little more....

Suvendu, December 16, 2005 - 8:25 pm UTC

Hi Tom,

Thanks a lot for your consideration to my query.

I wouldn't able to catch you exactly. Could you please, provide some more input on it?

Regards,
Suvendu

Tom Kyte
December 17, 2005 - 11:13 am UTC

the plan says:


0 SELECT STATEMENT Optimizer=CHOOSE (Cost=14780 Card=8 Bytes=2
48)

1 0 SORT (GROUP BY) (Cost=14780 Card=8 Bytes=248)
2 1 PARTITION RANGE (ALL)
3 2 TABLE ACCESS (FULL) OF 'FACT_PM_PROMO' (Cost=9258 Card
=1821233 Bytes=56458223)


it says "I shall get 1,821,233 records from the full scan"

My question to you: is that number even remotely accurate


No, it's different

Suvendu, December 17, 2005 - 8:32 pm UTC

Hi Tom,

No, it's different. Initially I was also thiking what you aske me now.

Thanking you.

Regards,
Suvendu

bbg4@ORPMORP> select table_name, num_rows, sample_size,last_analyzed from user_tables
2 where table_name='FACT_PM_PROMO';

TABLE_NAME NUM_ROWS SAMPLE_SIZE LAST_ANAL
------------------------------ ---------- ----------- ---------
FACT_PM_PROMO 13394434 23694 17-DEC-05

Elapsed: 00:00:00.15
bbg4@ORPMORP>


Tom Kyte
December 18, 2005 - 10:15 am UTC

no, not at all what I mean.

the optimizer is taking your query:

FROM "FACT_PM_PROMO"
6 7 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
8 OR ("FACT_PM_PROMO".sku_key = 3114703)
9 OR ("FACT_PM_PROMO".sku_key = 3114710)
10 OR ("FACT_PM_PROMO".sku_key = 3114704)
11 OR ("FACT_PM_PROMO".sku_key = 3114711)
12 OR ("FACT_PM_PROMO".sku_key = 3114657)
OR ("FACT_PM_PROMO".sku_key = 3114664)
OR ("FACT_PM_PROMO".sku_key = 3114364)
13 14 15 )
16 GROUP BY "FACT_PM_PROMO".sku_key;

6 rows selected.

Elapsed: 00:00:00.60

and based on that plan says:

3 2 TABLE ACCESS (FULL) OF 'FACT_PM_PROMO' (Cost=9258 Card
=1821233 Bytes=56458223)

I shall retrieve 1,821,233 rows using that OR'd condition

Is that number even remotely close - AFTER doing that where clause, is 1.8 million even remotely accurate.

and how do you gather statistics. precise command.

that is a tiny sample isn't it? 13 million records is pretty smallish/medium - you might up that a tad.



Another tuning problem

Puja, December 19, 2005 - 7:22 am UTC

Hi Tom,

I am running the following query.

SELECT 
COUNT(*) AS COUNT FROM 
    (  SELECT  ROWNUM AS RECNUM,  LOAN_ACCOUNT_ID,  ACCOUNT_NUMBER,  STATUS_DESC,  REGION_DESC,  CUST_NAME,  SSN,  BOARDING_DATE,  APPLICATION_ID  FROM 
        (  SELECT  * FROM 
            (  SELECT  LOAN_ACCOUNT.LOAN_ACCOUNT_ID LOAN_ACCOUNT_ID, ACCOUNT_NUMBER, STATUS_DESC, REGION_DESC,  FIRST_NAME || ' ' || LAST_NAME CUST_NAME, SSN, BOARDING_DATE, APPLICATION_ID  FROM  LOAN_ACCOUNT, LOAN_STATUS, LOAN_MSTR_STATUS, LOAN_MSTR_REGION,  DM_PARTY_INFO  
            WHERE  
            DM_PARTY_INFO.CATEGORY_ID = 0  AND 
            DM_PARTY_INFO.PARTY_TYPE_ID = 1 AND
            LOAN_MSTR_STATUS.STATUS_CATEGORY_ID IN (1,2)  AND 
            LOAN_ACCOUNT.LOAN_ACCOUNT_ID = LOAN_STATUS.LOAN_ACCOUNT_ID  AND 
            LOAN_STATUS.STATUS_ID = LOAN_MSTR_STATUS.STATUS_ID  AND 
            LOAN_MSTR_REGION.REGION_ID = LOAN_ACCOUNT.REGION_ID  AND 
            LOAN_ACCOUNT.LOAN_ACCOUNT_ID = DM_PARTY_INFO.LOAN_ACCOUNT_ID  
            ORDER BY  TO_CHAR(LOAN_ACCOUNT.ACCOUNT_NUMBER)  ) 
        )
            );


     COUNT
----------
     32939
     
There are indexes created on the tables involved (The details are appended below).
The query is taking a long time to execute (around 1 min), which is not acceptable.
If you see the plan, the indexes for LOAN_ACCOUNT, DM_PARTY_INFO And LOAN_MSTR_REGION are not used.
Is this the reason for the query running slow? If yes, then why are the indexes not being used? I am not able to point out the reason for index suppression in this case.

Please help me in finding out how to tune this query.





     
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=812 Card=1)
   1    0   SORT (AGGREGATE)
   2    1     VIEW (Cost=812 Card=31370)
   3    2       COUNT
   4    3         VIEW (Cost=812 Card=31370)
   5    4           SORT (ORDER BY) (Cost=812 Card=31370 Bytes=3137000
          )

   6    5             HASH JOIN (Cost=274 Card=31370 Bytes=3137000)
   7    6               TABLE ACCESS (FULL) OF 'DM_PARTY_INFO' (Cost=6
          7 Card=32939 Bytes=1350499)

   8    6               NESTED LOOPS (Cost=109 Card=31370 Bytes=185083
          0)

   9    8                 HASH JOIN (Cost=109 Card=439187 Bytes=232769
          11)

  10    9                   MERGE JOIN (CARTESIAN) (Cost=10 Card=53 By
          tes=1696)

  11   10                     TABLE ACCESS (FULL) OF 'LOAN_MSTR_REGION
          ' (Cost=2 Card=4 Bytes=36)

  12   10                     BUFFER (SORT) (Cost=8 Card=13 Bytes=299)
  13   12                       TABLE ACCESS (FULL) OF 'LOAN_MSTR_STAT
          US' (Cost=2 Card=13 Bytes=299)

  14    9                   TABLE ACCESS (FULL) OF 'LOAN_ACCOUNT' (Cos
          t=98 Card=32939 Bytes=691719)

  15    8                 INDEX (UNIQUE SCAN) OF 'LOAN_STATUS_AK2' (UN
          IQUE)





Statistics
----------------------------------------------------------
          7  recursive calls
          8  db block gets
     166407  consistent gets
       2892  physical reads
          0  redo size
        302  bytes sent via SQL*Net to client
        495  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          1  sorts (memory)
          1  sorts (disk)
          1  rows processed    
          
          
    
CREATE TABLE LOAN_ACCOUNT ( 
  LOAN_ACCOUNT_ID              NUMBER        NOT NULL, 
  ACCOUNT_NUMBER               NUMBER (20)   NOT NULL, 
  LOAN_TYPE_ID                 NUMBER        NOT NULL, 
  LOAN_CLASS_ID                NUMBER        NOT NULL, 
  ORIGINAL_AMOUNT_FINANCED     NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_FINANCE_CHARGE      NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  NOTE_DATE                    DATE          NOT NULL, 
  INTEREST_BEGIN_DATE          DATE          NOT NULL, 
  FIRST_PAYMENT_DATE           DATE          NOT NULL, 
  SERVICE_CONTRACT_AMT         NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  STATE_CODE_ID                NUMBER        NOT NULL, 
  LEAD_DAYS                    NUMBER (3)    NOT NULL, 
  REGION_ID                    NUMBER        NOT NULL, 
  APPLICATION_ID               VARCHAR2 (10)  NOT NULL, 
  LANGUAGE_ID                  NUMBER, 
  FUNDING_DATE                 DATE          NOT NULL, 
  BOARDING_DATE                DATE          NOT NULL, 
  FP_INS_ELIGIBILTY_FLAG       VARCHAR2 (1)  DEFAULT 'T' NOT NULL, 
  FP_INS_ELIGIBILITY_DATE      DATE          NOT NULL, 
  APPROVING_ANALYST            VARCHAR2 (50), 
  FUNDER                       VARCHAR2 (50)  NOT NULL, 
  MATURITY_ID                  NUMBER        NOT NULL, 
  LATE_CHARGE_ID               NUMBER        NOT NULL, 
  NSF_ID                       NUMBER        NOT NULL, 
  NOTICE_CODE                  VARCHAR2 (1)  DEFAULT 'Y' NOT NULL, 
  CONTRACT_TYPE                VARCHAR2 (50), 
  ORIG_CASH_SALE_PRICE         NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_DOWN_PAYMENT        NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_TRADE_IN_AMT        NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_NOTE_AMT            NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_LTV_PERCENT         NUMBER (5,2)  DEFAULT 0.00 NOT NULL, 
  ORIGINAL_SALES_REP           VARCHAR2 (50), 
  MATRIX_LOAN_CLASS_ID         NUMBER, 
  CREDIT_LIFE_PREMIUM_AMT      NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_DISABL_PREMIUM_AMT  NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  ORIGINAL_GAP_PREMIUM_AMT     NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  METRO2_ID                    NUMBER, 
  CONVERTED_STATUS             VARCHAR2 (1)  DEFAULT 'N' NOT NULL, 
  CONVERTED_DATE               DATE, 
  VERSION_NUMBER               NUMBER        NOT NULL, 
  CREATED_BY                   VARCHAR2 (20)  NOT NULL, 
  CREATED_DATE                 DATE          NOT NULL, 
  UPDATED_BY                   VARCHAR2 (20)  NOT NULL, 
  UPDATED_DATE                 DATE          NOT NULL, 
  MBI_PREMIUM_AMOUNT           NUMBER (11,2) DEFAULT 0.00 NOT NULL, 
  CONSTRAINT LOAN_ACCOUNT_I1
    UNIQUE (ACCOUNT_NUMBER) , 
  CONSTRAINT PK_LOAN_ACCOUNT
  PRIMARY KEY ( LOAN_ACCOUNT_ID ) 
     )
   NOCACHE; 

CREATE INDEX LOAN_ACCOUNT_APPID_IDX1
 ON LOAN_ACCOUNT(APPLICATION_ID);
 
 CREATE UNIQUE INDEX LOAN_ACCOUNT_I1
  ON LOAN_ACCOUNT(ACCOUNT_NUMBER);
  
  CREATE UNIQUE INDEX PK_LOAN_ACCOUNT
   ON LOAN_ACCOUNT(LOAN_ACCOUNT_ID);
   
   
CREATE TABLE LOAN_STATUS ( 
  LOAN_STATUS_ID       NUMBER        NOT NULL, 
  LOAN_ACCOUNT_ID      NUMBER        NOT NULL, 
  STATUS_ID            NUMBER        NOT NULL, 
  STATUS_DATE          DATE          NOT NULL, 
  VERSION_NUMBER       NUMBER        NOT NULL, 
  CREATED_BY           VARCHAR2 (20)  NOT NULL, 
  CREATED_DATE         DATE          NOT NULL, 
  UPDATED_BY           VARCHAR2 (20)  NOT NULL, 
  UPDATED_DATE         DATE          NOT NULL, 
  IS_STATUS_PERMENANT  CHAR (1)      DEFAULT 'N' NOT NULL, 
  EFFECTIVE_DATE       DATE, 
  END_DATE             DATE, 
   CONSTRAINT CKC_IS_STATUS_PRMT_LOAN_STS
          CHECK (IS_STATUS_PERMENANT IN ('Y','N')) , 
  CONSTRAINT LOAN_STATUS_AK2
    UNIQUE (LOAN_ACCOUNT_ID, STATUS_ID) , 
  CONSTRAINT PK_LOAN_STATUS
  PRIMARY KEY ( LOAN_STATUS_ID ) 
     )
   NOCACHE; 
   
CREATE UNIQUE INDEX LOAN_STATUS_AK2
 ON LOAN_STATUS(LOAN_ACCOUNT_ID, STATUS_ID);
 
 CREATE UNIQUE INDEX LOAN_STATUS_AK2
  ON LOAN_STATUS(LOAN_ACCOUNT_ID, STATUS_ID);
  
  CREATE INDEX LOAN_STATUS_LOANACCTID_IDX1
   ON LOAN_STATUS(LOAN_ACCOUNT_ID);
   
   CREATE UNIQUE INDEX PK_LOAN_STATUS
    ON LOAN_STATUS(LOAN_STATUS_ID);
    
    
 CREATE TABLE LOAN_MSTR_REGION ( 
   REGION_ID           NUMBER        NOT NULL, 
   REGION_DESC         VARCHAR2 (30)  NOT NULL, 
   PRESENTATION_ORDER  NUMBER (5)    NOT NULL, 
   IS_ACTIVE           NUMBER (1)    NOT NULL, 
   VERSION_NUMBER      NUMBER        NOT NULL, 
   CREATED_BY          VARCHAR2 (20)  NOT NULL, 
   CREATED_DATE        DATE          NOT NULL, 
   UPDATED_BY          VARCHAR2 (20)  NOT NULL, 
   UPDATED_DATE        DATE          NOT NULL, 
   CONSTRAINT LOAN_MSTR_REGION_UQC
     UNIQUE (REGION_DESC), 
   CONSTRAINT PK_LOAN_MSTR_REGION
   PRIMARY KEY ( REGION_ID ) 
       )
    NOCACHE; 

CREATE UNIQUE INDEX LOAN_MSTR_REGION_UQC
 ON LOAN_MSTR_REGION(REGION_DESC);
 
 CREATE UNIQUE INDEX PK_LOAN_MSTR_REGION
  ON LOAN_MSTR_REGION(REGION_ID);
  
  

CREATE TABLE DM_PARTY_INFO ( 
  PARTY_ID                 NUMBER        NOT NULL, 
  LOAN_ACCOUNT_ID          NUMBER        NOT NULL, 
  PARTY_TYPE_ID            NUMBER        NOT NULL, 
  FIRST_NAME               VARCHAR2 (30), 
  MIDDLE_NAME              VARCHAR2 (30), 
  LAST_NAME                VARCHAR2 (30), 
  SUFFIX_ID                NUMBER, 
  SSN                      VARCHAR2 (9), 
  AGE                      NUMBER (3), 
  EMAIL                    VARCHAR2 (50), 
  RESIDENCE_STATUS_ID      NUMBER, 
  YEARS_AT_RESIDENCE       NUMBER (3), 
  YEARS_AT_JOB             NUMBER (3), 
  DRIVER_LICENSE_NO        VARCHAR2 (20), 
  DRIVER_LICENSE_STATE_ID  NUMBER, 
  PRIVACY_FLAG             VARCHAR2 (1)  DEFAULT 'N', 
  MONTHLTY_INCOME          NUMBER (9,2)  DEFAULT 0.00, 
  MONTHLY_DEBT             NUMBER (9,2)  DEFAULT 0.00, 
  ORIGINAL_DTI_PERCENT     NUMBER (5,2)  DEFAULT 0.00, 
  ORIGINAL_PTI_PERCENT     NUMBER (5,2)  DEFAULT 0.00, 
  VERSION_NUMBER           NUMBER        NOT NULL, 
  CREATED_DATE             DATE          NOT NULL, 
  CREATED_BY               VARCHAR2 (20)  NOT NULL, 
  UPDATED_DATE             DATE          NOT NULL, 
  UPDATED_BY               VARCHAR2 (20)  NOT NULL, 
  COMMENTS                 VARCHAR2 (450), 
  CATEGORY_ID              NUMBER        DEFAULT 0 NOT NULL, 
  CONSTRAINT PK_DM_CONTRACT_PARTY
  PRIMARY KEY ( PARTY_ID )
 )
   NOCACHE; 
   
   
   CREATE INDEX DM_PARTY_INFO_CATID_IDX1
    ON DM_PARTY_INFO(CATEGORY_ID);
    
    CREATE INDEX DM_PARTY_INFO_FIRSTNAME_IDX1
     ON DM_PARTY_INFO (LOWER("FIRST_NAME"));
     
     CREATE INDEX DM_PARTY_INFO_FIRSTNAME_IDX2
      ON DM_PARTY_INFO(FIRST_NAME);
      
      CREATE INDEX DM_PARTY_INFO_LASTNAME_IDX1
       ON DM_PARTY_INFO (LOWER("LAST_NAME"));
       
       CREATE INDEX DM_PARTY_INFO_LASTNAME_IDX2
        ON DM_PARTY_INFO(LAST_NAME);
        
        CREATE INDEX DM_PARTY_INFO_LOANACCTID_IDX1
     ON DM_PARTY_INFO(LOAN_ACCOUNT_ID);
     
     CREATE INDEX DM_PARTY_INFO_PRTYTYPEID_IDX1
      ON DM_PARTY_INFO(PARTY_TYPE_ID);
      
      CREATE INDEX DM_PARTY_INFO_SSN_IDX1
       ON DM_PARTY_INFO(SSN);
       
       CREATE UNIQUE INDEX PK_DM_CONTRACT_PARTY
        ON DM_PARTY_INFO(PARTY_ID);
        
CREATE TABLE LOAN_MSTR_STATUS ( 
  STATUS_ID                       NUMBER        NOT NULL, 
  STATUS_CODE                     VARCHAR2 (25)  NOT NULL, 
  STATUS_DESC                     VARCHAR2 (30)  NOT NULL, 
  STATUS_CATEGORY_ID              NUMBER        NOT NULL, 
  SUSPEND_STATEMENT_FLAG          VARCHAR2 (1)  NOT NULL, 
  SUSPEND_LATE_CHARGE_FLAG        VARCHAR2 (1)  NOT NULL, 
  SUSPEND_CREDIT_BUREAU_RPT_FLAG  VARCHAR2 (1)  NOT NULL, 
  NET_DELINQUENCY_FLAG            VARCHAR2 (1)  NOT NULL, 
  SUSPEND_INT_ACCRUAL_FLAG        VARCHAR2 (1)  NOT NULL, 
  BLOCK_PAYMENT_FLAG              VARCHAR2 (1)  NOT NULL, 
  AUTO_DEFER_FLAG                 VARCHAR2 (1)  NOT NULL, 
  EFFECTIVE_DATE                  DATE          NOT NULL, 
  PRESENTATION_ORDER              NUMBER (5)    NOT NULL, 
  IS_ACTIVE                       NUMBER (1)    NOT NULL, 
  VERSION_NUMBER                  NUMBER        NOT NULL, 
  CREATED_BY                      VARCHAR2 (20)  NOT NULL, 
  CREATED_DATE                    DATE          NOT NULL, 
  UPDATED_BY                      VARCHAR2 (20)  NOT NULL, 
  UPDATED_DATE                    DATE          NOT NULL, 
  CONSTRAINT LOAN_MSTR_STATUS_CODE_AK
    UNIQUE (STATUS_CODE), 
  CONSTRAINT PK_LOAN_MSTR_STATUS
  PRIMARY KEY ( STATUS_ID ) 
 )
   NOCACHE;         

     CREATE UNIQUE INDEX LOAN_MSTR_STATUS_CODE_AK
      ON LOAN_MSTR_STATUS(STATUS_CODE);
      
      CREATE UNIQUE INDEX PK_LOAN_MSTR_STATUS
       ON LOAN_MSTR_STATUS(STATUS_ID);


SQL> SELECT COUNT(*) FROM LOAN_ACCOUNT;

  COUNT(*)
----------
     32939
SQL> SELECT COUNT(*) FROM LOAN_STATUS;

  COUNT(*)
----------
     32945
 
SQL> SELECT COUNT(*) FROM LOAN_MSTR_REGION;

  COUNT(*)
----------
         4

SQL> SELECT COUNT(*) FROM DM_PARTY_INFO;

  COUNT(*)
----------
     32939
     

           
   

 

Tom Kyte
December 19, 2005 - 7:46 am UTC

well, unless you are planning on doing a count(*) (in which case - hey, lets lose the rownum and order by!!!) don't TEST with count(*)

when we see count(*) we can and do skip things - so, don't test with count(*) it is misleading at best. use set autotrace traceonly if you don't want the output, but run the *real* query.

Look at your query:


FROM LOAN_ACCOUNT, LOAN_STATUS, LOAN_MSTR_STATUS,
LOAN_MSTR_REGION, DM_PARTY_INFO
WHERE DM_PARTY_INFO.CATEGORY_ID = 0
AND DM_PARTY_INFO.PARTY_TYPE_ID = 1
AND LOAN_MSTR_STATUS.STATUS_CATEGORY_ID IN (1,2)

AND
LOAN_ACCOUNT.LOAN_ACCOUNT_ID = LOAN_STATUS.LOAN_ACCOUNT_ID AND
LOAN_STATUS.STATUS_ID = LOAN_MSTR_STATUS.STATUS_ID AND
LOAN_MSTR_REGION.REGION_ID = LOAN_ACCOUNT.REGION_ID AND
LOAN_ACCOUNT.LOAN_ACCOUNT_ID = DM_PARTY_INFO.LOAN_ACCOUNT_ID
ORDER BY TO_CHAR(LOAN_ACCOUNT.ACCOUNT_NUMBER)


Only the bit in bold could use an index to start driving the query.

Now, loan_mstr_status.STATUS_CATEGORY_ID has no index.


I see that dm_party_info.CATEGORY_ID does - but is it selective? how many 0's do you have in that table out of how many rows.

I see that there is another separate index on party_type_id, but (same questions... is it selective, how many 1's in there...)


and this is really taking a minute? on such teeny tiny data? Where is your tkprof (with the row source operation component - the real plan used with the real row counts)

Version

Puja, December 19, 2005 - 7:23 am UTC

Added to the response above:

SQL> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle9i Enterprise Edition Release 9.2.0.6.0 - Production
PL/SQL Release 9.2.0.6.0 - Production
CORE    9.2.0.6.0       Production
TNS for 32-bit Windows: Version 9.2.0.6.0 - Production
NLSRTL Version 9.2.0.6.0 - Production
 

Continuing existing thread prior to above one...

Suvendu, December 20, 2005 - 8:56 am UTC

Hi Tom,
Above reader interrupted to my initial thread. Hope I'm not going to interrupt her. :-)

I'm placing here all detail information relating to query earlier I posted. And look forward your kind consideration on it. And now I recollect the statistics where NUM_ROWS and SAMPLE_SIZE both are pointing same value.

Thanking you a lot for time and such kind help.

Regards,
Suvendu


bbg4@ORPMORP> exec dbms_stats.gather_table_stats(user,'FACT_PM_PROMO',degree=>8,cascade=>true);

PL/SQL procedure successfully completed.

Elapsed: 00:10:42.29
bbg4@ORPMORP> select table_name, num_rows, sample_size, last_analyzed from user_tables
where table_name='FACT_PM_PROMO'; 2

TABLE_NAME NUM_ROWS SAMPLE_SIZE LAST_ANAL
------------------------------ ---------- ----------- ---------
FACT_PM_PROMO 13680014 13680014 20-DEC-05

Elapsed: 00:00:00.01

bbg4@ORPMORP> select column_name, data_type, num_distinct, last_analyzed from user_tab_columns
2 where table_name='FACT_PM_PROMO';

COLUMN_NAME DATA_TYPE NUM_DISTINCT LAST_ANALYZED
------------------------------ --------------- ------------ --------------------
MANUFACTURER_KEY NUMBER 1 20-DEC-05
BRAND_KEY NUMBER 4 20-DEC-05
SUBBRAND_KEY NUMBER 6 20-DEC-05
SKU_KEY NUMBER 59 20-DEC-05
RMA_KEY NUMBER 46 20-DEC-05
PARENT_CHAIN_KEY NUMBER 3 20-DEC-05
STATE VARCHAR2 48 20-DEC-05
ZIPCODE VARCHAR2 4937 20-DEC-05
STORE_KEY NUMBER 8221 20-DEC-05
DAY_KEY NUMBER 244 20-DEC-05
DAY_OF_WEEK_KEY NUMBER 7 20-DEC-05
WEEK_KEY NUMBER 36 20-DEC-05
CAUSAL_KEY NUMBER 2 20-DEC-05
OOS_KEY NUMBER 6 20-DEC-05
COMPLIANCE_KEY NUMBER 4 20-DEC-05
CENTS NUMBER 11801 20-DEC-05
UNITS_SOLD NUMBER 144 20-DEC-05
AVERAGE_PRICE NUMBER 2176 20-DEC-05
BASELINE_CENTS NUMBER 478689 20-DEC-05
BASELINE_UNITS_SOLD NUMBER 5667 20-DEC-05
BASELINE_AVERAGE_PRICE NUMBER 5487 20-DEC-05
EXPECTED_CENTS NUMBER 22419 20-DEC-05
EXPECTED_UNITS_SOLD NUMBER 7581 20-DEC-05
EXPECTED_AVERAGE_PRICE NUMBER 2176 20-DEC-05
IMPUTED_FLAG VARCHAR2 1 20-DEC-05
UNIT_PROBABILITY_FACTOR NUMBER 10001 20-DEC-05

26 rows selected.

Elapsed: 00:00:00.00
bbg4@ORPMORP>
bbg4@ORPMORP> select index_name,column_name from user_ind_columns where table_name='FACT_PM_PROMO';

INDEX_NAME COLUMN_NAME
------------------------------ ------------------------------
PK_FACT_PM_PROMO SKU_KEY
PK_FACT_PM_PROMO STORE_KEY
PK_FACT_PM_PROMO DAY_KEY
FPP_BIDX_BRAND BRAND_KEY
FPP_BIDX_CAUSAL CAUSAL_KEY
FPP_BIDX_COMPLIANCE COMPLIANCE_KEY
FPP_BIDX_DAY DAY_KEY
FPP_BIDX_DOW_KEY DAY_OF_WEEK_KEY
FPP_BIDX_MANU MANUFACTURER_KEY
FPP_BIDX_OOS OOS_KEY
FPP_BIDX_PARENT PARENT_CHAIN_KEY
FPP_BIDX_RMA RMA_KEY
FPP_BIDX_STATE STATE
FPP_BIDX_STORE STORE_KEY
FPP_BIDX_SUBBRAND SUBBRAND_KEY
FPP_BIDX_WEEK WEEK_KEY
FPP_BIDX_ZIP ZIPCODE
FPP_BIDX_SKU SKU_KEY

18 rows selected.

Elapsed: 00:00:00.02
bbg4@ORPMORP>
bbg4@ORPMORP> SELECT SUM ("FACT_PM_PROMO".units_sold),
2 SUM ("FACT_PM_PROMO".baseline_units_sold),
3 SUM (((baseline_average_price) - (average_price)) * units_sold),
SUM (cents / 100), SUM (baseline_cents / 100),
4 5 "FACT_PM_PROMO".sku_key
6 FROM "FACT_PM_PROMO"
7 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
8 OR ("FACT_PM_PROMO".sku_key = 3114703)
9 OR ("FACT_PM_PROMO".sku_key = 3114710)
10 OR ("FACT_PM_PROMO".sku_key = 3114704)
11 OR ("FACT_PM_PROMO".sku_key = 3114711)
12 OR ("FACT_PM_PROMO".sku_key = 3114657)
13 OR ("FACT_PM_PROMO".sku_key = 3114664)
14 OR ("FACT_PM_PROMO".sku_key = 3114364)
15 )
GROUP BY "FACT_PM_PROMO".sku_key; 16

6 rows selected.

Elapsed: 00:00:20.97

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=15256 Card=8 Bytes=2
48)

1 0 SORT (GROUP BY) (Cost=15256 Card=8 Bytes=248)
2 1 PARTITION RANGE (ALL)
3 2 TABLE ACCESS (FULL) OF 'FACT_PM_PROMO' (Cost=9641 Card
=1854917 Bytes=57502427)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
100484 consistent gets
89974 physical reads
2632 redo size
1214 bytes sent via SQL*Net to client
655 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
6 rows processed

bbg4@ORPMORP>
bbg4@ORPMORP> SELECT /*+ index (FACT_PM_PROMO,FPP_BIDX_SKU)*/
2 SUM ("FACT_PM_PROMO".units_sold),
3 SUM ("FACT_PM_PROMO".baseline_units_sold),
4 SUM (((baseline_average_price) - (average_price)) * units_sold),
SUM (cents / 100), SUM (baseline_cents / 100),
5 6 "FACT_PM_PROMO".sku_key
7 FROM "FACT_PM_PROMO"
8 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
9 OR ("FACT_PM_PROMO".sku_key = 3114703)
10 OR ("FACT_PM_PROMO".sku_key = 3114710)
11 OR ("FACT_PM_PROMO".sku_key = 3114704)
12 OR ("FACT_PM_PROMO".sku_key = 3114711)
13 OR ("FACT_PM_PROMO".sku_key = 3114657)
14 OR ("FACT_PM_PROMO".sku_key = 3114664)
15 OR ("FACT_PM_PROMO".sku_key = 3114364)
16 )
17 GROUP BY "FACT_PM_PROMO".sku_key;

6 rows selected.

Elapsed: 00:00:00.66

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=197234 Card=8 Bytes=
248)

1 0 SORT (GROUP BY) (Cost=197234 Card=8 Bytes=248)
2 1 PARTITION RANGE (ALL)
3 2 INLIST ITERATOR
4 3 TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'FACT_PM_PROM
O' (Cost=191619 Card=1854917 Bytes=57502427)

5 4 INDEX (RANGE SCAN) OF 'FPP_BIDX_SKU' (NON-UNIQUE)
(Cost=4486 Card=1854917)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
14358 consistent gets
0 physical reads
2312 redo size
1214 bytes sent via SQL*Net to client
655 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
6 rows processed

bbg4@ORPMORP>


Tom Kyte
December 20, 2005 - 9:48 am UTC

all I really needed was "yes or no"


IS the plans estimated cardinality of 1.8 millino rows EVEN CLOSE to reality.



No...

Suvendu, December 20, 2005 - 12:23 pm UTC

Hi Tom,

No, Index SCAN and FTS cardinality is not same as NUM_ROWS in table, which I already provided to you. Please, provide some input on it where most of queries in this status. Sure, your help will save me lot.


Regards,
Suvendu


INDEX (RANGE SCAN) OF 'FPP_BIDX_SKU' (NON-UNIQUE)
(Cost=4486 Card=1854917)

TABLE ACCESS (FULL) OF 'FACT_PM_PROMO' (Cost=9641 Card
=1854917 Bytes=57502427)

But,

bbg4@ORPMORP> select table_name, num_rows, sample_size, last_analyzed from user_tables
where table_name='FACT_PM_PROMO'; 2

TABLE_NAME NUM_ROWS SAMPLE_SIZE LAST_ANAL
------------------------------ ---------- ----------- ---------
FACT_PM_PROMO 13680014 13680014 20-DEC-05


Tom Kyte
December 20, 2005 - 1:03 pm UTC



I know that - what I'm trying to ask is:


given your predicate - the or'ed together stuff - would you expect that predicate to return 1,854,917 rows.

Ok, just do this:

select count(*)
7 FROM "FACT_PM_PROMO"
8 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
9 OR ("FACT_PM_PROMO".sku_key = 3114703)
10 OR ("FACT_PM_PROMO".sku_key = 3114710)
11 OR ("FACT_PM_PROMO".sku_key = 3114704)
12 OR ("FACT_PM_PROMO".sku_key = 3114711)
13 OR ("FACT_PM_PROMO".sku_key = 3114657)
14 OR ("FACT_PM_PROMO".sku_key = 3114664)
15 OR ("FACT_PM_PROMO".sku_key = 3114364)
16 )



No.. strange output...

Suvendu, December 20, 2005 - 1:19 pm UTC

Hi Tom,
Sorry, not to catch you properly. But here is the confuse output, please direct me to achive further.

Regards,
Suvendu


bbg4@ORPMORP> SELECT COUNT (*)
2 FROM "FACT_PM_PROMO"
3 WHERE ( ("FACT_PM_PROMO".sku_key = 3114673)
4 OR ("FACT_PM_PROMO".sku_key = 3114703)
OR ("FACT_PM_PROMO".sku_key = 3114710)
5 6 OR ("FACT_PM_PROMO".sku_key = 3114704)
7 OR ("FACT_PM_PROMO".sku_key = 3114711)
8 OR ("FACT_PM_PROMO".sku_key = 3114657)
9 OR ("FACT_PM_PROMO".sku_key = 3114664)
10 OR ("FACT_PM_PROMO".sku_key = 3114364)
11 )
12 ;

COUNT(*)
----------
71879

Elapsed: 00:00:11.59
bbg4@ORPMORP>


Tom Kyte
December 20, 2005 - 1:41 pm UTC

and what is your database version.

Version....

Suvendu, December 20, 2005 - 1:57 pm UTC

Hi Tom,
Here is info:


bbg4@ORPMORP> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle9i Enterprise Edition Release 9.2.0.6.0 - 64bit Production
PL/SQL Release 9.2.0.6.0 - Production
CORE 9.2.0.6.0 Production
TNS for HPUX: Version 9.2.0.6.0 - Production
NLSRTL Version 9.2.0.6.0 - Production

Elapsed: 00:00:00.16
bbg4@ORPMORP>


Tom Kyte
December 20, 2005 - 2:12 pm UTC

can you grab histograms on sku_key, is sku_key "skewed" perhaps?

Histograms info...

Suvendu, December 20, 2005 - 2:57 pm UTC

Hi Tom,

Here is SKU_KEY histogram info:

bbg4@ORPMORP> select * from USER_TAB_HISTOGRAMS
2 where table_name='FACT_PM_PROMO' and column_name='SKU_KEY';

TABLE_NAME COLUMN_NAM ENDPOINT_NUMBER ENDPOINT_VALUE ENDPOINT_A
-------------------- ---------- --------------- -------------- ----------
FACT_PM_PROMO SKU_KEY 0 1641852
FACT_PM_PROMO SKU_KEY 1 3114711

Elapsed: 00:00:00.01
bbg4@ORPMORP>



Tom Kyte
December 20, 2005 - 3:01 pm UTC

sorry was trying to say:

if sku_key is skewed as I think it might be, could you try adding some histograms on there.

The problem in a nutshell:

a) optimizer things 1.8 million rows
b) reality is 80k rows

we need to get optimizer to understand reality.

As asked..

Puja, December 21, 2005 - 5:11 am UTC

I cannot eliminate count(*) as this is the requirement. 

SQL> select count(DM_PARTY_INFO.CATEGORY_ID) from DM_PARTY_INFO where DM_PARTY_INFO.CATEGORY_ID=0;

COUNT(DM_PARTY_INFO.CATEGORY_ID)
--------------------------------
                           32939
                           
                           
                           
SQL> select count(DM_PARTY_INFO.PARTY_TYPE_ID) from DM_PARTY_INFO where DM_PARTY_INFO.PARTY_TYPE_ID=1;

COUNT(DM_PARTY_INFO.PARTY_TYPE_ID)
----------------------------------
                             32939
                             
                             

But I did get rid of the outer loop, and now my query looks like :


SELECT 
COUNT(CATEGORY_ID) AS COUNT FROM 
    (    SELECT  DM_PARTY_INFO.CATEGORY_ID FROM  LOAN_ACCOUNT, LOAN_STATUS, LOAN_MSTR_STATUS, LOAN_MSTR_REGION,  DM_PARTY_INFO
            WHERE
            DM_PARTY_INFO.CATEGORY_ID = 0  AND
            DM_PARTY_INFO.PARTY_TYPE_ID = 1 AND
            LOAN_MSTR_STATUS.STATUS_CATEGORY_ID IN (1,2)  AND
            LOAN_ACCOUNT.LOAN_ACCOUNT_ID = LOAN_STATUS.LOAN_ACCOUNT_ID  AND
            LOAN_STATUS.STATUS_ID = LOAN_MSTR_STATUS.STATUS_ID  AND
            LOAN_MSTR_REGION.REGION_ID = LOAN_ACCOUNT.REGION_ID  AND
            LOAN_ACCOUNT.LOAN_ACCOUNT_ID = DM_PARTY_INFO.LOAN_ACCOUNT_ID
             )     
             
             
    I checked out the tkprof for this session, but it has only stats$ related information (I was taking statspack.snaps at that time)         
 

in need of some ideas

Mita, December 22, 2005 - 2:39 pm UTC

I have following tables

table : sec
(sec_id number
ticker varchar2(10),
cusip varchar2(9),
asset_class varchar2(2),
sec_name varchar2(100))

table : acct
(acct_no varchar2(9),
acct_name varchar2(200),
cust_no varchar2(9),
objective varchar2(100)
pm_no varchar2(10))

table : trade
(acct_no varchar2(9), --> referenced to acct
trade_date date,
sec_id number, --> referenced to sec
trade_type varchar2(3),
qty number,
cost number)

I have a report which queries data in above tables for different parameters.

mandatory parameters

start_trade_Date
end_trade_date
trade_type

optional parameters
acct_no --> any text
Pm_no --> can be selected from given values
Objective --> can be selected from given values
ticker --> any text
asset_type --> can be selected from given values

result :
acct.acct_no, acct.acct_name,acct.objective, sec.sec_name, sec.asset_type, acct.pm_no, trade.trade_date, trade.qty, trade.cost

my query is something like

select acct.acct_no, acct.acct_name,acct.objective, sec.sec_name, sec.asset_type, acct.pm_no, trade.trade_date, trade.qty, trade.cost
from acct, sec, trade
where acct.acct_no = trade.acct_no
and sec.sec_id = trade.sec_id
and sec.ticker like nvl(:ticker,sec.ticker)
and sec.asset_class = nvl(:asset_class, sec.asset_class)
and acct.acct_no like nvl(:acct,acct.acct_no)
and acct.objective = nvl(:objective, acct.objective)
and acct.pm_no = nvl(:pm_no, acct.pm_no)
and trade.trade_date >= :trade_start_date
and trade.trade_date <= :trade_end_date
and trade.trans_cd = :trans_cd

No of records in each table

sec -- 150,000
acct -- 60,000
trade -- 25,000,000

the query is extremely slow right and Ideas I have suggest that, I should write different query for different scenarios. parameters to the queries are not going to change (no changes once its fixed).

what's your suggestion ??






Tom Kyte
December 22, 2005 - 5:22 pm UTC

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279 <code>

might be an approach to consider (some dynamic sql... with binds)

some mor einfo

Mita, December 22, 2005 - 6:18 pm UTC

I will try to implement that, but currently, we do not have any composite index. we have indexed on SEC_id, acct_no, trade_date in all the tables even in trade. what's the downside of creating index on acct_no, sec_id, trade_date in trade table for this kind of queries ??

Tom Kyte
December 22, 2005 - 6:35 pm UTC

one word:

benchmark


test it out, see what it buys you... (*test*)

any suggestions

Murali, January 04, 2006 - 10:05 pm UTC

Tom,

Thanks for your time, I went through the threads about histograms and tuning, Here is Issue i am still facing.

We have an Inventory table which is skewed, we gathered statistics using histograms on the column, the performance improved but not to an acceptable solution, when we run this sql in sqlplus window the response time is 13seconds however when it runs through the application forms, the sql takes 270 seconds,

SELECT 1 FROM MTL_SYSTEM_ITEMS_B IT WHERE ROWNUM = 1 AND NOT EXISTS (SELECT NULL FROM MTL_ITEM_CATEGORIES C WHERE C.CATEGORY_SET_ID = :B1 AND C.INVENTORY_ITEM_ID = IT.INVENTORY_ITEM_ID AND C.ORGANIZATION_ID = T.ORGANIZATION_ID)
call count cpu elapsed disk query current

rows
------- ------ -------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 0 0 0
Execute 26 0.01 0.00 0 0 0 0
Fetch 26 269.63 264.84 0 30047862 0 26
------- ------ -------- ---------- ---------- ---------- ----------
total 54 269.64 264.84 0 30047862 0 26

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 173 (APPS) (recursive depth: 2)
Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
0 COUNT (STOPKEY)
0 INDEX GOAL: ANALYZED (FULL SCAN) OF 'MTL_SYSTEM_ITEMS_B_U1' (UNIQUE)
0 INDEX GOAL: ANALYZED (RANGE SCAN) OF 'MTL_ITEM_CATEGORIES_U1' (UNIQUE)


Tom Kyte
January 05, 2006 - 10:21 am UTC

compare plans, are they the same in both environments.

I've a feeling that in sqlplus, you are *not* binding and in the application you are. Application gets "one plan" for all inputs.


sooo, what is "skewed", what column were you concerned with here.

and even more important - is that really the query???? "select 1"??????? What is the logic here - why do you need to know if there is a row in mtl_system_items that is not in mtl_item_categories - what is the "goal" of this query (it reminds me of all of the silly "select count(*) ..." queries to check for existence - when the application should just TRY TO PROCESS A RECORD and upon finding nothing to process - quit. Rather than "LOOK TO SEE IF WE HAVE SOMETHING TO PROCESS and then process"



Formation of Sql Query

A reader, January 10, 2006 - 8:04 am UTC

HI Tom,

Is there any possible Query that can be formed so that I can get only distinct rows for the rows shown below
For example :
For the query :

select rid,defid,acctid,aid from table1 where aid in
(654,655);

I get the following results :

rid defid acctid aid
=================================
38675 61 24 654
38792 61 24 654
38695 61 24 654
38676 61 24 655
38793 61 24 655
38696 61 24 655

Can you let me know the query to be executed so that I should only distinct "aid" values as shown below

rid defid acctid aid
===========================
38675 61 24 654
38676 61 24 655

Thanks for the same.



Tom Kyte
January 10, 2006 - 8:32 am UTC

tell us what values of rid, defid, acctid should be returned.

what 38675 for example, what was the "rule" you used to get that one.

good thread!

A reader, January 10, 2006 - 10:12 am UTC


Creating indexes slows performance of a query

A reader, January 10, 2006 - 8:13 pm UTC

Tom,

I am trying to tune a query, this query takes about 40 seconds to return the results and has a cost of 638.  
When I create a few indexes, check the cost and run the query, the cost goes down to 30, query execution time goes up to 900 seconds, and the explan plan looks quite different.  

Why is the cost going down and the execution time going up way high after creating the indexes?


Cost before index creation: 638
Time before index creation - 40 seconds

Cost after index creation: 30
Time after index creation - 900 seconds


Explain plan before index creation
-----------------------------------

SQL> set autotrace trace explain;
SQL> SELECT HD.HDOID S_ID,
  2         TO_CHAR(HDODATE) S_DATE,
  3         OT O_STATION,
  4         DESTT DESTINATION_STATION,
  5         SHIPPERID SHIPPER_ID,
  6         CONSIGNEEID CONSIGNEE_ID,
  7         BILL_TO_PARTY BILL_TO,
  8         STYPE
  9    FROM F_HDOHD HD
 10   WHERE HD.HB_NO IS NOT NULL AND NOT EXISTS
 11   (SELECT 'X'
 12            FROM F_HDOHD H
 13           WHERE HD.HB_NO = H.HB_NO AND H.DOUMENT_TYPE = 'D' AND
 14                 H.DESTT = 'MAA') AND EXISTS
 15   (SELECT 'X'
 16            FROM F_HDOHD H, F_RINVMAS I
 17           WHERE HD.HB_NO = H.HB_NO AND H.HB_NO = I.H_NO AND
 18                 I.IS_ACTIVE = 'Y' AND I.SMODE = 1) AND
 19         (HD.HDOID) LIKE '%%' AND
 20         (OT = 'MAA' OR DESTT = 'MAA')
 21   ORDER BY S_ID ASC;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=638 Card=1 Bytes=62)
   1    0   SORT (ORDER BY) (Cost=627 Card=1 Bytes=62)
   2    1     FILTER
   3    2       TABLE ACCESS (BY INDEX ROWID) OF 'F_HDOHD' (
          Cost=624 Card=1 Bytes=62)

   4    3         BITMAP CONVERSION (TO ROWIDS)
   5    4           BITMAP OR
   6    5             BITMAP CONVERSION (FROM ROWIDS)
   7    6               INDEX (RANGE SCAN) OF 'F_HDOHD_N6' (
          NON-UNIQUE) (Cost=5)

   8    5             BITMAP CONVERSION (FROM ROWIDS)
   9    8               INDEX (RANGE SCAN) OF 'F_HDOHD_N7' (
          NON-UNIQUE) (Cost=4)

  10    2       TABLE ACCESS (BY INDEX ROWID) OF 'F_HDOHD' (
          Cost=4 Card=1 Bytes=12)

  11   10         INDEX (RANGE SCAN) OF 'F_HDOHD_21' (NON-UN
          IQUE) (Cost=3 Card=1)

  12    2       NESTED LOOPS (Cost=7 Card=1 Bytes=17)
  13   12         TABLE ACCESS (BY INDEX ROWID) OF 'F_RINVMA
          STER' (Cost=5 Card=1 Bytes=11)

  14   13           INDEX (RANGE SCAN) OF 'F_RINVMAS_N6'
          (NON-UNIQUE) (Cost=3 Card=2)

  15   12         INDEX (RANGE SCAN) OF 'F_HDOHD_N4' (NON-UN
          IQUE) (Cost=2 Card=1 Bytes=6)






Indexes created
---------------

SQL> 
SQL> create index F_HDOHD_20 on F_HDOHD (HB_NO, HDOID, OT, DESTT);

Index created

SQL> create index F_RINVMAS_N11 on F_RINVMAS (IS_ACTIVE);

Index created

SQL> create index IND_F_RINVMAS_N2 on F_RINVMAS (H_NO, IS_ACTIVE);

Index created

SQL> create index IND_F_RINVMAS_N1 on F_RINVMAS (HDOID, IS_ACTIVE);

Index created

SQL> exec DBMS_STATS.GATHER_TABLE_STATS ('TQA', 'F_RINVMAS');

PL/SQL procedure successfully completed


Explain plan after index creation
---------------------------------

SQL> set autotrace trace explain;
SQL> SELECT HD.HDOID S_ID,
  2         TO_CHAR(HDODATE) S_DATE,
  3         OT O_STATION,
  4         DESTT DESTINATION_STATION,
  5         SHIPPERID SHIPPER_ID,
  6         CONSIGNEEID CONSIGNEE_ID,
  7         BILL_TO_PARTY BILL_TO,
  8         STYPE
  9    FROM F_HDOHD HD
 10   WHERE HD.HB_NO IS NOT NULL AND NOT EXISTS
 11   (SELECT 'X'
 12            FROM F_HDOHD H
 13           WHERE HD.HB_NO = H.HB_NO AND H.DOUMENT_TYPE = 'D' AND
 14                 H.DESTT = 'MAA') AND EXISTS
 15   (SELECT 'X'
 16            FROM F_HDOHD H, F_RINVMAS I
 17           WHERE HD.HB_NO = H.HB_NO AND H.HB_NO = I.H_NO AND
 18                 I.IS_ACTIVE = 'Y' AND I.SMODE = 1) AND
 19         (HD.HDOID) LIKE '%%' AND
 20         (OT = 'MAA' OR DESTT = 'MAA')
 21   ORDER BY S_ID ASC;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=30 Card=1 Bytes=62)
   1    0   SORT (ORDER BY) (Cost=30 Card=1 Bytes=62)
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'F_HDOHD' (Co
          st=27 Card=1 Bytes=62)

   3    2       INDEX (FULL SCAN) OF 'F_HDOHD_20' (NON-UNIQU
          E) (Cost=26 Card=69)

   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'F_HDOHD'
           (Cost=3 Card=1 Bytes=12)

   5    4           INDEX (RANGE SCAN) OF 'F_HDOHD_20' (NON-
          UNIQUE) (Cost=2 Card=1)

   6    3         NESTED LOOPS (Cost=3 Card=1 Bytes=17)
   7    6           TABLE ACCESS (BY INDEX ROWID) OF 'F_RINV
          MAS' (Cost=2 Card=1 Bytes=11)

   8    7             INDEX (RANGE SCAN) OF 'IND_F_RINVMASTE
          R_N2' (NON-UNIQUE) (Cost=1 Card=1)

   9    6           INDEX (RANGE SCAN) OF 'F_HDOHD_20' (NON-
          UNIQUE) (Cost=1 Card=1 Bytes=6)




SQL>
 

Tom Kyte
January 12, 2006 - 9:59 am UTC

are the card=1 values in the plan "correct" or near reality

the cost is driven by the card=values in large part (if you want the details - see my home page, get the book by Jonathan Lewis).


The cost is in part a function of the amount of IO the optimizer believes will be performed - adding the indexes made it believe "less IO"

If the query is taking hundreds of seconds - but the optimizer is showing cardinalities like the above - I'd guess that your statistics might be woefully out of date.

Formation of Sql Query

A reader, January 11, 2006 - 10:08 pm UTC

This is a follow up for youe Question

tell us what values of rid, defid, acctid should be returned.

rid defid acctid aid
=================================
38675 61 24 654
38792 61 24 654
38695 61 24 654
38676 61 24 655
38793 61 24 655
38696 61 24 655

Can you let me know the query to be executed so that I should only distinct
"aid" values as shown below

rid defid acctid aid
===========================
38675 61 24 654
38676 61 24 655



Any values rid, defid, acctid can be returned but aid values should be distinct.

Thanks for the same.



Tom Kyte
January 12, 2006 - 10:56 am UTC

then

select aid, max(rid), max(defid), max(acctid) from t group by aid;

sort of useless in my opinion - might as well select random numbers.

slow query

A reader, January 17, 2006 - 2:04 pm UTC

I am writing a query in a cursor

select address1, address2, city, state, zip , email, country
into ls_neweraddr1, ls_neweraddr2, ls_newercity, ll_newerstate, ls_newerzip, ls_neweremail, ls_country
from lwgnaddresshistory
where addressid = cur_lic.mlgaddrid
and historyid = (select max(historyid) from lwgnaddresshistory where addressid = cur_lic.mlgaddrid) ;

It is very slow

how can i make it fast.

Tom Kyte
January 17, 2006 - 4:20 pm UTC

select ....
from (select ....
from table
where addressid = :x
order by addressid desc, historyid desc)
where rownum = 1;

index on addressid, historyid.

it'll use the index to read the rows and stop after the very very first row.

"it is very slow" is about "as vague as you get"... no tables, no indexing scheme, no tkprof - not too much more can be said, this is a pure guess on my part.

MV

A reader, January 17, 2006 - 2:16 pm UTC

can i make materialized view on it. how?

Tom Kyte
January 17, 2006 - 4:24 pm UTC

that would not be "wise" for such a simple thing.

Tune SQL

Jorge, January 20, 2006 - 5:04 am UTC

Hi Tom,

I need tune this query but I can´t found thwe way to do this.

Mi query is "simple".
SELECT event_t.account_obj_db,
event_t.account_obj_id0,
event_t.account_obj_type,
event_t.account_obj_rev,
event_t.poid_db,
event_t.poid_id0,
event_t.poid_type,
event_t.poid_rev
FROM pin.event_billing_charge_t,pin.event_t
WHERE event_t.poid_id0 = event_billing_charge_t.obj_id0
AND event_billing_charge_t.obj_id0> :x
AND event_billing_charge_t.RESULT >= :y
AND event_billing_charge_t.bill_type = :z


Table event_t has about 160.000.000 rows and is partitioned by range on (CREATED_T, POID_ID0). Table event_billing_charge_t has about 1.600.000 rows and it is not partitioned.

About indexes, event_t has a index I1 on columns (ITEM_OBJ_ID0, POID_TYPE, POID_ID0) and other on column item_obj_id0.

Table event_billing_charge_t has a index on (OBJ_ID0, RESULT, BILL_TYPE).

Both tables have pctfree 10
pctused 40 as storage parameters.

My plain indicates this:

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=21127 Card=53460 Byt
es=4757940)

1 0 NESTED LOOPS (Cost=21127 Card=53460 Bytes=4757940)
2 1 PARTITION RANGE (ALL)
3 2 TABLE ACCESS (BY LOCAL INDEX ROWID) OF 'EVENT_T' (Cost
=10565 Card=1056175 Bytes=76044600)

4 3 INDEX (RANGE SCAN) OF 'I_EVENT__ID' (UNIQUE) (Cost=7
924 Card=1056175)

5 1 TABLE ACCESS (BY INDEX ROWID) OF 'EVENT_BILLING_CHARGE_T
' (Cost=2 Card=1 Bytes=17)

6 5 INDEX (UNIQUE SCAN) OF 'I_EVENT_BILLING_CHARGE__ID' (U
NIQUE)


I have not found another plain better than this one. Please Tom, could you tell may a way to optimize this query?.

Than you very much.







Tom Kyte
January 20, 2006 - 10:25 am UTC

you give no information as to what is slow about it, how about a tkprof and what sort of "expectations" about speed do you have. tkprof will show use the reality (rows actually processed), needed to compare to what is guessed to be processed.

A reader, January 20, 2006 - 9:44 am UTC

Hi tom,

Kindly clear my doubt.

we have a Database script for example , lets say , 500 create table statements , 500 index creations, 500 synonyms and 500 sequences.
as of now , the script is run in one session.if i split in 4 or more sessions.Does the elapsed time come down.
This is a very big script so i cannot past it.

In short ,what happens running a big script in one session Vs Running it in parallel multiple sessions.

Thanks in Advance

Tom Kyte
January 20, 2006 - 10:38 am UTC

it might go faster
it might go slower
it might go at the same speed


depends on the machine, the dependencies between the schema objects. In general, doing DDL is not something that scales very well.


Bottom line will be: benchmark it.

Query tuning

Jorge, January 23, 2006 - 4:24 am UTC

Tom, Thank you for your response. I forgot the Tkprof output. As you can see the optimizer method is FIRST ROWS. I was not who did this. The query takes about two hours and ten minutes to complete. As it is a very long time to us I don´t think I can launch it again with optimizer goal as CHOOSE. Please, with these results, could you please tell me a way to optimize the query?.

Thanks Tom!



SELECT event_t.account_obj_db, event_t.account_obj_id0,
event_t.account_obj_type, event_t.account_obj_rev, event_t.poid_db,
event_t.poid_id0, event_t.poid_type, event_t.poid_rev
FROM pin.event_t, pin.event_billing_charge_t
WHERE event_billing_charge_t.obj_id0 > :X
AND event_billing_charge_t.RESULT >= :Y
AND event_billing_charge_t.bill_type = :Z
AND event_t.poid_id0 = event_billing_charge_t.obj_id0

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.11 5.33 14 50 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 50136 345.57 4444.14 690041 27559727 0 752020
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 50138 345.68 4449.47 690055 27559777 0 752020

Misses in library cache during parse: 1
Optimizer goal: FIRST_ROWS
Parsing user id: 90

Rows Row Source Operation
------- ---------------------------------------------------
752020 NESTED LOOPS
8896404 PARTITION RANGE ALL PARTITION: 1 67
8896404 TABLE ACCESS BY LOCAL INDEX ROWID OBJ#(EVENT_T) PARTITION: 1 67
8896404 INDEX RANGE SCAN OBJ#(I_EVENT__ID) PARTITION: 1 67 (object id I_EVENT__ID)
752020 TABLE ACCESS BY INDEX ROWID OBJ#(EVENT_BILLING_CHARGE_T)
764972 INDEX UNIQUE SCAN OBJ#(I_EVENT_BILLING_CHARGE__ID) (object id I_EVENT_BILLING_CHARGE__ID)

Tom Kyte
January 23, 2006 - 10:14 am UTC

change optimizer mode??? if you want "all rows" as fast as possible, you have the wrong optimization goal. We'd probably really like to see a plan with no indexes being used.

I try this ...

Jorge, January 23, 2006 - 9:52 am UTC

Tom,

 I set the optimizer goal as CHOOSE an set autotrace traceonly explain statistics. In this case, customer gave me special values for the query and I got this using the parallel hint:

SQL> SELECT
  2      /*+ PARALLEL(EVENT_BILLING_CHARGE_T  8) */
  3         event_t.account_obj_db, event_t.account_obj_id0,
  4         event_t.account_obj_type, event_t.account_obj_rev, event_t.poid_db,
  5         event_t.poid_id0, event_t.poid_type, event_t.poid_rev
  6    FROM  pin.event_billing_charge_t, pin.event_t
  7   WHERE 
  8        --    event_billing_charge_t.obj_id0 > 230000241265963031
  9         event_t.poid_id0 > 230000241265963031
 10     AND 
 11            event_billing_charge_t.RESULT >= 0
 12     AND event_billing_charge_t.bill_type = 10005
 13     AND event_t.poid_id0 = event_billing_charge_t.obj_id0
 14  /

765582 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=11600 Card=53460 Byt
          es=4757940)

   1    0   TABLE ACCESS* (BY LOCAL INDEX ROWID) OF 'EVENT_T' (Cost=2  :Q106093
          Card=1 Bytes=72)                                             9000

   2    1     NESTED LOOPS* (Cost=11600 Card=53460 Bytes=4757940)      :Q106093
                                                                       9000

   3    2       TABLE ACCESS* (FULL) OF 'EVENT_BILLING_CHARGE_T' (Cost :Q106093
          =2911 Card=53460 Bytes=908820)                               9000

   4    2       PARTITION RANGE* (ALL)                                 :Q106093
                                                                       9000

   5    4         INDEX* (RANGE SCAN) OF 'I_EVENT__ID' (UNIQUE) (Cost= :Q106093
          129 Card=1)                                                  9000



   1 PARALLEL_COMBINED_WITH_CHILD
   2 PARALLEL_TO_SERIAL            SELECT /*+ ORDERED NO_EXPAND USE_NL(A2) INDE
                                   X(A2 "I_EVENT__ID") */ A1.C0,A2.ROWI

   3 PARALLEL_COMBINED_WITH_PARENT
   4 PARALLEL_COMBINED_WITH_PARENT
   5 PARALLEL_COMBINED_WITH_PARENT


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
  151608298  consistent gets
     232467  physical reads
          0  redo size
   29730505  bytes sent via SQL*Net to client
     562073  bytes received via SQL*Net from client
      51040  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
     765582  rows processed

 Is it more useful?

    Thank you Tom, again :)

 

Tom Kyte
January 23, 2006 - 10:41 am UTC

more useful than what?

jorge, January 23, 2006 - 11:57 am UTC

Tom,

I mean that it could be more userful for you. I have been making several test using hints but the only one that reduces the cost is the parallel. However our server only has one processor so the cost is not relevant ( I think this because I consider the explain plan believe I have N processors if I declare mi parallel hint with those N, perhaps I am wrong ...). Mi boss insists on sure there is a way to reduce the time of response and the cost but looking at the query and seeing the defined indexes and how the optimizer uses them, I think all is good if I consider the amount of data and that this query takes two hours.



Tom Kyte
January 23, 2006 - 12:54 pm UTC

do not try to just lower the cost, it isn't the goal. Let this go with all rows.

general tuning habits,

sns, January 27, 2006 - 1:08 pm UTC

When someone (probably a user or an application developer) asks the DBA to help in identifying any progress is made in their DML statements. What would you look in the database to give them an answer? Normally they call only when their statement is running longer than usual.

I would do the following:

If it is a DML statement then,

I first get the explain plan of the SQL statement.
I see any locks held by other session.
Observe v$filestat to see any IO is taking place (particularly on the file the table resides). Also see whether UNDO segments are growing.
Observe whether they are any parallel slaves working on the SQL statement.
If there is a sorting done, find out the activity in the temp space and the amount of CPU usage by issuing ‘top’ command on UNIX.
Look into the wait events for the SID.

What would you do?


If I start tracing the activities for that SID using dbms_system.set_sql_trace package, will it give the information of the session since when it started (say 2 hours ago)? If I want my tracing to continue on that session until the SQL completes what should we do?

Thanks,


followup,

sns, January 31, 2006 - 12:54 pm UTC

Did you had a chance to answer my previous question?

thanks,

SQL tuning

Puja, February 13, 2006 - 6:10 am UTC

Hi Tom,
I have a query that is using all the relevant indexes, and looks structurally fine to me (i.e. the explain plan seems to be ok). But there is a small doubt. When I check the tkprof, it shows me high values for cpu, elapsed, disk and query. Is there any way I can bring it down?

SELECT PP_VENDOR_POST.VENDOR_POST_ID VENDOR_POST_ID,
PP_VENDOR_POST.ACCOUNT_NUMBER ACCOUNT_NUMBER, PP_VENDOR_POST.AMOUNT AMOUNT,
PP_VENDOR_POST.EFFECTIVE_DATE EFFECTIVE_DATE, PP_VENDOR_POST.CHECK_NUMBER
CHECK_NUMBER, PP_VENDOR_POST.TRANS_CODE TRANS_CODE,
PP_VENDOR_POST.PAYMENT_CODE PAYMENT_CODE,
PP_VENDOR_POST.TRANS_DESCRIPTION_CODE TRANS_DESCRIPTION_CODE,
PP_VENDOR_ENTRY.FILE_NAME PAYMENT_SOURCE, PP_VENDOR_POST.NSF_FLAG NSF_FLAG,
PP_VENDOR_POST.COMMENT_1 COMMENT_1, PP_VENDOR_POST.COMMENT_2 COMMENT_2,
PP_VENDOR_POST.COMMENT_3 COMMENT_3, PP_VENDOR_ENTRY.GENISIS_ID GENISIS_ID,
COMMON_EXTERNAL_ENTITY.ENTITY_NAME VENDOR_DESC
FROM
PP_VENDOR_POST, PP_VENDOR_ENTRY, COMMON_EXTERNAL_ENTITY,
PP_MSTR_PAYMENT_TYPE
WHERE
PP_VENDOR_POST.VENDOR_ENTRY_ID = PP_VENDOR_ENTRY.VENDOR_ENTRY_ID AND
PP_VENDOR_ENTRY.VENDOR_ID = COMMON_EXTERNAL_ENTITY.ENTITY_ID AND
PP_VENDOR_POST.PAYMENT_CODE = PP_MSTR_PAYMENT_TYPE.PAYMENT_TYPE_ID AND
PP_VENDOR_POST.TO_BE_PROCESSED = 1 AND
PP_VENDOR_POST.EFFECTIVE_DATE <= ( select CURRENT_BUSINESS_DATE from common_business_date) AND
PP_VENDOR_POST.TRANS_CODE IN (100, 200, 523, 623)



call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 301 0.24 0.23 201 17234 0 3000
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 303 0.24 0.24 201 17234 0 3000

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer goal: ALL_ROWS
Parsing user id: 58 (LBAC_ONE) (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
3000 NESTED LOOPS (cr=17234 pr=201 pw=0 time=276865 us)
3000 NESTED LOOPS (cr=8234 pr=201 pw=0 time=180836 us)
3000 NESTED LOOPS (cr=2232 pr=201 pw=0 time=93830 us)
3000 TABLE ACCESS BY INDEX ROWID OBJ#(123165) (cr=1931 pr=201 pw=0 time=45822 us)
3000 INDEX RANGE SCAN OBJ#(123916) (cr=1188 pr=176 pw=0 time=24765 us)(object id 123916)
1 INDEX FULL SCAN OBJ#(122859) (cr=1 pr=0 pw=0 time=17 us)(object id 122859)
3000 INDEX UNIQUE SCAN OBJ#(123045) (cr=301 pr=0 pw=0 time=26573 us)(object id 123045)
3000 TABLE ACCESS BY INDEX ROWID OBJ#(123164) (cr=6002 pr=0 pw=0 time=67880 us)
3000 INDEX UNIQUE SCAN OBJ#(123285) (cr=3001 pr=0 pw=0 time=30439 us)(object id 123285)
3000 TABLE ACCESS BY INDEX ROWID OBJ#(123116) (cr=9000 pr=0 pw=0 time=66434 us)
3000 INDEX UNIQUE SCAN OBJ#(123237) (cr=6000 pr=0 pw=0 time=33662 us)(object id 123237)

unable to set optimizer goal
ORA-01986: OPTIMIZER_GOAL is obsolete

parse error offset: 33

Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: ALL_ROWS
3000 NESTED LOOPS
3000 NESTED LOOPS
3000 NESTED LOOPS
3000 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'PP_VENDOR_POST' (TABLE)
3000 INDEX GOAL: ANALYZED (RANGE SCAN) OF
'INDX_TO_BE_PROCESSED' (INDEX)
1 INDEX GOAL: ANALYZED (FULL SCAN) OF
'AK_COMMON_BUSINESS_DA_COMMON_B' (INDEX (UNIQUE))
3000 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF
'PK_PP_MSTR_PAYMENT_TYPE' (INDEX (UNIQUE))
3000 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'PP_VENDOR_ENTRY' (TABLE)
3000 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF
'PK_PP_VENDOR_ENTRY' (INDEX (UNIQUE))
3000 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF
'COMMON_EXTERNAL_ENTITY' (TABLE)
3000 INDEX GOAL: ANALYZED (UNIQUE SCAN) OF
'PK_COMMON_EXTERNAL_ENTITY' (INDEX (UNIQUE))



Number of rows in the tables

Table COUNT(*)
------------------------------ ----------
PP_VENDOR_POST 25748

Table COUNT(*)
------------------------------ ----------
PP_VENDOR_ENTRY 64

Table COUNT(*)
------------------------------ ----------
COMMON_EXTERNAL_ENTITY 1103

Table COUNT(*)
------------------------------ ----------
PP_MSTR_PAYMENT_TYPE 18

Tom Kyte
February 13, 2006 - 8:41 am UTC

well, it could be using too many indexes :)

got CBO?

CBO

Puja, February 13, 2006 - 10:26 pm UTC

yes, Tom..

It is using CBO.

SQL> SET AUTOTRACE ON
SQL> SELECT PP_VENDOR_POST.VENDOR_POST_ID VENDOR_POST_ID,
  2  PP_VENDOR_POST.ACCOUNT_NUMBER ACCOUNT_NUMBER,  PP_VENDOR_POST.AMOUNT AMOUNT,
  3  PP_VENDOR_POST.EFFECTIVE_DATE EFFECTIVE_DATE, PP_VENDOR_POST.CHECK_NUMBER
  4  CHECK_NUMBER,  PP_VENDOR_POST.TRANS_CODE TRANS_CODE,
  5  PP_VENDOR_POST.PAYMENT_CODE PAYMENT_CODE,
  6  PP_VENDOR_POST.TRANS_DESCRIPTION_CODE TRANS_DESCRIPTION_CODE,
  7  PP_VENDOR_ENTRY.FILE_NAME PAYMENT_SOURCE, PP_VENDOR_POST.NSF_FLAG NSF_FLAG,
  8  PP_VENDOR_POST.COMMENT_1 COMMENT_1, PP_VENDOR_POST.COMMENT_2 COMMENT_2,
  9  PP_VENDOR_POST.COMMENT_3 COMMENT_3,  PP_VENDOR_ENTRY.GENISIS_ID GENISIS_ID,
 10  COMMON_EXTERNAL_ENTITY.ENTITY_NAME VENDOR_DESC
 11  FROM
 12  PP_VENDOR_POST, PP_VENDOR_ENTRY, COMMON_EXTERNAL_ENTITY,
 13  PP_MSTR_PAYMENT_TYPE
 14  WHERE
 15  PP_VENDOR_POST.VENDOR_ENTRY_ID = PP_VENDOR_ENTRY.VENDOR_ENTRY_ID  AND
 16  PP_VENDOR_ENTRY.VENDOR_ID = COMMON_EXTERNAL_ENTITY.ENTITY_ID  AND
 17  PP_VENDOR_POST.PAYMENT_CODE = PP_MSTR_PAYMENT_TYPE.PAYMENT_TYPE_ID  AND
 18  PP_VENDOR_POST.TO_BE_PROCESSED = 1  AND
 19  PP_VENDOR_POST.EFFECTIVE_DATE <= ( select CURRENT_BUSINESS_DATE from
 20  common_business_date)  AND
 21  PP_VENDOR_POST.TRANS_CODE IN (100, 200, 523, 623)
 22
SQL> /

no rows selected


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=5 Card=1 Bytes=129
          )

   1    0   NESTED LOOPS (Cost=4 Card=1 Bytes=129)
   2    1     NESTED LOOPS (Cost=3 Card=1 Bytes=101)
   3    2       NESTED LOOPS (Cost=2 Card=1 Bytes=66)
   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'PP_VENDOR_POST' (T
          ABLE) (Cost=2 Card=1 Bytes=63)

   5    4           INDEX (RANGE SCAN) OF 'INDX_TO_BE_PROCESSED' (INDE
          X) (Cost=1 Card=1)

   6    4           INDEX (FULL SCAN) OF 'AK_COMMON_BUSINESS_DA_COMMON
          _B' (INDEX (UNIQUE)) (Cost=1 Card=1 Bytes=8)

   7    3         INDEX (UNIQUE SCAN) OF 'PK_PP_MSTR_PAYMENT_TYPE' (IN
          DEX (UNIQUE)) (Cost=0 Card=1 Bytes=3)

   8    2       TABLE ACCESS (BY INDEX ROWID) OF 'PP_VENDOR_ENTRY' (TA
          BLE) (Cost=1 Card=1 Bytes=35)

   9    8         INDEX (UNIQUE SCAN) OF 'PK_PP_VENDOR_ENTRY' (INDEX (
          UNIQUE)) (Cost=0 Card=1)

  10    1     TABLE ACCESS (BY INDEX ROWID) OF 'COMMON_EXTERNAL_ENTITY
          ' (TABLE) (Cost=1 Card=1 Bytes=28)

  11   10       INDEX (UNIQUE SCAN) OF 'PK_COMMON_EXTERNAL_ENTITY' (IN
          DEX (UNIQUE)) (Cost=0 Card=1)

 

Tom Kyte
February 14, 2006 - 7:45 am UTC

well, not having the schema makes it hard. It guessed "1 row" and got 3000. Can you see any obvious reason why this might be so. I don't know what indexes correspond to what tables, what colums

putting the same question again,

sns, February 14, 2006 - 10:20 am UTC

Tom,

Earlier I have asked a question in this thread which I think you didn't had time to look into that. I am posting the same question again.

*****************************************
When someone (probably a user or an application developer) asks the DBA to help
in identifying any progress is made in their DML statements. What would you
look in the database to give them an answer? Normally they call only when their
statement is running longer than usual.

I would do the following:

If it is a DML statement then,

I first get the explain plan of the SQL statement.
I see any locks held by other session.
Observe v$filestat to see any IO is taking place (particularly on the file the
table resides). Also see whether UNDO segments are growing.
Observe whether they are any parallel slaves working on the SQL statement.
If there is a sorting done, find out the activity in the temp space and the
amount of CPU usage by issuing ‘top’ command on UNIX.
Look into the wait events for the SID.

What would you do?


If I start tracing the activities for that SID using dbms_system.set_sql_trace
package, will it give the information of the session since when it started (say
2 hours ago)? If I want my tracing to continue on that session until the SQL
completes what should we do?

Thanks,

*****************************************



Stored Outlines

Anton, February 14, 2006 - 9:46 pm UTC

Hi Tom.

I have a sql statement in a 3rd party app that is not coded correctly and running very slow in Oracle 9.2. Unfortunately we cannot modify the sql so I was looking at using stored outlines.

I have created a stored outline for the slow sql and another for an improved version of the sql (modified one of the where conditions). I then swapped the hints over for the sqls so the slow sql has the improved sql hints and dropped the outline for the improved sql (which has the slow sql hints).

I set the use_stored_outlines to my category and do an explain plan on the slow sql and it comes back with the improved sql execution plan. All good so far.

I then run the slow sql and it takes ages (ie. no improvement). I check v$sql and the slow sql outline category is what I expect (ie. set to my outline category) and user_outlines shows that the outline has been used, but the slow sql is running just as slow as ever ?

Any ideas ?

Tom Kyte
February 15, 2006 - 8:37 am UTC

did you verify the plan you intended to have be used is in fact being used.

Stored outlines

Anton, February 15, 2006 - 3:01 pm UTC

Hi Tom.

An explain plan on the slow sql (set to use the improved sql outline) shows the improved sql plan is used, but when I run the slow sql it still takes ages, but if I run the improved sql it flys by. Everything looks good apart from the fact the slow sql doesn;t appear to be using the improved sql plan (even though explain plan/USER_OUTLINES.USED and V$sql.OUTLINE_CATEFORY says it is)

Tom Kyte
February 15, 2006 - 9:47 pm UTC

don't follow you - have you a tkprof showing this? tkprof show the actual plan used, not an explain plan which is "a guess as to what might be used if all things are held constant in the universe"

indexes and columns

Puja, February 15, 2006 - 10:14 pm UTC

SQL> SELECT PP_VENDOR_POST.VENDOR_POST_ID VENDOR_POST_ID,
  2  PP_VENDOR_POST.ACCOUNT_NUMBER ACCOUNT_NUMBER,  PP_VENDOR_POST.AMOUNT 
AMOUNT,
  3  PP_VENDOR_POST.EFFECTIVE_DATE EFFECTIVE_DATE, PP_VENDOR_POST.CHECK_NUMBER
  4  CHECK_NUMBER,  PP_VENDOR_POST.TRANS_CODE TRANS_CODE,
  5  PP_VENDOR_POST.PAYMENT_CODE PAYMENT_CODE,
  6  PP_VENDOR_POST.TRANS_DESCRIPTION_CODE TRANS_DESCRIPTION_CODE,
  7  PP_VENDOR_ENTRY.FILE_NAME PAYMENT_SOURCE, PP_VENDOR_POST.NSF_FLAG NSF_FLAG,
  8  PP_VENDOR_POST.COMMENT_1 COMMENT_1, PP_VENDOR_POST.COMMENT_2 COMMENT_2,
  9  PP_VENDOR_POST.COMMENT_3 COMMENT_3,  PP_VENDOR_ENTRY.GENISIS_ID GENISIS_ID,
 10  COMMON_EXTERNAL_ENTITY.ENTITY_NAME VENDOR_DESC
 11  FROM
 12  PP_VENDOR_POST, PP_VENDOR_ENTRY, COMMON_EXTERNAL_ENTITY,
 13  PP_MSTR_PAYMENT_TYPE
 14  WHERE
 15  PP_VENDOR_POST.VENDOR_ENTRY_ID = PP_VENDOR_ENTRY.VENDOR_ENTRY_ID  AND
 16  PP_VENDOR_ENTRY.VENDOR_ID = COMMON_EXTERNAL_ENTITY.ENTITY_ID  AND
 17  PP_VENDOR_POST.PAYMENT_CODE = PP_MSTR_PAYMENT_TYPE.PAYMENT_TYPE_ID  AND
 18  PP_VENDOR_POST.TO_BE_PROCESSED = 1  AND
 19  PP_VENDOR_POST.EFFECTIVE_DATE <= ( select CURRENT_BUSINESS_DATE from
 20  common_business_date)  AND
 21  PP_VENDOR_POST.TRANS_CODE IN (100, 200, 523, 623)
 22
SQL> /

no rows selected


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=5 Card=1 Bytes=129
          )

   1    0   NESTED LOOPS (Cost=4 Card=1 Bytes=129)
   2    1     NESTED LOOPS (Cost=3 Card=1 Bytes=101)
   3    2       NESTED LOOPS (Cost=2 Card=1 Bytes=66)
   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'PP_VENDOR_POST' (T
          ABLE) (Cost=2 Card=1 Bytes=63)

   5    4           INDEX (RANGE SCAN) OF 'INDX_TO_BE_PROCESSED' (INDE
          X) (Cost=1 Card=1)

   6    4           INDEX (FULL SCAN) OF 'AK_COMMON_BUSINESS_DA_COMMON
          _B' (INDEX (UNIQUE)) (Cost=1 Card=1 Bytes=8)

   7    3         INDEX (UNIQUE SCAN) OF 'PK_PP_MSTR_PAYMENT_TYPE' (IN
          DEX (UNIQUE)) (Cost=0 Card=1 Bytes=3)

   8    2       TABLE ACCESS (BY INDEX ROWID) OF 'PP_VENDOR_ENTRY' (TA
          BLE) (Cost=1 Card=1 Bytes=35)

   9    8         INDEX (UNIQUE SCAN) OF 'PK_PP_VENDOR_ENTRY' (INDEX (
          UNIQUE)) (Cost=0 Card=1)

  10    1     TABLE ACCESS (BY INDEX ROWID) OF 'COMMON_EXTERNAL_ENTITY
          ' (TABLE) (Cost=1 Card=1 Bytes=28)

  11   10       INDEX (UNIQUE SCAN) OF 'PK_COMMON_EXTERNAL_ENTITY' (IN
          DEX (UNIQUE)) (Cost=0 Card=1)

 


There are 5 tables in referred to in this query.
PP_VENDOR_POST,
PP_VENDOR_ENTRY,
COMMON_EXTERNAL_ENTITY,
PP_MSTR_PAYMENT_TYPE,
COMMON_BUSINESS_DATE


Here is the list of indexes associated with each table.


TABLE_NAME                     INDEX_NAME                     COLUMN_NAME
-------------------------- ------------------------------ ----------------------
1 COMMON_BUSINESS_DATE      AK_COMMON_BUSINESS_DA_COMMON_B CURRENT_BUSINESS_DATE


2 COMMON_EXTERNAL_ENTITY    PK_COMMON_EXTERNAL_ENTITY      ENTITY_ID
                    VENDOR_ID_CONSTRAINT           VENDOR_ID


3 PP_MSTR_PAYMENT_TYPE      PK_PP_MSTR_PAYMENT_TYPE        PAYMENT_TYPE_ID
                     PP_MSTR_PAYMENT_TYPE_UQC       PAYMENT_TYPE_DESC


4 PP_VENDOR_ENTRY           PK_PP_VENDOR_ENTRY             VENDOR_ENTRY_ID


5 PP_VENDOR_POST            PK_PP_VENDOR_POST              VENDOR_POST_ID
                      INDX_TO_BE_PROCESSED           TO_BE_PROCESSED

There is one more doubt.

The first step is 
a. INDEX (RANGE SCAN) OF 'INDX_TO_BE_PROCESSED' 
 
b. INDEX (FULL SCAN) OF 'AK_COMMON_BUSINESS_DA_COMMON_B'

As you can see, the index for the table COMMON_BUSINESS_DATE Is full scanned during the subquery:
select CURRENT_BUSINESS_DATE from common_business_date (line num 19 of the query pasted).
But why not full tablescan? This table has only 1 row in it.
SQL> select count(*) from common_business_date;

  COUNT(*)
----------
         1 

Tom Kyte
February 16, 2006 - 8:08 am UTC

if the table has one row in it the index is small as well, if the data we need is in the index, and we don't need to goto the table, why bother with the table (and why be concerned that we don't go to the table?)

My concern ....

Puja, February 17, 2006 - 12:16 am UTC

.... is not particularly about the index being used or not, it is more about the performance of the query.

I am just trying to analyze it step by step to understand how it is getting executed and whether I can do anything about increasing the performance.

Any suggestions on that?


Regards,

Puja

Tom Kyte
February 17, 2006 - 1:42 pm UTC

the performance of what exactly?

Performance...

Puja, February 19, 2006 - 12:34 pm UTC

.... of the query.

It is taking more time than is expected.This query is one of those executed when a web page (our application is web based) is executed.Hence, the expected time is less than 1 sec, specially because the tables involved are small in size and also the query doesnt involve a large number of joins.

Regards,

Puja

Tom Kyte
February 19, 2006 - 5:19 pm UTC

are the card= values in the plan even close to reality? if so, this query should fly.

If not, we need to figure out "why"

Tom, Could you please help me optimize these queries?

rich, February 21, 2006 - 3:19 pm UTC

Hi, Tom,

I have read most of you book but still need advice from you for the following query:
1)tables:
(1) Txn_process_status
INTERNAL_PROCESS_ID NOT NULL VARCHAR2(50)
PROCESS_TYPE NOT NULL VARCHAR2(20)
CORRELATION_ID VARCHAR2(50)
NECST_BILL_ID VARCHAR2(100)
LAST_PROCESS_STAGE VARCHAR2(40)
LAST_PROCESS_STATUS VARCHAR2(20)
INTERACTION_ID VARCHAR2(20)
PROCESS_START_DTE DATE
LAST_PROCESS_DTE DATE
COMPLETE_IND VARCHAR2(10)
BATCH_IND VARCHAR2(1)
INVOKE_CLIENT VARCHAR2(20)
ACTIVE_IND VARCHAR2(1)

primary key (INTERNAL_PROCESS_ID,PROCESS_TYPE),
indexed on each column:LAST_PROCESS_STATUS,PROCESS_START_DTE
(2) DENTAL_MSG
NAME Null? Type
------------------------------- --------- -----
INTERNAL_PROCESS_ID NOT NULL VARCHAR2(50)
PROCESS_TYPE NOT NULL VARCHAR2(20)
CARRIER_ID VARCHAR2(6)
OFFICE_NO VARCHAR2(4)
OFFICE_SEQ_NO VARCHAR2(6)
DENTIST_NO VARCHAR2(9)
DENTAL_MSG CLOB
CDA_VERSION VARCHAR2(10)
TXN_DATE DATE
CREATE_DATE DATE
TXN_TYPE VARCHAR2(2)
MSG_SRC VARCHAR2(10)
TXN_SEQ NUMBER

primary key (INTERNAL_PROCESS_ID,PROCESS_TYPE)and also foreign key reference to txn_process_status table,
indexed on each column:CARRIER_ID ,CREATE_DATE

data: both table have about less than 100,000 records now
My query:
select count(a.internal_process_id) from
TXN_PROCESS_STATUS a,dental_msg b
where b.CARRIER_ID='000102'
AND a.last_process_status='R'
and a.internal_process_id=b.internal_process_id
and a.process_type in ('FNL_RESPONSE','INIT_RESPONSE')
and a.PROCESS_START_DTE>TO_DATE('20/01/2006 00:00','dd/mm/yyyy HH24:MI')
and a.PROCESS_START_DTE<TO_DATE('21/02/2006 00:00','dd/mm/yyyy HH24:MI')

take over 800sec to finish

Tom Kyte
February 22, 2006 - 8:20 am UTC

sorry, if that is taking 800 seconds, you have something seriously wrong. I could do that on paper in less time.


how about a tkprof report showing us the information.

here's the similar one

rich, February 22, 2006 - 5:07 pm UTC

Thanks Tom for your response.
I use the following query generate the trace file and tkprof the report here from our QA env (the similar data amount as above):

1)query (this query takes about 15 sec to finish with result of 0:
select count(a.internal_process_id) as numOfReject
from TXN_PROCESS_STATUS a,dental_msg b
where a.last_process_status='R'
and a.internal_process_id=b.internal_process_id
and a.process_type in('INIT_RESPONSE','FNL_RESPONSE') and b.CARRIER_ID='900014'

2)tkprof report:


TKPROF: Release 9.2.0.1.0 - Production on Wed Feb 22 16:42:14 2006

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: ora9r2qa_ora_13654.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

alter session set SQL_TRACE=true


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.01 0.02 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.01 0.02 0 0 0 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 65
********************************************************************************

select count(a.internal_process_id) as numOfReject
from TXN_PROCESS_STATUS a,dental_msg b
where a.last_process_status=:"SYS_B_0"
and a.internal_process_id=b.internal_process_id
and a.process_type in(:"SYS_B_1",:"SYS_B_2") and b.CARRIER_ID=:"SYS_B_3"

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 16.24 15.86 0 160121 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 16.24 15.86 0 160121 0 1

Misses in library cache during parse: 1
Parsing user id: 65
********************************************************************************

select o.owner#,o.name,o.namespace,o.remoteowner,o.linkname,o.subname,
o.dataobj#,o.flags
from
obj$ o where o.obj#=:1


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 0.00 0.00 0 3 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 0.00 0.00 0 3 0 1

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS (recursive depth: 1)
********************************************************************************

alter session set SQL_TRACE=false


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.01 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.01 0.00 0 0 0 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 65



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3 0.00 0.00 0 0 0 0
Execute 3 0.02 0.03 0 0 0 0
Fetch 1 16.24 15.86 0 160121 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7 16.26 15.90 0 160121 0 1

Misses in library cache during parse: 2
Misses in library cache during execute: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 0.00 0.00 0 3 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 0.00 0.00 0 3 0 1

Misses in library cache during parse: 1

4 user SQL statements in session.
1 internal SQL statements in session.
5 SQL statements in session.
********************************************************************************
Trace file: ora9r2qa_ora_13654.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
4 user SQL statements in trace file.
1 internal SQL statements in trace file.
5 SQL statements in trace file.
4 unique SQL statements in trace file.
74 lines in trace file.


Thanks in advance for your analysis!!


Tom Kyte
February 22, 2006 - 5:35 pm UTC

where is the 800 second one?

here's the similar one

rich, February 23, 2006 - 12:05 pm UTC

Hi, Tom,

I have no chance to access the prod environment now, so the 800sec one report will be sent to you later.

here's another one which takes more than 600 sec to finish...
1) query:
select count(a.internal_process_id) as numOfAccept
from TXN_PROCESS_STATUS a,dental_msg b
where a.last_process_status ='A'
and a.internal_process_id=b.internal_process_id
and a.process_type in('INIT_RESPONSE','FNL_RESPONSE') and b.CARRIER_ID='900014'

2)tkprof report:

TKPROF: Release 9.2.0.1.0 - Production on Thu Feb 23 11:32:29 2006

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: ora9r2qa_ora_5101.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

ALTER SESSION SET sql_trace = TRUE


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 65
********************************************************************************

select count(a.internal_process_id) as numOfAccept
from TXN_PROCESS_STATUS a,dental_msg b
where a.last_process_status =:"SYS_B_0"
and a.internal_process_id=b.internal_process_id
and a.process_type in(:"SYS_B_1",:"SYS_B_2") and b.CARRIER_ID=:"SYS_B_3"

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 637.40 622.94 0 6474329 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 637.40 622.95 0 6474329 0 1

Misses in library cache during parse: 1
Parsing user id: 65
********************************************************************************

alter session set sql_trace=false


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.01 0.00 0 0 0 0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 65



********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3 0.01 0.00 0 0 0 0
Execute 3 0.00 0.00 0 0 0 0
Fetch 1 637.40 622.94 0 6474329 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7 637.41 622.95 0 6474329 0 1

Misses in library cache during parse: 2
Misses in library cache during execute: 1


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 0 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 0 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0

4 user SQL statements in session.
0 internal SQL statements in session.
4 SQL statements in session.
********************************************************************************
Trace file: ora9r2qa_ora_5101.trc
Trace file compatibility: 9.00.01
Sort options: default

1 session in tracefile.
4 user SQL statements in trace file.
0 internal SQL statements in trace file.
4 SQL statements in trace file.
3 unique SQL statements in trace file.
67 lines in trace file.


from the report, I saw the most cpu time was on "fetch" which took over 600 sec to fetch 6474329 buffers... does that mean our cpu resource is not good enough for it? but during the running process, I monitored from OEM for the CPU consumming, the user% is about 35~40%, still lots of percentage in idle time...

Can you explain this if I'm wrong?

Great thanks!

Tom Kyte
February 23, 2006 - 6:44 pm UTC

need the row source operation lines - cannot tell where the IO was taking place.

look at that query, seems like an UNREASONABLE amount of IO does it not?


set sql_trace=true
run query
EXIT SESSION

to trace this.

"OR" and "IN"

Kidd, February 27, 2006 - 11:21 pm UTC

Hello Tom,

I want to know if there is any difference in terms of performance for SQLs:

1. select * from tbl1 where field1 = 1 or field1 = 2 or field1 = 3

2. select * from tbl1 where field1 in (1,2,3)

And if it is not very good to have too many "(" ")" in a SQL?


Tom Kyte
February 28, 2006 - 7:10 am UTC

explain plan for select * from dual where dummy in ( 'a', 'b', 'c' )

Explained.


PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------
Plan hash value: 272002086

--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 2 | 2 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| DUAL | 1 | 2 | 2 (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("DUMMY"='a' OR "DUMMY"='b' OR "DUMMY"='c')

13 rows selected.


they are pretty much "exactly the same, only where in is easier for humans to type"


Use as many parenthesis as you need to make the sql understandable for you.

Query

A reader, March 10, 2006 - 7:19 am UTC

Tom,

Iam running the following query for a report. This query is taking more than 2 hours to fetch the data. There are 
around 5700000+ records in the s_user.claim table and around 14000000+ in claim_item table. None of the indexes are getting used. 

Can you please suggest a way to tune the first sql for better performance. 
Please see the usage of the indexes for the same sql (SQL 2 below) when the claim_id is passed. 
---- SQL 1 

  1         select f.fund_name,
  2               cl.claim_number,
  3               insured.ssn as ssn,
  4               patient.last_name as last_name,
  5               patient.first_name as first_name,
  6               patient.middle_name as middle_name,
  7               nvl(cl.updated_by, cl.inserted_by) updated_by,
  8               cm.user_description as memo_user_description,
  9               cl.claim_curr_status,
 10               p.provider_name,
 11               cim.claim_memo_id as claim_memo_id,
 12               cl.claim_id,
 13               s_user.f_get_claim_min_memo_date(cl.claim_id) AS memo_inserted_date,
 14               cl.claim_total_charge_amt,
 15               trunc(sysdate) - trunc(s_user.f_get_claim_min_memo_date(cl.claim_id)) AS pend_days
 16          from s_user.claim           cl,
 17               s_user.fund            f,
 18               s_user.claim_item      ci,
 19               s_user.claim_item_memo cim,
 20               s_user.claim_memo      cm,
 21               s_user.person          insured,
 22               s_user.person          patient,
 23               s_user.provider        p
 24         where cl.claim_id = ci.claim_id
 25           and f.fund_id = 1
 26           and cl.fund_id = f.fund_id
 27           and ci.claim_item_id = cim.claim_item_id
 28           and cim.claim_memo_id = cm.claim_memo_id
 29           and cl.insured_id = insured.person_id
 30           and cl.person_id = patient.person_id
 31           and p.provider_id = cl.service_provider_id
 32           and cm.calculate_action = 'P'
 33           and cim.disabled = 'N'
 34           UNION
 35        select f.fund_name,
 36               cl.claim_number,
 37               insured.ssn as ssn,
 38               patient.last_name as last_name,
 39               patient.first_name as first_name,
 40               patient.middle_name as middle_name,
 41               nvl(cl.updated_by, cl.inserted_by) updated_by,
 42               to_char(null) as memo_user_description,
 43               cl.claim_curr_status,
 44               p.provider_name,
 45               to_number(null) as claim_memo_id,
 46               cl.claim_id,
 47               nvl(cl.updated_date, cl.inserted_date) as memo_inserted_date,
 48               cl.claim_total_charge_amt,
 49               trunc(sysdate) - trunc(nvl(cl.updated_date, cl.inserted_date)) as pend_days
 50          from s_user.claim      cl,
 51               s_user.fund       f,
 52               s_user.claim_item ci,
 53               s_user.person     insured,
 54               s_user.person     patient,
 55               s_user.provider   p
 56         where f.fund_id = 1
 57           and cl.fund_id = f.fund_id
 58           and cl.claim_curr_status = 'P'
 59           and cl.claim_id = ci.claim_id
 60           and cl.insured_id = insured.person_id
 61           and cl.person_id = patient.person_id
 62           and p.provider_id = cl.service_provider_id
 63           and not exists (select cl.claim_id
 64                  from s_user.claim           cl1,
 65                       s_user.fund            f1,
 66                       s_user.claim_item      ci1,
 67                       s_user.claim_item_memo cim1,
 68                       s_user.claim_memo      cm1
 69                 where f1.fund_id = 1
 70                   and cl1.fund_id = f1.fund_id
 71                   and cl1.claim_id = ci1.claim_id
 72                   and ci1.claim_item_id = cim1.claim_item_id
 73                   and cim1.claim_memo_id = cm1.claim_memo_id
 74                   and cm1.calculate_action = 'P'
 75                   and cim1.disabled = 'N'
 76*                  and cl1.claim_id = cl.claim_id)
SQL> /

73890 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=220185707 Card=8194022 Bytes=1381370724)
   1    0   SORT (UNIQUE) (Cost=220185707 Card=8194022 Bytes=1381370724)
   2    1     UNION-ALL
   3    2       HASH JOIN (Cost=330481 Card=6344476 Bytes=1103938824)
   4    3         TABLE ACCESS (FULL) OF 'CLAIM_MEMO' (Cost=4 Card=180Bytes=4320)
   5    3         HASH JOIN (Cost=330057 Card=6344476 Bytes=951671400)
   6    5           TABLE ACCESS (FULL) OF 'PERSON' (Cost=1611 Card=1072026 Bytes=21440520)
   7    5           HASH JOIN (Cost=297751 Card=6344476 Bytes=824781880)
   8    7             INDEX (FAST FULL SCAN) OF 'PROVIDER_X1' (UNIQUE)(Cost=854 Card=1685405 Bytes=38764315)
   9    7             HASH JOIN (Cost=259087 Card=6344476 Bytes=678858932)
  10    9               INDEX (FAST FULL SCAN) OF 'PERSON_X2' (UNIQUE) (Cost=307 Card=1072026 Bytes=10720260)
  11    9               HASH JOIN (Cost=239800 Card=6344476 Bytes=615414172)
  12   11                 TABLE ACCESS (FULL) OF 'CLAIM' (Cost=17369 Card=5435810 Bytes=282662120)
  13   11                 HASH JOIN (Cost=132879 Card=6344476 Bytes=285501420)
  14   13                   TABLE ACCESS (FULL) OF 'CLAIM_ITEM_MEMO' (Cost=5853 Card=6344476 Bytes=57100284)
  15   13                   NESTED LOOPS (Cost=59270 Card=14390029 Bytes=518041044)
  16   15                     TABLE ACCESS (BY INDEX ROWID) OF 'FUND'(Cost=1 Card=1 Bytes=26)
  17   16                       INDEX (UNIQUE SCAN) OF 'PK_FUND' (UNIQUE)
  18   15                     TABLE ACCESS (FULL) OF 'CLAIM_ITEM' (Cost=59269 Card=14390029 Bytes=143900290)
  19    2       FILTER
  20   19         HASH JOIN (Cost=66268 Card=1849546 Bytes=277431900)
  21   20           TABLE ACCESS (FULL) OF 'PERSON' (Cost=1611 Card=1072026 Bytes=21440520)
  22   20           HASH JOIN (Cost=55113 Card=1849546 Bytes=240440980)
  23   22             INDEX (FAST FULL SCAN) OF 'PROVIDER_X1' (UNIQUE)(Cost=854 Card=1685405 Bytes=38764315)
  24   22             HASH JOIN (Cost=42212 Card=1849546 Bytes=197901422)
  25   24               INDEX (FAST FULL SCAN) OF 'PERSON_X2' (UNIQUE) (Cost=307 Card=1072026 Bytes=10720260)
  26   24               HASH JOIN (Cost=35962 Card=1849546 Bytes=179405962)
  27   26                 TABLE ACCESS (FULL) OF 'CLAIM' (Cost=17369 Card=67948 Bytes=4484568)
  28   26                 NESTED LOOPS (Cost=3303 Card=14390029 Bytes=446090899)
  29   28                   TABLE ACCESS (BY INDEX ROWID) OF 'FUND' (Cost=1 Card=1 Bytes=26)
  30   29                     INDEX (UNIQUE SCAN) OF 'PK_FUND' (UNIQUE)
  31   28                   INDEX (FAST FULL SCAN) OF 'CLAIM_ITEM_FK2'(NON-UNIQUE) (Cost=3302 Card=14390029 Bytes=71950145)
  32   19         NESTED LOOPS (Cost=118 Card=27 Bytes=864)
  33   32           NESTED LOOPS (Cost=91 Card=27 Bytes=756)
  34   33             NESTED LOOPS (Cost=10 Card=27 Bytes=513)
  35   34               NESTED LOOPS (Cost=3 Card=1 Bytes=9)
  36   35                 INDEX (UNIQUE SCAN) OF 'PK_FUND' (UNIQUE)
  37   35                 TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM' (Cost=2 Card=1 Bytes=7)
  38   37                   INDEX (UNIQUE SCAN) OF 'PK_CLAIM' (UNIQUE) (Cost=1 Card=1)
  39   34               TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_ITEM' (Cost=7 Card=27 Bytes=270)
  40   39                 INDEX (RANGE SCAN) OF 'AK_CLAIM_ITEM' (UNIQUE) (Cost=2 Card=27)
  41   33             TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_ITEM_MEMO' (Cost=3 Card=1 Bytes=9)
  42   41               INDEX (RANGE SCAN) OF 'CLAIM_ITEM_MEMO_FK1' (NON-UNIQUE) (Cost=2 Card=1)
  43   32           TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_MEMO' (Cost=1 Card=1 Bytes=4)
  44   43             INDEX (UNIQUE SCAN) OF 'PK_CLAIM_MEMO' (UNIQUE)


Statistics
----------------------------------------------------------
     202726  recursive calls
         19  db block gets
   14529226  consistent gets
    5445597  physical reads
          0  redo size
   11081634  bytes sent via SQL*Net to client
     548561  bytes received via SQL*Net from client
       4927  SQL*Net roundtrips to/from client
          5  sorts (memory)
          1  sorts (disk)
      73890  rows processed


---- SQL 2. 

SQL> ed
Wrote file afiedt.buf

  1         select f.fund_name,
  2               cl.claim_number,
  3               insured.ssn as ssn,
  4               patient.last_name as last_name,
  5               patient.first_name as first_name,
  6               patient.middle_name as middle_name,
  7               nvl(cl.updated_by, cl.inserted_by) updated_by,
  8               cm.user_description as memo_user_description,
  9               cl.claim_curr_status,
 10               p.provider_name,
 11               cim.claim_memo_id as claim_memo_id,
 12               cl.claim_id,
 13          s_user.f_get_claim_min_memo_date(cl.claim_id) AS memo_inserted_date,
 14               cl.claim_total_charge_amt,
 15               trunc(sysdate) - trunc(s_user.f_get_claim_min_memo_date(cl.claim_id)) AS pend_days
 16          from s_user.claim           cl,
 17               s_user.fund            f,
 18               s_user.claim_item      ci,
 19               s_user.claim_item_memo cim,
 20               s_user.claim_memo      cm,
 21               s_user.person          insured,
 22               s_user.person          patient,
 23               s_user.provider        p
 24         where cl.claim_id = ci.claim_id
 25           and f.fund_id = 1
 26           and cl.fund_id = f.fund_id
 27           and ci.claim_item_id = cim.claim_item_id
 28           and cim.claim_memo_id = cm.claim_memo_id
 29           and cl.insured_id = insured.person_id
 30           and cl.person_id = patient.person_id
 31           and p.provider_id = cl.service_provider_id
 32           and cm.calculate_action = 'P'
 33           and cim.disabled = 'N'
 34           and cl.claim_id=1            -- the claim_id is passed
 35           UNION
 36        select f.fund_name,
 37               cl.claim_number,
 38               insured.ssn as ssn,
 39               patient.last_name as last_name,
 40               patient.first_name as first_name,
 41               patient.middle_name as middle_name,
 42               nvl(cl.updated_by, cl.inserted_by) updated_by,
 43               to_char(null) as memo_user_description,
 44               cl.claim_curr_status,
 45               p.provider_name,
 46               to_number(null) as claim_memo_id,
 47               cl.claim_id,
 48               nvl(cl.updated_date, cl.inserted_date) as memo_inserted_date,
 49               cl.claim_total_charge_amt,
 50               trunc(sysdate) - trunc(nvl(cl.updated_date, cl.inserted_date)) as pend_days
 51          from s_user.claim      cl,
 52               s_user.fund       f,
 53               s_user.claim_item ci,
 54               s_user.person     insured,
 55               s_user.person     patient,
 56               s_user.provider   p
 57         where f.fund_id = 1
 58           and cl.fund_id = f.fund_id
 59           and cl.claim_curr_status = 'P'
 60           and cl.claim_id = ci.claim_id
 61           and cl.insured_id = insured.person_id
 62           and cl.person_id = patient.person_id
 63           and p.provider_id = cl.service_provider_id
 64           and cl.claim_id=1                    -- the claim_id is passed
 65           and not exists (select cl.claim_id
 66                  from s_user.claim           cl1,
 67                       s_user.fund            f1,
 68                       s_user.claim_item      ci1,
 69                       s_user.claim_item_memo cim1,
 70                       s_user.claim_memo      cm1
 71                 where f1.fund_id = 1
 72                   and cl1.fund_id = f1.fund_id
 73                   and cl1.claim_id = ci1.claim_id
 74                   and ci1.claim_item_id = cim1.claim_item_id
 75                   and cim1.claim_memo_id = cm1.claim_memo_id
 76                   and cm1.calculate_action = 'P'
 77                   and cim1.disabled = 'N'
 78*                  and cl1.claim_id = cl.claim_id)
SQL> /

no rows selected

Elapsed: 00:00:00.63

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=117 Card=54 Bytes=8748)
   1    0   SORT (UNIQUE) (Cost=117 Card=54 Bytes=8748)
   2    1     UNION-ALL
   3    2       HASH JOIN (Cost=102 Card=27 Bytes=4698)
   4    3         TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_ITEM_MEMO' (Cost=3 Card=1 Bytes=9)
   5    4           NESTED LOOPS (Cost=97 Card=27 Bytes=4050)
   6    5             NESTED LOOPS (Cost=16 Card=27 Bytes=3807)
   7    6               NESTED LOOPS (Cost=9 Card=1 Bytes=131)
   8    7                 NESTED LOOPS (Cost=7 Card=1 Bytes=121)
   9    8                   NESTED LOOPS (Cost=5 Card=1 Bytes=101)
  10    9                     NESTED LOOPS (Cost=3 Card=1 Bytes=78)
  11   10                       TABLE ACCESS (BY INDEX ROWID) OF 'FUND' (Cost=1 Card=1 Bytes=26)
  12   11                         INDEX (UNIQUE SCAN) OF 'PK_FUND' (UNIQUE)
  13   10                       TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM' (Cost=2 Card=1 Bytes=52)
  14   13                         INDEX (UNIQUE SCAN) OF 'PK_CLAIM' (UNIQUE) (Cost=1 Card=1)
  15    9                     TABLE ACCESS (BY INDEX ROWID) OF 'PROVIDER' (Cost=2 Card=1 Bytes=23)
  16   15                       INDEX (UNIQUE SCAN) OF 'PK_PROVIDER' (UNIQUE) (Cost=1 Card=1)
  17    8                   TABLE ACCESS (BY INDEX ROWID) OF 'PERSON' (Cost=2 Card=1 Bytes=20)
  18   17                     INDEX (UNIQUE SCAN) OF 'PK_PERSON' (UNIQUE) (Cost=1 Card=1)
  19    7                 TABLE ACCESS (BY INDEX ROWID) OF 'PERSON' (Cost=2 Card=1 Bytes=10)
  20   19                   INDEX (UNIQUE SCAN) OF 'PK_PERSON' (UNIQUE) (Cost=1 Card=1)
  21    6               TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_ITEM'(Cost=7 Card=27 Bytes=270)
  22   21                 INDEX (RANGE SCAN) OF 'AK_CLAIM_ITEM' (UNIQUE) (Cost=2 Card=27)
  23    5             INDEX (RANGE SCAN) OF 'CLAIM_ITEM_MEMO_FK1' (NON-UNIQUE) (Cost=2 Card=1)
  24    3         TABLE ACCESS (FULL) OF 'CLAIM_MEMO' (Cost=4 Card=180 Bytes=4320)
  25    2       NESTED LOOPS (Cost=11 Card=27 Bytes=4050)
  26   25         NESTED LOOPS (Cost=9 Card=1 Bytes=145)
  27   26           NESTED LOOPS (Cost=7 Card=1 Bytes=135)
  28   27             NESTED LOOPS (Cost=5 Card=1 Bytes=115)
  29   28               NESTED LOOPS (Cost=3 Card=1 Bytes=92)
  30   29                 TABLE ACCESS (BY INDEX ROWID) OF 'FUND' (Cost=1 Card=1 Bytes=26)
  31   30                   INDEX (UNIQUE SCAN) OF 'PK_FUND' (UNIQUE)
  32   29                 TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM' (Cost=2 Card=1 Bytes=66)
  33   32                   INDEX (UNIQUE SCAN) OF 'PK_CLAIM' (UNIQUE)(Cost=1 Card=1)
  34   33                     NESTED LOOPS (Cost=118 Card=27 Bytes=864)
  35   34                       NESTED LOOPS (Cost=91 Card=27 Bytes=756)
  36   35                         NESTED LOOPS (Cost=10 Card=27 Bytes=513)
  37   36                           NESTED LOOPS (Cost=3 Card=1 Bytes=9)
  38   37                             INDEX (UNIQUE SCAN) OF 'PK_FUND'(UNIQUE)
  39   37                             TABLE ACCESS (BY INDEX ROWID) OF'CLAIM' (Cost=2 Card=1 Bytes=7)
  40   39                               INDEX (UNIQUE SCAN) OF 'PK_CLAIM' (UNIQUE) (Cost=1 Card=1)
  41   36                           TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_ITEM' (Cost=7 Card=27 Bytes=270)
  42   41                             INDEX (RANGE SCAN) OF 'AK_CLAIM_ITEM' (UNIQUE) (Cost=2 Card=27)
  43   35                         TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_ITEM_MEMO' (Cost=3 Card=1 Bytes=9)
  44   43                           INDEX (RANGE SCAN) OF 'CLAIM_ITEM_MEMO_FK1' (NON-UNIQUE) (Cost=2 Card=1)
  45   34                       TABLE ACCESS (BY INDEX ROWID) OF 'CLAIM_MEMO' (Cost=1 Card=1 Bytes=4)
  46   45                         INDEX (UNIQUE SCAN) OF 'PK_CLAIM_MEMO' (UNIQUE)
  47   28               TABLE ACCESS (BY INDEX ROWID) OF 'PROVIDER' (Cost=2 Card=1 Bytes=23)
  48   47                 INDEX (UNIQUE SCAN) OF 'PK_PROVIDER' (UNIQUE) (Cost=1 Card=1)
  49   27             TABLE ACCESS (BY INDEX ROWID) OF 'PERSON' (Cost=2 Card=1 Bytes=20)
  50   49               INDEX (UNIQUE SCAN) OF 'PK_PERSON' (UNIQUE) (Cost=1 Card=1)
  51   26           TABLE ACCESS (BY INDEX ROWID) OF 'PERSON' (Cost=2 Card=1 Bytes=10)
  52   51             INDEX (UNIQUE SCAN) OF 'PK_PERSON' (UNIQUE) (Cost=1 Card=1)
  53   25         INDEX (RANGE SCAN) OF 'AK_CLAIM_ITEM' (UNIQUE) (Cost=2 Card=27 Bytes=135)

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         79  consistent gets
          0  physical reads
          0  redo size
       1036  bytes sent via SQL*Net to client
       1815  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          0  rows processed 

Another Question

Carol, April 11, 2006 - 1:33 pm UTC

Tom,
I am told by a DBA that if I run an explain plan in Toad vs. SQL Plus vs. using TKProf (in the same schema/database), I could get different results in them all. Is this true? Does this mean I can only use TKProf to get the 'true' explain plan for a query?

Thanks very much.

Tom Kyte
April 11, 2006 - 7:20 pm UTC

sure you can

but only because each environment might have different optimizer settings (toad might be first rows for example and sqlplus "choose" or "all rows")

And because explain plan "lies" sometimes - since explain plan

a) uses whatever optimizer settings you currently HAVE, not what were in place when the query in question was run
b) cannot bind variable peek
c) sees ALL BINDS as strings regardless

tkprof - the row source operation section - is the actual true plan used by a given query at runtime.

Efficient code

Yoav, April 18, 2006 - 11:34 am UTC

Hi Tom,

From above:
"
...
queries to check for existence -
when the application should just TRY TO PROCESS A RECORD and
upon finding nothing to process - quit.
Rather than "LOOK TO SEE IF WE HAVE SOMETHING TO PROCESS and then process"
"

Tom , could you please demonstrate how to implement
"LOOK TO SEE IF WE HAVE SOMETHING TO PROCESS and then process".

suppose we have we somthing simple like this:

SELECT 1
FROM EMP
WHERE DEPTNO > 30
AND ROWNUM = 1;

Thanks Alot.


Tom Kyte
April 18, 2006 - 2:33 pm UTC

you have to tell me why you would run that query - what comes "next"

then I'll show you how to remove that query and just do the "next" bit.


eg: I see this "really bad practice" a lot:


select count(*) into l_cnt
from emp
where empno = :x; /* empno is primary key */

if ( l_cnt != 0 )
then
update emp set .... where empno = :x;
else
insert into emp ( empno, ... ) values ( :x, ... );
end if;



That should be nothing more than:

update emp set .... where empno = :x;
if (SQL%ROWCOUNT=0)
then
insert into emp ( empno, ... ) values ( :x, ... );
end if;


why bother doing the search TWICE to do the upadte - once to count records - to see if it is there, and then again to re-find said record and modify it.

Just try to modify it - if nothing to modify, then heck - insert it.




I do not advocate "look to see...", I advocate "just do it".

Tuning

Carol, April 28, 2006 - 4:46 pm UTC

I have noticed that the explain plan generated by Toad vs. SQL Plus vs TKPROF can all be different so I am assuming the only way to properly tune a query is using TKPROF?

I have a query that has analyzed tables and the correct joins and indexes and uses bind variables. It is joining the tables in the wrong order. If I don't use hints (like you suggest), what are some ways I can make it change the order it joins tables?

Thanks

Tom Kyte
April 28, 2006 - 5:36 pm UTC

show me, give me something to work with here.

Difference between TKPROF and Explain Plan

A reader, April 30, 2006 - 6:23 am UTC

Tom,

I was asked in one interview, what is the difference between Tkprof and Explain plan?


Can you provide the difference?

Tom Kyte
April 30, 2006 - 2:08 pm UTC

they are not even comparable. explain plan is the guess as to to what a query plan might be for some query (without bind variable peeking, without knowing the bind datatype, without knowing the executing environment optimizer environment)

tkprof on the other hand is a command line utility that takes an Oracle trace file and formats it in human readable format. In the tkprof report you will see actual SQL executed, how many times it was parsed/executed/fetched from (as well as the cpu, elapsed time and other statistics about its execution). Optionally, you might see the "row source operation" which is the ACTUAL execution plan used by that query at runtime (not a guess). You can, if you pass in explain=, get the explain plan output as well.


but basically, if the question was literraly what you said it was - the question doesn't really "make sense" as phrased, it would need more detail.

"Bad" Query

Jagat Singh, May 02, 2006 - 4:07 am UTC

Hi Tom,

SELECT xyz.*,TOT-ALLOC "Non-Allocated" FROM (
SELECT AA.P,AA.M,AA.T TOT,BB.C,(
SELECT COUNT(*) AS j2 FROM CUSTOMER.BJAZ_DM_PROSPECTS a,CUSTOMER.BJAZ_DM_PROSP_ASSG_DTL b
WHERE a.p_prospect_id = b.prospect_id AND TO_CHAR(a.p_date_of_expiry,'MONTH') = AA.M
AND a.p_city = AA.P) ALLOC
FROM (
SELECT p_city P,TO_CHAR(p_date_of_expiry,'MONTH') M,COUNT(*) T
FROM CUSTOMER.BJAZ_DM_PROSPECTS WHERE P_CITY IS NOT NULL
GROUP BY P_CITY,TO_CHAR(p_date_of_expiry,'MONTH')
) AA ,
(
SELECT p_city P,TO_CHAR(p_date_of_expiry,'MONTH') M,COUNT(*) C
FROM CUSTOMER.BJAZ_DM_PROSPECTS WHERE P_CITY IS NOT NULL
AND P_TELEPHONE IS NOT NULL AND P_DATE_OF_EXPIRY IS NOT NULL
GROUP BY P_CITY,TO_CHAR(p_date_of_expiry,'MONTH') )
BB
WHERE AA.P = BB.P(+) AND AA.M = bb.M(+)
) XYZ

Above mentioned query is executed everyday .. it takes lot of time .. can you tell how to tune.. clue not solution would help to learn.

Thanks a lot

Tom Kyte
May 02, 2006 - 7:26 am UTC

(hehehe, I would have a really hard time with those column names wouldn't I - I have to rename all of them before I could use any plsql....)

you would have to really help us understand the question being asked in the FIRST PLACE.

what I do see is a very unformatted (and hence unreadable) query...

SELECT xyz.*,TOT-ALLOC "Non-Allocated"
FROM ( SELECT AA.P,AA.M,AA.T TOT,BB.C,
( SELECT COUNT(*) AS j2
FROM CUSTOMER.BJAZ_DM_PROSPECTS a,
CUSTOMER.BJAZ_DM_PROSP_ASSG_DTL b
WHERE a.p_prospect_id = b.prospect_id
AND TO_CHAR(a.p_date_of_expiry,'MONTH') = AA.M
AND a.p_city = AA.P) ALLOC
FROM ( SELECT p_city P,TO_CHAR(p_date_of_expiry,'MONTH') M,COUNT(*) T
FROM CUSTOMER.BJAZ_DM_PROSPECTS WHERE P_CITY IS NOT NULL
GROUP BY P_CITY,TO_CHAR(p_date_of_expiry,'MONTH')) AA ,
( SELECT p_city P,TO_CHAR(p_date_of_expiry,'MONTH') M,COUNT(*) C
FROM CUSTOMER.BJAZ_DM_PROSPECTS
WHERE P_CITY IS NOT NULL
AND P_TELEPHONE IS NOT NULL AND P_DATE_OF_EXPIRY IS NOT NULL
GROUP BY P_CITY,TO_CHAR(p_date_of_expiry,'MONTH') ) BB
WHERE AA.P = BB.P(+) AND AA.M = bb.M(+)
) XYZ


Is one way to write it "more cleanly" so others have a chance.... But what jumps out immediately is the two passes on bjaz_dm_prospects and the outer join that results.

that can be done in a single pass

FROM ( SELECT p_city P,TO_CHAR(p_date_of_expiry,'MONTH') M,COUNT(*) T ,
count(case when P_TELEPHONE IS NOT NULL
AND P_DATE_OF_EXPIRY IS NOT NULL
then 1
end ) C
FROM CUSTOMER.BJAZ_DM_PROSPECTS
WHERE P_CITY IS NOT NULL
GROUP BY P_CITY,TO_CHAR(p_date_of_expiry,'MONTH'))



tuning

mal, May 04, 2006 - 6:53 pm UTC

can you please me on this query to tune
SELECT O.ORGANIZATION_ID, O.NAME, O.DESCRIPTION, O.CREATE_DATE,
O.ACTIVE, O.ALLOW_AUCTION_DIRECT_RELEASE, O.SALES_REGION_ID,
O.SALES_REP_ID, O.TELESALES_AGENT_ID, O.PAYMENT_DEPARTMENT, O.PRIMARY_PAYEE_CHECK_NAME,
O.COMMENTS, O.SEND_RESERVE_MET_EMAIL,
O.AIGNUMBER, O.FORD_ENROLLED, O.ALLOW_TRANSPORT,
O.ALLOW_SELLER_LINK
FROM ORGANIZATIONS O
WHERE O.ORGANIZATION_ID
in
(SELECT AGO.ORGANIZATION_ID FROM ACCESS_GROUPS_ORGANIZATIONS AGO, PRIVATE_LABEL_INFOS PLI,
ACCESS_GROUPS_PRV_LABEL_INFOS AGPLI, ORGANIZATIONS_ORGTYPES OO
WHERE PLI.PRIVATE_LABEL_INFO_ID = AGPLI.PRIVATE_LABEL_INFO_ID
AND AGPLI.ACCESS_GROUP_ID = AGO.ACCESS_GROUP_ID AND AGO.ORGANIZATION_ID = OO.ORGANIZATION_ID AND
PLI.PRIVATE_LABEL_INFO_ID=1 AND OO.ORGANIZATION_TYPE_ID=1)

229 rows selected.

Elapsed: 00:00:08.06

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=125 Card=116 Bytes=9
048)

1 0 NESTED LOOPS (Cost=125 Card=116 Bytes=9048)
2 1 VIEW OF 'VW_NSO_1' (Cost=5 Card=116 Bytes=1508)
3 2 SORT (UNIQUE)
4 3 NESTED LOOPS (Cost=5 Card=116 Bytes=2900)
5 4 NESTED LOOPS (Cost=5 Card=944 Bytes=16992)
6 5 NESTED LOOPS (Cost=2 Card=1 Bytes=9)
7 6 INDEX (UNIQUE SCAN) OF 'PRIVATE_LABEL_INFOS_PK
' (UNIQUE)

8 6 INDEX (FULL SCAN) OF 'GROUPS_PRIVATE_LABEL_INF
OS_PK' (UNIQUE) (Cost=1 Card=1 Bytes=6)

9 5 INDEX (RANGE SCAN) OF 'GROUPS_ORGANIZATIONS_PK'
(UNIQUE) (Cost=3 Card=889 Bytes=8001)

10 4 INDEX (UNIQUE SCAN) OF 'PK_ORGANIZATIONS_ORGTYPES'
(UNIQUE)

11 1 TABLE ACCESS (BY INDEX ROWID) OF 'ORGANIZATIONS' (Cost=1
Card=1 Bytes=65)

12 11 INDEX (UNIQUE SCAN) OF 'PK_ORGANIZATIONS' (UNIQUE)




Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
74227 consistent gets
0 physical reads
0 redo size
73729 bytes sent via SQL*Net to client
668 bytes received via SQL*Net from client
17 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
229 rows processed


tuning

reda, May 07, 2006 - 2:11 pm UTC

I am need do tuning sql statements. Can u give a step by step of tuning
the sql statements.


Tom Kyte
May 07, 2006 - 4:15 pm UTC

1) read a lot
2) become experienced :)

If you need "step by steps" - best to get a piece of software where the "rules of thumb" have been codified into subroutines (such as enterprise manager with the tuning pack - there are others)

Otherwise - you can re-read my original answer above which directly addresses your question and has my never changing response.

Su Baba, May 07, 2006 - 8:39 pm UTC

I'm kind of puzzled by the fact that the last two SQLs use the index. Since there are only two distinct values in the column, shouldn't Oracle use full table scan?

SQL> SELECT * FROM v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Prod
PL/SQL Release 10.2.0.1.0 - Production
CORE    10.2.0.1.0      Production
TNS for 32-bit Windows: Version 10.2.0.1.0 - Production
NLSRTL Version 10.2.0.1.0 - Production

SQL> 
SQL> DROP TABLE x;

Table dropped.

SQL> 
SQL> CREATE TABLE x
  2  AS
  3  SELECT rownum pk_id, 1 protocol
  4  FROM   all_objects
  5  WHERE  rownum <= 1000
  6  UNION ALL
  7  SELECT rownum + 1000 pk_id, 2 protocl
  8  FROM   all_objects
  9  WHERE  rownum <= 5;

Table created.

SQL> 
SQL> ALTER TABLE x ADD PRIMARY KEY (pk_id);

Table altered.

SQL> 
SQL> CREATE INDEX x_ind ON x(protocol);

Index created.

SQL> 
SQL> SELECT protocol, COUNT(*)
  2  FROM   x
  3  GROUP  BY protocol;

  PROTOCOL   COUNT(*)
---------- ----------
         1       1000
         2          5

SQL> exec dbms_stats.gather_table_stats( user, 'X' );

PL/SQL procedure successfully completed.

SQL> 
SQL> SELECT table_name, column_name, num_distinct, num_buckets, density, histogram
  2  FROM   user_tab_columns
  3  WHERE  table_name = 'X';

TABLE_NAME   COLUMN_NAME  NUM_DISTINCT NUM_BUCKETS    DENSITY HISTOGRAM
------------ ------------ ------------ ----------- ---------- ---------------
X            PK_ID                1005           1 .000995025 NONE
X            PROTOCOL                2           1         .5 NONE

SQL> set autotrace traceonly explain
SQL> 
SQL> SELECT * FROM x WHERE protocol = 1;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=2 Card=503 Bytes=3018)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'X' (TABLE) (Cost=2 Card=503 Bytes=3018)
   2    1     INDEX (RANGE SCAN) OF 'X_IND' (INDEX) (Cost=1 Card=503)



SQL> SELECT * FROM x WHERE protocol = 2;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=2 Card=503 Bytes=3018)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'X' (TABLE) (Cost=2 Card=503 Bytes=3018)
   2    1     INDEX (RANGE SCAN) OF 'X_IND' (INDEX) (Cost=1 Card=503)



SQL> set autotrace off
SQL> 
SQL> spool off
 

Tom Kyte
May 08, 2006 - 7:58 am UTC

(you really ought to use the 10gr2 sqlplus too!!!  better explain plan output, incredibly better)



It is a TINY TABLE.  The costs here are trivial - 3 for a full scan, 2 for the index scan.  

We have a saying "6 one way, 1/2 dozen the other" - this is just "way way too small" to be very picky about.  


Now, what is interesting (if you want to make this an interesting example) is what happens if you just gather statistics again :)

See:
https://www.oracle.com/technetwork/issue-archive/2006/06-may/o36asktom-099107.html
"Why Does My Plan Change?" for the "what is going on" here

ops$tkyte@ORA10GR2> exec dbms_stats.gather_table_stats( user, 'X' );
                                                                                                                                                                   
PL/SQL procedure successfully completed.
                                                                                                                                                                   
ops$tkyte@ORA10GR2> set autotrace traceonly explain
ops$tkyte@ORA10GR2> SELECT * FROM x WHERE protocol = 1;
                                                                                                                                                                   
Execution Plan
----------------------------------------------------------
Plan hash value: 1381019782
                                                                                                                                                                   
-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |   503 |  3018 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| X     |   503 |  3018 |     2   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | X_IND |   503 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------
                                                                                                                                                                   
Predicate Information (identified by operation id):
---------------------------------------------------
                                                                                                                                                                   
   2 - access("PROTOCOL"=1)
                                                                                                                                                                   
ops$tkyte@ORA10GR2> SELECT * FROM x WHERE protocol = 2;
                                                                                                                                                                   
Execution Plan
----------------------------------------------------------
Plan hash value: 1381019782
                                                                                                                                                                   
-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |   503 |  3018 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| X     |   503 |  3018 |     2   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | X_IND |   503 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------
                                                                                                                                                                   
Predicate Information (identified by operation id):
---------------------------------------------------
                                                                                                                                                                   
   2 - access("PROTOCOL"=2)
                                                                                                                                                                   
ops$tkyte@ORA10GR2> select /*+ FULL(x) */ * from x where protocol = 2;
                                                                                                                                                                   
Execution Plan
----------------------------------------------------------
Plan hash value: 2941724873
                                                                                                                                                                   
--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |   503 |  3018 |     3   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| X    |   503 |  3018 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------
                                                                                                                                                                   
Predicate Information (identified by operation id):
---------------------------------------------------
                                                                                                                                                                   
   1 - filter("PROTOCOL"=2)
                                                                                                                                                                   
ops$tkyte@ORA10GR2> set autotrace off
ops$tkyte@ORA10GR2> exec dbms_stats.gather_table_stats( user, 'X' );
                                                                                                                                                                   
PL/SQL procedure successfully completed.
                                                                                                                                                                   
ops$tkyte@ORA10GR2> set autotrace traceonly explain
ops$tkyte@ORA10GR2> SELECT * FROM x WHERE protocol = 1;
                                                                                                                                                                   
Execution Plan
----------------------------------------------------------
Plan hash value: 2941724873
                                                                                                                                                                   
--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |  1000 |  6000 |     3   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| X    |  1000 |  6000 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------
                                                                                                                                                                   
Predicate Information (identified by operation id):
---------------------------------------------------
                                                                                                                                                                   
   1 - filter("PROTOCOL"=1)
                                                                                                                                                                   
ops$tkyte@ORA10GR2> SELECT * FROM x WHERE protocol = 2;
                                                                                                                                                                   
Execution Plan
----------------------------------------------------------
Plan hash value: 1381019782
                                                                                                                                                                   
-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |     5 |    30 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| X     |     5 |    30 |     2   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | X_IND |     5 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------
                                                                                                                                                                   
Predicate Information (identified by operation id):
---------------------------------------------------
                                                                                                                                                                   
   2 - access("PROTOCOL"=2)
                                                                                                                                                                   
ops$tkyte@ORA10GR2> select /*+ FULL(x) */ * from x where protocol = 2;
                                                                                                                                                                   
Execution Plan
----------------------------------------------------------
Plan hash value: 2941724873
                                                                                                                                                                   
--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     5 |    30 |     3   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| X    |     5 |    30 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------
                                                                                                                                                                   
Predicate Information (identified by operation id):
---------------------------------------------------
                                                                                                                                                                   
   1 - filter("PROTOCOL"=2)
                                                                                                                                                                   
ops$tkyte@ORA10GR2> set autotrace off

 

Index Scan

Narendra, May 08, 2006 - 12:40 am UTC

Su Baba,

I tried reproducing your test case but could not.
SQL> select * from v$version ;

BANNER
----------------------------------------------------------------
Oracle9i Enterprise Edition Release 9.2.0.6.0 - 64bit Production
PL/SQL Release 9.2.0.6.0 - Production
CORE    9.2.0.6.0       Production
TNS for Solaris: Version 9.2.0.6.0 - Production
NLSRTL Version 9.2.0.6.0 - Production

SQL> create table X
  2  as
  3  select rownum pk_id, 1 protocol
  4  from all_objects
  5  where rownum <= 1000
  6  union all
  7  select rownum + 1000, 2 protocol
  8  from all_objects
  9  where rownum <= 5 ;

Table created.

SQL> alter table X add primary key (pk_id) ;

Table altered.

SQL> create index x_ind on x(protocol) ;

Index created.

SQL> select protocol, count(*) from X group by protocol ;

  PROTOCOL   COUNT(*)
---------- ----------
         1       1000
         2          5

SQL> exec dbms_stats.gather_table_stats(user, 'X') ;

PL/SQL procedure successfully completed.

SQL> set autotrace traceonly explain
SQL> select * from x where protocol = 1 ;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=503 Bytes=301
          8)

   1    0   TABLE ACCESS (FULL) OF 'X' (Cost=2 Card=503 Bytes=3018)



SQL> select * from x where protocol = 2 ;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=503 Bytes=301
          8)

   1    0   TABLE ACCESS (FULL) OF 'X' (Cost=2 Card=503 Bytes=3018)



SQL> set autotrace off

The suspect in your case is "card=503" in the plan for both queries. Optimizer is "assuming" 503 rows for the WHERE condition (which, in fact, is not the case).
How about collecting statistics for INDEXED columns as well or creating histograms ?

Tom,
There still remains a question. With the steps given above, why did ORACLE (incorrectly) chose an index scan in 10g whereas (correctly) chose a table scan in 9i ? Isn't the optimizer for 10g supposed to be superior than that of 10g ? 

Tom Kyte
May 08, 2006 - 8:01 am UTC

You have an entirely different release - things change. See above. The costs here are so tiny it boils down to "so what" for either access plan.

Some additional Info

Narendra, May 08, 2006 - 12:59 am UTC

Sorry to have missed out on some details in earlier example.

Even the plan in 9i showed "card=503" but chose a full table scan. So it seems not cardinality but some other factors (like DB_FILE_MULTIBLOCK_READ_COUNT, OPTIMIZER_IND_* parameters setings) might be the cause behind different access paths chosen.
However, following are some interesting observations:
SQL> exec dbms_stats.gather_table_stats(user, 'X', method_opt => 'for all indexed columns size skewonly', cascade => true) ;

PL/SQL procedure successfully completed.

SQL> set autotrace traceonly explain
SQL> select * from x where protocol = 1 ;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=1000 Bytes=6000)

   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'X' (Cost=2 Card=1000 Bytes=6000)

   2    1     INDEX (RANGE SCAN) OF 'X_IND' (NON-UNIQUE) (Cost=1 Card=1000)




SQL> select * from x where protocol = 2 ;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=2 Card=5 Bytes=30)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'X' (Cost=2 Card=5 Bytes=30)

   2    1     INDEX (RANGE SCAN) OF 'X_IND' (NON-UNIQUE) (Cost=1 Card=5)

SQL> select clustering_factor from all_indexes where index_name = 'X_IND' ;

CLUSTERING_FACTOR
-----------------
                1

SQL> select blocks, num_rows from all_tables where table_name = 'X' ;

    BLOCKS   NUM_ROWS
---------- ----------
         4       1005

When collected stats for SKEWED columns, the "card=" problem got corrected and queries chose INDEX RANGE scan instead of table scan. The reasoning for choosing index scan can be backed up by clustering factor value for the index (1), which is closer to number of table blocks (4) rather than number of rows (1005).

Tom,
Now this adds some confusion. If "select * from x where protocol = 1 ;" returns 100 rows out of 1005 rows in the table, why won't a table scan be more efficient than an index scan ? 

Tom Kyte
May 08, 2006 - 8:01 am UTC

*this table is so so so so so teeny teeny tiny*

example is uninteresting due to extreme small size of table.

tuning

mike, May 08, 2006 - 12:36 pm UTC

Tom:

How do you explain this:

I have as imple table with "SSN" as a primary key:

TEST
SSN  NOT NULL varchar2(10),
NAME          varchar2(50),
DOB           date


SQL> select * from test where SSN='611';

SSN        NAME                           DOB                   ------------------------------ -------------------- ----------
611        John                           18-oct-2002 15:26:31

1 row selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=1 Card=1 Bytes=20)
   1    0   TABLE ACCESS (FULL) OF 'TEST' (Cost=1 Card=1 Bytes=20)




Statistics
----------------------------------------------------------
          0  recursive calls
          4  db block gets
          2  consistent gets
          0  physical reads
          0  redo size
        297  bytes sent via SQL*Net to client
        132  bytes received via SQL*Net from client
          3  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          1  rows processed


1.  Why is the "SELECT" doing a full table scan since I alerady have a Primary key/index on SSN?

2.  If I did "select * from test where SSN=123 and NAME=Joe'

will it always do a full table scan unless I create an index on (ssn,name) Correct?


 

Tom Kyte
May 08, 2006 - 1:37 pm UTC

utterly incomplete example.

but look at the cost and card there. I would suspect you have what, maybe a one row table. Would you mind using a reasonable sized example?


if you did "where ssn=123 and ...." - you would need a FUNCTION BASED INDEX on ssn since you are comparing a string to a number and Oracle would really be doing:

where to_number(ssn) = 123 and ....


but no, if you query:

where ssn = '123' and name = 'Joe'

Oracle would use an index on SSN or NAME or (name,ssn) or (ssn,name) ......

sql tuning

mal, May 08, 2006 - 3:31 pm UTC

Please help me to tune this
SELECT O.ORGANIZATION_ID, O.NAME, O.DESCRIPTION, O.CREATE_DATE,
O.ACTIVE, O.ALLOW_AUCTION_DIRECT_RELEASE, O.SALES_REGION_ID,
O.SALES_REP_ID, O.TELESALES_AGENT_ID, O.PAYMENT_DEPARTMENT,
O.PRIMARY_PAYEE_CHECK_NAME,
O.COMMENTS, O.SEND_RESERVE_MET_EMAIL,
O.AIGNUMBER, O.FORD_ENROLLED, O.ALLOW_TRANSPORT,
O.ALLOW_SELLER_LINK
FROM ORGANIZATIONS O
WHERE O.ORGANIZATION_ID
in
(SELECT AGO.ORGANIZATION_ID FROM ACCESS_GROUPS_ORGANIZATIONS AGO,
PRIVATE_LABEL_INFOS PLI,
ACCESS_GROUPS_PRV_LABEL_INFOS AGPLI, ORGANIZATIONS_ORGTYPES OO
WHERE PLI.PRIVATE_LABEL_INFO_ID = AGPLI.PRIVATE_LABEL_INFO_ID
AND AGPLI.ACCESS_GROUP_ID = AGO.ACCESS_GROUP_ID AND AGO.ORGANIZATION_ID =
OO.ORGANIZATION_ID AND
PLI.PRIVATE_LABEL_INFO_ID=1 AND OO.ORGANIZATION_TYPE_ID=1)

229 rows selected.

Elapsed: 00:00:08.06

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=125 Card=116 Bytes=9
048)

1 0 NESTED LOOPS (Cost=125 Card=116 Bytes=9048)
2 1 VIEW OF 'VW_NSO_1' (Cost=5 Card=116 Bytes=1508)
3 2 SORT (UNIQUE)
4 3 NESTED LOOPS (Cost=5 Card=116 Bytes=2900)
5 4 NESTED LOOPS (Cost=5 Card=944 Bytes=16992)
6 5 NESTED LOOPS (Cost=2 Card=1 Bytes=9)
7 6 INDEX (UNIQUE SCAN) OF 'PRIVATE_LABEL_INFOS_PK
' (UNIQUE)

8 6 INDEX (FULL SCAN) OF 'GROUPS_PRIVATE_LABEL_INF
OS_PK' (UNIQUE) (Cost=1 Card=1 Bytes=6)

9 5 INDEX (RANGE SCAN) OF 'GROUPS_ORGANIZATIONS_PK'
(UNIQUE) (Cost=3 Card=889 Bytes=8001)

10 4 INDEX (UNIQUE SCAN) OF 'PK_ORGANIZATIONS_ORGTYPES'
(UNIQUE)

11 1 TABLE ACCESS (BY INDEX ROWID) OF 'ORGANIZATIONS' (Cost=1
Card=1 Bytes=65)

12 11 INDEX (UNIQUE SCAN) OF 'PK_ORGANIZATIONS' (UNIQUE)




Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
74227 consistent gets
0 physical reads
0 redo size
73729 bytes sent via SQL*Net to client
668 bytes received via SQL*Net from client
17 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
229 rows processed

Tom Kyte
May 08, 2006 - 5:08 pm UTC

how about you compare the TKPROF which has actual rowcounts to the autotrace above and let us know if they are "way off" from eachother - and if so WHERE - and explain any reasons you can think of that they might be off (missing stats, invalid stats, stale stats, incomplete stats...)

tuning

mike, May 08, 2006 - 3:49 pm UTC

Tom:

The table have 11 records and not one record. Why do you think it is doing a full scan.

SQL> select * from test;

SSN        NAME                           DOB                  
---------- ------------------------------ -------------------- 
777        Joe Blow                       01-jan-2002 00:00:00
456        Henry walkman                  17-jan-2002 00:00:00
444        Tony walkman                   18-jan-2002 00:00:00
555        Karin wilsow
888        john kare                      01-mar-2002 00:00:00
3333       Cindy Best                     04-mar-2002 13:52:20
222        Joe  Blow                      24-apr-2002 15:56:53
3444       Joe         Blow               24-apr-2002 16:53:12
0000                                      24-apr-2002 16:56:12
611        John                           18-oct-2002 15:26:31
1232

11 rows selected.

2.  When you say "oracle" tries to use an index on SSN and (ssn, name) or (name,ssn) do you mean oracle will automatically create those indexes?

I am assuming I only have one index table and that is the "SSN". Will it always do a full table scan on any query on this table that uses more than one column unless I create proper indexes?

3. My whole test is to see whether in a given application I should check for the WHERE clauses in QUERIES on the TEST table and then build separate indexes on these columns to avoid full table scans and getter performance.

Problem is that this may speed up querying but slow down INSERTS and UPDATES because every time you insert/update you have to update all these indexes.

Thanks, 

Tom Kyte
May 08, 2006 - 5:13 pm UTC

*because the table is so teeny teeny teeny tiny as to not make a whit of difference*



If everything fits on a block, well.... You are sort of going to have to get that block anyway won't you.


2) oracle will not automagically create indexes. You said:

<quote>
If I did "select * from test where SSN=123 and NAME=Joe'

will it always do a full table scan unless I create an index on (ssn,name)
Correct?
</quote>

I said "no, it would use an index on SSN or on NAME or on (ssn,name) or on (name,ssn) - it doesn't have to be on (ssn,name)". I didn't say it would create one, but that it could use one on any or all of the columns.

Your table is so so teeny tiny here - you cannot possibly extrapolate this example up to a full sized table. The action you see taken against a 1 block table will be much different than a 1,000 block table - as far as query plans go!!!!


3) I have a three step program for you to undertake immediately:

step 1) say out loud "FULL SCANS ARE NOT EVIL"
step 2) say out loud "INDEX ACCESS IS NOT ALL GOODNESS"
step 3) go to step 1 and repeat until you actually believe what you are saying.



One more thing

Warren McCall, May 08, 2006 - 6:28 pm UTC

One more thing to add to your list Tom:

4. I will test on tables of representative size!

tp

A reader, May 09, 2006 - 9:55 am UTC

hi toem
who are you
what The difference betwen EXTENT MANAGEMENT LOCAL AUTOALLOCATE and
MANAGEMENT DICTIONARY
i craete table space with option MANAGEMENT DICTIONARY
do find any error??

CREATE TABLESPACE POS_TRANS DATAFILE
'F:\ORACLE\ORADATA\PROD\POS_TRANS_01.DBF' SIZE 500M AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED,
'F:\ORACLE\ORADATA\PROD\POS_TRANS_02.DBF' SIZE 500M AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED,
'F:\ORACLE\ORADATA\PROD\POS_TRANS_03.DBF' SIZE 500M AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED
LOGGING
DEFAULT STORAGE (
INITIAL 40K
NEXT 40K
MINEXTENTS 1
MAXEXTENTS 505
PCTINCREASE 50
)
ONLINE
PERMANENT
EXTENT MANAGEMENT DICTIONARY;
-----------------
CREATE TABLESPACE NAHDI_POS DATAFILE
'F:\ORACLE\ORADATA\PROD\NAHDI_POS1.DBF' SIZE 500M AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED,
'F:\ORACLE\ORADATA\PROD\NAHDI_POS4.DBF' SIZE 500M AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED
LOGGING
ONLINE
PERMANENT
EXTENT MANAGEMENT LOCAL AUTOALLOCATE;




Tom Kyte
May 09, 2006 - 10:01 am UTC

Lots of good stuff in the documentation
</code> http://docs.oracle.com/docs/cd/B19306_01/server.102/b14231/tspaces.htm#i1006225 <code>

suggestion: never use dictionary managed tablespaces anymore, they are not the way to go and in many current databases, not even an "option" (since a locally managed system tablespace will not allow you to create new dictionary managed ones)

tuning

mike, May 09, 2006 - 2:27 pm UTC

Tom:

based on your steps:
step 1) say out loud "FULL SCANS ARE NOT EVIL"
step 2) say out loud "INDEX ACCESS IS NOT ALL GOODNESS"

1. Can you refer to an article here or your book on how best to make decisions on when you create indexes and what indexes you create and when are full table scans can be good versus bad.

Tom Kyte
May 09, 2006 - 4:39 pm UTC

I have a chapter in Effective Oracle By Design on Efficient SQL. I have chapters on physical data structures in Expert Oracle Database Architecture.

It is more about understanding these structures than having some rule of thumb (ROT) as to when to apply them (for then you won't know when the ROT doesn't apply!)

Understand them - don't try to checklist everything. There are tools that will suggest indexes, we don't need humans for that. If you however understand the "physics" behind the data - you'll find that your own common sense will carry you very very far.



enqueue

mal, May 10, 2006 - 12:28 pm UTC

Following is one snapshot from statspack. Yesterday we had serious issues in our instance 3 :( ...How to avoid enqueue wait events?
Avg
Total Wait wait Waits
Event Waits Timeouts Time (s) (ms) /txn
---------------------------- ------------ ---------- ---------- ------ --------
enqueue 69,582 44,366 21,640 311 2.3
db file sequential read 1,656,599 0 4,188 3 54.3
db file scattered read 431,815 0 2,825 7 14.2
db file parallel read 50,048 0 666 13 1.6
global cache cr request 1,777,545 1,152 470 0 58.3
log file parallel write 54,965 0 106 2 1.8
global cache open x 44,630 37 41 1 1.5
log file sync 29,459 0 38 1 1.0
control file sequential read 57,534 0 34 1 1.9
global cache null to x 40,820 17 27 1 1.3
wait for scn from all nodes 121,674 1 23 0 4.0


Tom Kyte
May 11, 2006 - 8:57 am UTC

don't block yourself!

Most all enqueue waits are self inflicted - they are what happens when you lock a row and someone else wants to lock that same exact row for example.

You can check v$segment_statistics to see if these were ITL waits (fixable by setting mintrans a tad higher on the affected segments) as well.

Stat# or Name for ITL waits

Darrell Spisak, May 11, 2006 - 5:01 pm UTC

In reference to your response to Mal above, you mention ITL waits in v$segment_statistics. I wasn't able to find a stat name containing ITL or interested transaction list. What is the stat# or name for the ITL waits?

Tom Kyte
May 11, 2006 - 8:19 pm UTC

ops$tkyte@ORA10GR2> select distinct statistic_name from v$segment_statistics;

STATISTIC_NAME
----------------------------------------------------------------
gc buffer busy
db block changes
space used
segment scans
gc cr blocks received
gc current blocks received
row lock waits
buffer busy waits
physical reads
physical reads direct
physical writes
space allocated
logical reads
physical writes direct
ITL waits                         <<<<<<<<<<<<<<=====================

15 rows selected.
 

ITL Waits

Greg, May 11, 2006 - 5:40 pm UTC

Darrell - you didn't say what release you're running, but in 9.2.0.3, the STATISTIC_NAME is "ITL waits" and the STATISTIC# is 10.

ITL waits

Darrell, May 12, 2006 - 9:06 am UTC

Doh,

OK, I feel like an idiot.

and value > 0 <======= pesky WHERE clause

Maybe I should have tried removing the WHERE clause before asking a dumb question.

Those WHERE clauses really do filter data.

Look, I've only been working with SQL for 15 years!!!!

PLAN_HASH_VALUE

Matte, May 18, 2006 - 10:12 am UTC

What is the meaning of plan_hash_value=0 in v$sql view?


Tom Kyte
May 19, 2006 - 9:45 am UTC

is the plan still in the shared pool.

9i delete execution plan

A reader, July 13, 2006 - 6:06 pm UTC

Hi Tom

I am migrating from 8i to 9iR2. I noticed that simple delete statements such as

delete emp where empno = 100

changed plan from

0 DELETE STATEMENT Optimizer=CHOOSE
1 0 DELETE OF 'DEPT'
2 1 TABLE ACCESS BY INDEX ROWID
3 2 INDEX (UNIQUE SCAN) OF 'EMP_PK' (UNIQUE)

to

0 DELETE STATEMENT Optimizer=CHOOSE
1 0 DELETE OF 'DEPT'
2 1 INDEX (UNIQUE SCAN) OF 'EMP_PK' (UNIQUE)

What is sort of optimization called? Any way to revert it to old behaviour?

Tom Kyte
July 13, 2006 - 6:25 pm UTC

it does the same thing. nothing wrong. It finds the row to delete via the index.

How about actual explain plan

A reader, August 03, 2006 - 3:27 pm UTC

Hello Tom,
Fantastic Site. Great help to the community !!

How would I view the explain plan of a statement which was executed in the past? How can I view it in 9i and 10g.

Lets say that all I know is :
1) who ran it
2) sql statement
3) Execution time

Please advice.


Tom Kyte
August 03, 2006 - 5:00 pm UTC

if it is in v$sql you can see #2 and #3 - but the "who", that would require auditing (find grained auditing at that to capture the actual SQL)

in 10g, you can use ASH (active session history) if licensed for it as well, that'll get you closer to the "who"

Alberto Dell'Era, August 03, 2006 - 6:05 pm UTC

"A Reader" was asking about the plan :)

Short answer: v$sql_plan joined to v$sql ...

Tom Kyte
August 03, 2006 - 6:50 pm UTC

ahh - I read it wrong indeed. thought all they wanted to know was a) b) c) :)

Alberto Dell'Era, August 03, 2006 - 6:28 pm UTC

In 10g there's also the new wonderful feature of dbms_xplan.display_cursor; since there's only one demo on asktom but for a particular case, here's the most concise one:

dellera@ORACLE10> select * from t where 1=0;

no rows selected

dellera@ORACLE10> select sql_id, child_number from v$sql where sql_text = 'select * from t where 1=0';

SQL_ID CHILD_NUMBER
--------------------------------------- ------------
g0buhmx6r79tu 0

dellera@ORACLE10> select * from table (dbms_xplan.display_cursor ('g0buhmx6r79tu', 0, 'ALL'));

PLAN_TABLE_OUTPUT
-----------------------------------------------------
SQL_ID g0buhmx6r79tu, child number 0
-------------------------------------
select * from t where 1=0

Plan hash value: 1322348184

---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 1 (100)| |
|* 1 | FILTER | | | | | |
| 2 | TABLE ACCESS FULL| T | 1000K| 18M| 4792 (1)| 00:00:58 |
---------------------------------------------------------------------------

Query Block Name / Object Alias (identified by operation id):
-------------------------------------------------------------

1 - SEL$1
2 - SEL$1 / T@SEL$1

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter(NULL IS NOT NULL)

Column Projection Information (identified by operation id):
-----------------------------------------------------------

1 - "T"."X"[VARCHAR2,4000], "T"."RN"[NUMBER,22]
2 - "T"."X"[VARCHAR2,4000], "T"."RN"[NUMBER,22]

Tom Kyte
August 03, 2006 - 6:55 pm UTC

And in 9i:

<quote src=Effective Oracle by Design>

Use DBMS_XPLAN and V$SQL_PLAN

If you edit the script utlxpls.sql in Oracle9i Release 2, you’ll discover it is effectively one-line long:

select plan_table_output
from table( dbms_xplan.display( 'plan_table',null,'serial'))

If you edit that same script in Oracle9i Release 1 or before, you’ll find a huge query. DBMS_XPLAN.DISPLAY is a better method for querying and displaying the plan output. It is a function that simply returns a collection, which is a procedurally formatted EXPLAIN PLAN output, including the supplemental information at the bottom of the report (new in Oracle9i Release 2). This is a side effect of using the new DBMS_XPLAN package. 

So, if you do not have access to the utlxpls.sql script, the simple query shown here will perform the same function. In fact, the DBMS_XPLAN package is so good at adjusting its output based on the inputs that you do not even need to supply the inputs as utlxpls.sql does. This simple line suffices:

select * from table(dbms_xplan.display)

Using this feature coupled with the V$SQL_PLAN dynamic performance view, you can easily dump the query plans for already executed statements, directly from the database. 

In the previous section, I demonstrated how you can use an INSERT into the PLAN_TABLE and then run utlxpls or utlxplp to see the plan. In Oracle9i Release 2, using DBMS_XPLAN and a view you can create, it becomes even easier. If you use a schema that has been granted SELECT privileges on SYS.V_$SQL_PLAN directly, you’ll be able to create this view:

ops$tkyte@ORA920> create or replace view dynamic_plan_table
  2  as
  3  select
  4   rawtohex(address) || '_' || child_number statement_id,
  5   sysdate timestamp, operation, options, object_node,
  6   object_owner, object_name, 0 object_instance,
  7   optimizer,  search_columns, id, parent_id, position,
  8   cost, cardinality, bytes, other_tag, partition_start,
  9   partition_stop, partition_id, other, distribution,
 10   cpu_cost, io_cost, temp_space, access_predicates,
 11   filter_predicates
 12   from v$sql_plan;

View created.

Now, you can query any plan from the database with a single query:

ops$tkyte@ORA920> select plan_table_output
  2    from TABLE( dbms_xplan.display
  3                ( 'dynamic_plan_table',
  4                  (select rawtohex(address)||'_'||child_number x
  5                     from v$sql
  6  where sql_text='select * from t t1 where object_id > 32000' ),
  7                  'serial' ) )
  8  /

PLAN_TABLE_OUTPUT
------------------------------------------------------------------
| Id  | Operation                   | Name|Rows| Bytes |Cst(%CPU)|
------------------------------------------------------------------
|   0 | SELECT STATEMENT            |     |    |       |         |
|   1 |  TABLE ACCESS BY INDEX ROWID| T   |291 | 27936 | 25   (0)|
|*  2 |   INDEX RANGE SCAN          | T_PK|291 |       |  2   (0)|
------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OBJECT_ID">32000)

13 rows selected.

The emphasized text in the code is a query that gets the STATEMENT_ID. In this query, you can use whatever values you want to identify the exact query plan you wanted to review.  The use of this technique, querying the V$ table rather then inserting the contents of V$SQL_PLAN into a “real table” is appropriate if you will be generating the explain plan for this query once.  Access to V$ tables can be quite expensive latch wise on a busy system.  So, if you plan on running the explain plan for a given statement many times over – copying the information to a temporary working table would be preferred.
</quote> 

Thanks .. but

A reader, August 04, 2006 - 10:47 am UTC

Tom/Alberto,
that was very helpful.
But, (9i scenario) if my past statement is aged out of v$sql, then what should my strategy be to obtain the same informaion ?

I was thinking more in the lines of :
1) Capture the contents of the v$sql into a history table (sql_history) periodically (ofcourse inserting distinct hash_value)
2) Purge the contents of sql_history tables every 7 days or so.
3) Then using Tom's query, can obtain the plan.

What do you think of this idea? Your comments are much appreciated.

Tom Kyte
August 04, 2006 - 12:15 pm UTC

sounds like 10g :) that is sort of a builtin feature.

for 9i ?

A reader, August 04, 2006 - 2:06 pm UTC

Right.
But for 9i since this is not a built-in feature, should I use this methodology or is there any other efficient way ?

Alberto Dell'Era, August 04, 2006 - 2:22 pm UTC

> Capture the contents of the v$sql into a history table
> (sql_history) periodically

I've already written the (tedious) code for doing this:
</code> http://tinyurl.com/lnedm <code>
(install with "persistent=y")

it also formats the output using dbms_xplan (similarly to Tom's
dynamic_plan_table), runs in both 9i and 10g. Also records statistics
from v$sql_plan_statistics and v$sql itself.

There's my email on that page, and I'd be more than glad to look into
any problem you may have.

Tom Kyte
August 04, 2006 - 2:54 pm UTC

thanks much!

thats it ..

A reader, August 04, 2006 - 3:01 pm UTC

Alberto/Tom,
Thanks. I looked at your script, will try to install and will give you my feedback. Thx.


Confusing SQL

Kamini, August 06, 2006 - 7:06 am UTC

Hi Tom

I have table A with 7 million records and Table B wtih 0.3 million records. I am simply doing an Inner join between both the tables on a Primary Key Column.

Problem is if I select columns only from Table A it brings back the result faster when compared to selecting columns only from Table B and the difference is more than 5 mins. Why is it so? Explain Plan output is also same for both the queries.

Thanks
Kamini

Tom Kyte
August 06, 2006 - 9:14 am UTC

tkprof it, show us.

problem insert

Karmit, September 01, 2006 - 11:11 am UTC

Hi Tom,

I found that one of our application does this operation quite frequently
(3/4 time a day):

INSERT INTO table1
(table1.col1, table1.col2, ...
)
(SELECT t1.col1, t1.col2, t2.col3, t2.col5, ..., ...
FROM table1 t1, table2 t2
WHERE t1.col1= t2.col2
);


Now, table1 is a biggish table around 40mil records and keeps nearly
stagnant as some other processes do deletes as well.

Also, table2 is around 300K records on average.

(btw, table1 has 4 indexes on it and the explain plan shows one of them being
used for a range scan)

I see that this process runs extremely slow - around 1/2 hours minimum.

I've verified this issue on all our test systems as well (each are on
different storage areas) - so don't think its an issue with the
underlying h/w.


Was wondering whether the following would prove to be a better
technique.

--

INSERT INTO temp1
(temp1.col1, temp1.col2, ...
)
(SELECT t1.col1, t1.col2, t2.col3, t2.col5, ..., ...
FROM table1 t1, table2 t2
WHERE t1.col1= t2.col2
);
followed by:

INSERT INTO table1 select * from temp1 ;

--

Any comments?


Thanks,
Karmit


Tom Kyte
September 01, 2006 - 11:25 am UTC

if this:

SELECT t1.col1, t1.col2, t2.col3, t2.col5, ..., ...
FROM table1 t1, table2 t2
WHERE t1.col1= t2.col2


uses any indexes - that would be a problem, are you using the RBO??!?!?



the "better technique" does not compute to me. I didn't get it.


I think the best way to accomplish this is to comment out the insert into temp1 and turn temp1 into a VIEW. I have no idea why you do this 3/4 times a day.

problem insert

Karmit, September 03, 2006 - 7:02 am UTC

Hi Tom,

Thanks for your reply.

The "better technique" banks on the assumption that the
INSERT and SELECT don't use the index on the table1 at the same
time - though I guess that it shouldn't be much of an issue with
an INSERT updating the index (in fact all 4) and the SELECT reading a copy of the chosen index
from rollback (so.. doesn't sound like a good reason I'm afraid!).

I'm still foxed by why this should take so long (30 min + ).

Its a third party application. To simplify the example I didn't
put another where clause in the below stmt:

(SELECT t1.col1, t1.col2, t2.col3, t2.col5, ..., ...
FROM table1 t1, table2 t2
WHERE t1.col1= t2.col2

which goes like: AND t2.col5= :some_var

The :some_var would be derived from user input via application front
end ultimately (as part of some functionality).

We regularly collect statistics on table1 using DBMS_STATS and
specify FOR ALL INDEXED COLUMNS SIZE 20.

Its definitely not using the RBO.

a) I notice that the SQL uses bind variable :some_var, so I guess the
histogram data collected by us using DBMS_STATS is a waste?!

b) The developer also has put a hint to use one of the indexes on table1!.
You mentioned that if its using indexes then its a problem. Why would
that be? I checked using OEM that the total records inserted by this
execution is around 35K - 40K, which is the number of records resulting
from the SELECT part, which is ~0.1 % of the 40mil+ records in table1.
Will accessing table1 using an index (rather than Full Scan) not be better
in this case?

c) Sorry, didn't undertand how using a view would help? Wouldn't it
do the same SQL internally?

d) I'm trying to figure out the breakup of time per sub-operation, i.e
the INSERT and the SELECT part. Any idea how I can find this (can't
touch the application code though!).

Regards,
Karmit


Tom Kyte
September 04, 2006 - 8:29 am UTC

huh - I've not any idea what you mean about your index comment???

if you have a query such as:

SELECT t1.col1, t1.col2, t2.col3, t2.col5, ..., ...
FROM table1 t1, table2 t2
WHERE t1.col1= t2.col2

and you want it to complete in the least amount of time (not get the first row back fast, but rather get the LAST row back fast) and that query uses an index - then we have a problem!

I don't know what you mean about "using the index at the same time". That doesn't compute

got a tkprof?


my comment about "a view" is temp1 is just a copy of two full tables. I don't see the point, just create a view and don't copy the data.

problem insert

Karmit, September 05, 2006 - 1:11 pm UTC

Hi Tom,

Sorry to be vague about the index explanation I was trying to give. When I look at that insert statement which is selecting and inserting records in the same table (table1), I visualise different segments on different parts of a disk somewhere on the storage system. There are 4 index segments related to table1 which is itself a fifth (data) segment. Now, 1 out of the 4 index segments is
being used by the SELECT subquery to read the data segment (or maybe not - if the index itself contains all the columns required). However, at the same time, when a row is fed back from the SELECT part to the INSERT part of the DML, the table data segment will have a row inserted, and if I understand correctly, Oracle will update all the 4 index segments for table1 - to reflect the change in table data.

Now this is where my vague "thinking"(?) kicks in. Somehow, I feel that there is a contention when the index segment is being used to update the index entry while is also being read by the SELECT part to generate rows (the better part of me seems to think that its reading the index from a rollback - so two different segments? )

Would like to get this "thinking" blown to bits(!) with some logical explanation as to what happens - and why do you think that if its reading an index then its a problem, though the selected data is < 1% of the full table?

Also, does my statement that since its using bind
variables in the WHERE clause, my collecting of histograms on indexed columns of table1 is pointless?

Regards,
Karmit

Tom Kyte
September 05, 2006 - 5:26 pm UTC

the insert you gave me, did not do that (insert into same table).

I'll say it again: if that select uses any indexes, then we have a problem, I want two full scans and a hash join, nothing else makes really good sense.

problem insert

Karmit, September 06, 2006 - 6:16 am UTC

Hi Tom,

Here's the original SQL I gave:

INSERT INTO table1
(table1.col1, table1.col2, ...
)
(SELECT t1.col1, t1.col2, t2.col3, t2.col5, ..., ...
FROM table1 t1, table2 t2
WHERE t1.col1= t2.col2
);


It does select from table1 and insert in table1 - so its the same table.

Also, could you please comment on my other questions in my last post?

Thanks & Regards,
Karmit

Tom Kyte
September 06, 2006 - 7:58 am UTC

ahh, i see now, you gave two original inserts.

I'll say it one last time: IF that select uses an INDEX then you likely have a problem.

the query needs "consistent read", if you are inserting into the table and reading from it at the same time, modifying an index that is being used to read - yes, the amount of work needed to get a consistent read on index blocks over time could increase (depends depends depends depends - a chapter of things that this "depends on" could be here).

But - one last time: index should not be used for that type of query.

problem insert

Karmit, September 06, 2006 - 8:30 am UTC

Hi Tom,

Thanks for your patience.

Sorry but I still don't get it why you say that an index should not be used with "this type" of a SQL? When you say
"this type of SQL" do you mean a type where a table is being selected and inserted into itself using an index?? Or did you mean that comment regardless of the INSERT part?

Since if you mean it regardless of the INSERT part, then
I'll be really confused as all the books (ok 3 only :-) I've read say that an index is the best access path if selecting < 5% of records from a table - and this one does only 0.1%.

Sorry - but really do not get your point here!

Also, could you please kindly glance an eye on one of my
query before...

a) I notice that the SQL uses bind variable :some_var, so I
guess the histogram data collected by us using
DBMS_STATS is a waste?!

Thanks & Regards,
Karmit

Tom Kyte
September 06, 2006 - 3:29 pm UTC

select *
from t1, t2
where t1.key(s) = t2.key(s)

it is HIGHLY unlikely you want any indexes at all to be used in most all cases.

exceptions:

a) you are an interactive application and getting the first row as soon as possible is paramount. You understand however that getting the last row will take longer by using the index.

b) one of t1 or t2 is TINY and the other is HUGE and the result of the join would be a TINY set.




as for your comment on histograms, that is not correct. It is highly UNLIKELY you want histograms, but they are used, search this site for

bind variable peeking

problem insert

Karmit, September 07, 2006 - 11:09 am UTC

Hi Tom,

Thought I should compare the performance by replicating the 
situation with which I'm facing a problem i.e insert into a table while selecting from itself.

The results below show that using the index is 4 times
faster than using FTS - this does not seem to gel with the 
explanation provided in your comments?!

--
15:25:25 SQL> -- Created the first set of tables
15:25:31 SQL> create table test1_fts tablespace MYTEST_TBSP as select * from all_objects ;

Table created.

15:25:54 SQL> create table test1_ids tablespace MYTEST_TBSP as select * from all_objects ;

Table created.

15:25:57 SQL> insert into test1_fts select * from test1_fts;

51900 rows created.

15:26:01 SQL> insert into test1_ids select * from test1_ids;

51901 rows created.

15:26:07 SQL> commit;

Commit complete.

-- 
-- Run the above inserts a few times to populate the tables.
-- 

15:27:41 SQL> -- Created the indexes
15:28:30 SQL> create index idx1_test1_fts on test1_fts(object_id) tablespace MYTEST_TBSP ;

Index created.

15:29:29 SQL> create index idx1_test1_ids on test1_ids(object_id) tablespace MYTEST_TBSP ;

Index created.

15:30:28 SQL> create index idx2_test1_fts on test1_fts(OBJECT_NAME) tablespace MYTEST_TBSP ;

Index created.


15:30:57 SQL> create index idx2_test1_ids on test1_ids(OBJECT_NAME) tablespace MYTEST_TBSP ;

Index created.

15:31:58 SQL> -- Created the second set of tables
15:32:03 SQL> create table test2_fts tablespace MYTEST_TBSP as select * from all_objects where rownum < 5000;

Table created.

15:32:08 SQL> create table test2_ids tablespace MYTEST_TBSP as select * from all_objects where rownum < 5000;

Table created.

15:32:12 SQL> -- Check the counts
15:32:15 SQL> select count(*) from test1_fts;

  COUNT(*)
----------
   1660800

15:32:26 SQL> select count(*) from test1_ids;

  COUNT(*)
----------
   1660832

15:32:34 SQL> select count(*) from test2_fts;

  COUNT(*)
----------
      4999

15:32:36 SQL> select count(*) from test2_ids;

  COUNT(*)
----------
      4999


15:33:11 SQL> -- Run the Insert using the Index Scan method

15:34:03 SQL> insert into test1_ids(
15:34:04   2    OWNER
15:34:04   3   ,OBJECT_NAME
15:34:04   4   ,SUBOBJECT_NAME
15:34:04   5   ,OBJECT_ID
15:34:04   6   ,DATA_OBJECT_ID
15:34:04   7   ,OBJECT_TYPE
15:34:04   8   ,CREATED
15:34:04   9   ,LAST_DDL_TIME
15:34:04  10   ,TIMESTAMP
15:34:04  11   ,STATUS
15:34:04  12   ,TEMPORARY
15:34:04  13   ,GENERATED
15:34:04  14   ,SECONDARY
15:34:04  15  )
15:34:04  16  select
15:34:04  17    t1.OWNER
15:34:04  18   ,t1.OBJECT_NAME
15:34:04  19   ,t1.SUBOBJECT_NAME
15:34:04  20   ,t2.OBJECT_ID
15:34:04  21   ,t2.DATA_OBJECT_ID
15:34:04  22   ,t2.OBJECT_TYPE
15:34:04  23   ,t2.CREATED
15:34:04  24   ,t2.LAST_DDL_TIME
15:34:04  25   ,t2.TIMESTAMP
15:34:04  26   ,t2.STATUS
15:34:04  27   ,t2.TEMPORARY
15:34:04  28   ,t2.GENERATED
15:34:04  29   ,t2.SECONDARY
15:34:04  30  from
15:34:04  31  test1_ids t1, test2_ids t2
15:34:04  32  where t1.object_id = t2.object_id
15:34:04  33    and t1.object_name = t2.object_name
15:34:04  34  ;


159968 rows created.

15:34:16 SQL> 

===> Takes 12 seconds (plan confirms Index scan)



15:35:11 SQL> -- Run the Insert using the FTS method
15:35:17 SQL> insert into test1_fts(
15:35:17   2    OWNER
15:35:17   3   ,OBJECT_NAME
15:35:17   4   ,SUBOBJECT_NAME
15:35:17   5   ,OBJECT_ID
15:35:17   6   ,DATA_OBJECT_ID
15:35:17   7   ,OBJECT_TYPE
15:35:17   8   ,CREATED
15:35:17   9   ,LAST_DDL_TIME
15:35:17  10   ,TIMESTAMP
15:35:17  11   ,STATUS
15:35:17  12   ,TEMPORARY
15:35:17  13   ,GENERATED
15:35:17  14   ,SECONDARY
15:35:17  15  )
15:35:17  16  select /*+ FULL(t1) */
15:35:17  17    t1.OWNER
15:35:17  18   ,t1.OBJECT_NAME
15:35:17  19   ,t1.SUBOBJECT_NAME
15:35:17  20   ,t2.OBJECT_ID
15:35:17  21   ,t2.DATA_OBJECT_ID
15:35:17  22   ,t2.OBJECT_TYPE
15:35:17  23   ,t2.CREATED
15:35:17  24   ,t2.LAST_DDL_TIME
15:35:17  25   ,t2.TIMESTAMP
15:35:17  26   ,t2.STATUS
15:35:17  27   ,t2.TEMPORARY
15:35:17  28   ,t2.GENERATED
15:35:17  29   ,t2.SECONDARY
15:35:17  30  from
15:35:17  31  test1_fts t1, test2_fts t2
15:35:17  32  where t1.object_id = t2.object_id
15:35:17  33    and t1.object_name = t2.object_name
15:35:17  34  ;




159968 rows created.

15:36:08 SQL> 

===> Takes 51 seconds! (plan confirms FTS on t1)

--

Regards,
Karmit 

Tom Kyte
September 07, 2006 - 12:12 pm UTC

please use tkprof - you haven't shown that there were indexes used once and not again. I could put this down to "there was a log switch and checkpoint not complete encountered by query 2 and not query 1 - but the plans were the same"

for on my system, 10gr2, full scan both (and not 51 seconds!)

problem insert

Karmit, September 11, 2006 - 12:37 pm UTC

Hi Tom,


Please find below tkprof snips.


The FULL Scan took ~55 secs this time - slower than the index scan
which took 31 secs.


**** -- TKPROF of the FULL Scan -- ****

TKPROF: Release 9.2.0.4.0 - Production on Mon Sep 11 16:05:19 2006

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: test_ora_fullscan.trc
Sort options: exeela
********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

insert into test1_fts(
OWNER
,OBJECT_NAME
,SUBOBJECT_NAME
,OBJECT_ID
,DATA_OBJECT_ID
,OBJECT_TYPE
,CREATED
,LAST_DDL_TIME
,TIMESTAMP
,STATUS
,TEMPORARY
,GENERATED
,SECONDARY
)
select /*+ FULL(t1) */
t1.OWNER
,t1.OBJECT_NAME
,t1.SUBOBJECT_NAME
,t2.OBJECT_ID
,t2.DATA_OBJECT_ID
,t2.OBJECT_TYPE
,t2.CREATED
,t2.LAST_DDL_TIME
,t2.TIMESTAMP
,t2.STATUS
,t2.TEMPORARY
,t2.GENERATED
,t2.SECONDARY
from
test1_fts t1, test2_fts t2
where t1.object_id = t2.object_id
and t1.object_name = t2.object_name

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 3 0 0
Execute 1 11.43 55.72 65307 72134 1247283 159968
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 11.43 55.73 65307 72137 1247283 159968

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS

Rows Row Source Operation
------- ---------------------------------------------------
159968 HASH JOIN (cr=46930 r=54131 w=4278 time=8522603 us)
4999 TABLE ACCESS FULL TEST2_FTS (cr=150 r=22 w=0 time=4704 us)
1661952 TABLE ACCESS FULL TEST1_FTS (cr=45838 r=45684 w=0 time=5478441 us)

********************************************************************************




**** -- TKPROF of the Index based Scan -- ****

TKPROF: Release 9.2.0.4.0 - Production on Mon Sep 11 17:21:16 2006

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.

Trace file: test_ora_idxscan.trc
Sort options: exeela
********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

insert into test1_ids(
OWNER
,OBJECT_NAME
,SUBOBJECT_NAME
,OBJECT_ID
,DATA_OBJECT_ID
,OBJECT_TYPE
,CREATED
,LAST_DDL_TIME
,TIMESTAMP
,STATUS
,TEMPORARY
,GENERATED
,SECONDARY
)
select
t1.OWNER
,t1.OBJECT_NAME
,t1.SUBOBJECT_NAME
,t2.OBJECT_ID
,t2.DATA_OBJECT_ID
,t2.OBJECT_TYPE
,t2.CREATED
,t2.LAST_DDL_TIME
,t2.TIMESTAMP
,t2.STATUS
,t2.TEMPORARY
,t2.GENERATED
,t2.SECONDARY
from
test1_ids t1, test2_ids t2
where t1.object_id = t2.object_id
and t1.object_name = t2.object_name

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 7.71 31.80 25341 561992 224681 159968
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 7.71 31.81 25341 561992 224681 159968

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: SYS

Rows Row Source Operation
------- ---------------------------------------------------
159968 NESTED LOOPS (cr=536435 r=17307 w=0 time=13231317 us)
4999 TABLE ACCESS FULL TEST2_IDS (cr=150 r=133 w=0 time=14714 us)
159968 TABLE ACCESS BY INDEX ROWID TEST1_IDS (cr=536285 r=17174 w=0 time=13085786 us)
159968 AND-EQUAL (cr=376317 r=12461 w=0 time=10148678 us)
319936 INDEX RANGE SCAN IDX1_TEST1_IDS (cr=344791 r=12270 w=0 time=9059643 us)(object id 324128)
159968 INDEX RANGE SCAN IDX2_TEST1_IDS (cr=31526 r=191 w=0 time=744990 us)(object id 324130)

********************************************************************************

Regards,
Karmit

Tom Kyte
September 11, 2006 - 1:52 pm UTC

it got pinged on some physical IO that the other query did not.

overall, if you look at the query mode gets - it chose the plan it was supposed to, especially in 9i.

problem insert

Karmit, September 11, 2006 - 2:44 pm UTC

Hi,

I'm not questioning which plan it chose.

My point was that the index scan is faster than full scan -
contrary to previous discussion.

I have run this test 10 times and on different 9i boxes -
and all of the times the index scan was much faster, so I don't think its a one-off i/o ping issue.

Thanks for your time and patience.

Regards,
Karmit

Tom Kyte
September 11, 2006 - 3:00 pm UTC

because of the size of your buffer cache, the amount of physical IO that took place in this case.

do you see the physical IO's there???

problem insert

Karmit, September 12, 2006 - 4:47 am UTC

Hi Tom,

Do you mean to say that as there is not enough buffer cache
left, the table is not able to fit into the cache in one go, and as such multiple reads/ swaps are required from the disk to complete the FULL scan?

Please elaborate.

Regards,
Karmit

Tom Kyte
September 12, 2006 - 8:33 am UTC

look at the tkprof
see the disk reads

problem insert

A reader, September 12, 2006 - 9:12 am UTC

Hi,

For the FULL scan the disk reads are 65307 blocks
i.e around 500MB (8KB block size)

For the INDEX scan the disk reads are ~25000 blocks

But isn't that expected? I would imagine the FULL scan to read more blocks, and rightly so.

Apologies! you've lost me again.

Regards,
Karmit

Tom Kyte
September 12, 2006 - 9:18 am UTC

Look - I said "in general, when you have a query of that type, it would not be wise to use a single index, if you were using an index, I would look into that as it is in general not appropriate".

I gave some counter cases to that as well (based on relative table sizes)

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:6749454952894#6760861174154 <code>

There, now, would you like to use the index for that query?

Why do you "imagine" the full scan to read more blocks - in general, for a query of that type, it would just "not be so"

problem insert

Karmit, September 12, 2006 - 9:46 am UTC

Hi Tom,

Why would I imagine a full scan to read more blocks than index scan?

Well.. because I guess the name implies so?!

* FULL scan - scan ALL the blocks of the table.

* INDEX scan - scan the index, which invariably is of a
much smaller size than the table segment itself.

Scanning a larger segment means that it will take longer (plus more chances of going to disk) as opposed to a shorter index segment lookup.

I'll be stumped if you say "in general, for a query of that type, it would just not be so" (by the way, still cannot understand your "type" casting).

In that case I'll question the use of any indexes - why would Oracle build index technology at all (sorry just thinking aloud!)


Regards,
Karmit

Tom Kyte
September 12, 2006 - 11:00 am UTC

if you have to read all of the rows in a table, which is going to do less logical IO in general:

a) a full scan of the table
b) read an index block, get a rowid, read a table block. Repeat over and over for EVERY row in the table (did you, well, read the example I linked to?)


the index scan, well, that sort of leads straight back to the table, doesn't it.


My type casting is:

select * from t1, t2 where <join condition>;

the presumption:

every row in T1 will be read
every row in T2 will be read
Reading every row in a table via an index scan is "not smart"

indexes are good for getting "very small sets from very large sets"

If you get a very large set from a very large set, you don't want to use an index to do so.


Would you read a book via the index? No, you would full scan the book.

Would you use an index to find material related to "locking" in the concepts guide? Sure.

problem insert

Karmit, September 13, 2006 - 5:30 am UTC

Hi Tom,

I think I am beginning see your point now, however two
issues from your comments:

"
b) read an index block, get a rowid, read a table block.
Repeat over and over for EVERY row in the table (did
you, well, read the example I linked to?)
"
==> Why would it go over and over for "EVERY row in the
table"? If I have an index on column A, the index
entries for a particular value of column A will be in
a sequence. If my SQL uses a WHERE clause to filter on
a particular value of column A - only THOSE rows be
read from the table (if need be). Right?
(Yes. I did go through the link. Thanks)

Secondly -

"the index scan, well, that sort of leads straight back to the table, doesn't it."

==> Well... not always. If the required values are in the
index itself then there is no need to go to the table.
Right?


Regards,
Karmit


Tom Kyte
September 13, 2006 - 2:34 pm UTC

I was talking about a query of the form:

select * from t1, t2 where t1.key = t2.key;

In general - You will get every row from both of t1 and t2 (i gave exceptions as well to this). If you get every row - there is no predicate, you

a) get row from t1 (via full scan)
b) do index range scan on t2_idx to find row in t2
c) do table access by index rowid to find row in t2 based on index in b)
d) GOTO A OVER AND OVER AND OVER

secondly:

of course, but look at the query, they were not all in the index, in general they are NOT all in the index.

SQL Tuning

B Smith, September 15, 2006 - 12:39 pm UTC

Hi Tom,

In connection to an earlier thread in this page about "order by desc", ...

How would you go about designing schema and subsequent query performance tuning in following situation -

# Just one table is there with 45 Million records.
# This table has just 3 columns
Artist1 Number(38)
Artist2 Number(38)
Cnt Number(38)
Also note that artist1 and artist2 combination is going to be unique.

The ONLY final query that is going to be run on this table with 45Million records is this -

select *
from (
SELECT *
FROM (
SELECT artist1,artist2,cnt
FROM mytable
WHERE ( artist1 = 19 or artist2 = 19)
)
ORDER BY STRENGTH DESC
)
where rownum <= 25;

Note that again the static value being used in this query (19) is going to be any number but same for both artist1 and artist2. Also it is always going to get first 25 records only).

The idea is to have maximum performance, no worries about table design or indexes since batch load on
this table is just going to be once a week.

Just had couple of doubts,

1) Is it good to have this table hash partitioned on artist1 and artist2, having unique index on artist1 and artist2.
2) Can cnt be part of any index in this scenerio. How exactly should I index.

Your advice/guidance is highly appreciated.

Regards,

B Smith.

Tom Kyte
September 15, 2006 - 1:52 pm UTC

question - how many rows will


SELECT artist1,artist2,cnt
FROM mytable
WHERE ( artist1 = 19 or artist2 = 19)

in general return?

and what is the relevance of artist1 vs artist2 - is there any meaning to the pairing (eg: if artist1=19, artist2=25 is in there, is it OK to have artist1=25,artist1=19 as well?)

and what is "strength"?

what is performance?

scott, September 16, 2006 - 12:40 am UTC

"The idea is to have maximum performance"

What is maximum performance? Who is setting the criteria to measure performance - is it the end user? Is performance measured by wall clock time?

How many users will be asking this question (submitting the query), and how often? What is the end user expectation regarding performance /response time?


Tom Kyte
September 16, 2006 - 2:39 pm UTC

I think they defined that - they want the response time of that frequently executed query to be minimized.



SQL Tuning

B Smith, September 16, 2006 - 3:11 am UTC

Many thanks Tom for quick reply, and sorry to have missed points that you raised. The answers are -

1) question - how many rows will
SELECT artist1,artist2,cnt
FROM mytable
WHERE ( artist1 = 19 or artist2 = 19)
in general return?

Answer is depends on the artist id chosen. So the general data trend is that in all there are 45 million records in table. In that we have all combination of artists. So above query returns about 20,000 records (for id 19). Now there might be other artist (e.g. if in above we replace 19 with artist id 125670) combinations where it might just return about 20 rows. So In General, on average, the above query will return about 5000 records, however as I said it might be more or less depending on artist id chosen. However, as previously mentioned, in my where condition, I will always be using the same number for both artist1 and artist2.

2) and what is the relevance of artist1 vs artist2 - is there any meaning to the
pairing (eg: if artist1=19, artist2=25 is in there, is it OK to have
artist1=25,artist1=19 as well?)

Answer - The data built up in table is such that Artist1 and Artist2 pair will always follow the rule that artist1 < artist2 (from least to greatest). Also artist1 <> artist2. This is the reason I have put a unique constraint on their combination (artist1,artist2). Hence a record with artist1 = 25 amd artist2 = 19 is not present.

3) what is "strength"
Answer - "strength" is actually CNT (the third column), my mistake. So the query is -

select *
from (
SELECT *
FROM (
SELECT artist1,artist2,cnt
FROM mytable
WHERE ( artist1 = 19 or artist2 = 19)
)
ORDER BY CNT DESC
)
where rownum <= 25;

Regarding queries raised by reviewer SCOTT,
1) Yes the idea is to have max performance, the response time I am looking at is <= 2 sec (if possible). This is the target given to us by management. So yes the perfomance is based on wall clock time.
2) There would be many users asking this query - about 100 - 400 (on the max) once it goes in production.

Tom, thank you for your time on this.

Regards,

B Smith.

Tom Kyte
September 16, 2006 - 2:51 pm UTC

I think, something like:
select *
from (
select *
from(
select * from
(select * from mytable where artist1 = :bv order by cnt desc, artist2 desc)
where rownum <= 25
UNION ALL
select * from
(select * from mytable where artist2 = :bv order by cnt desc, artist1 desc)
where rownum <= 25
) order by cnt desc
)
where rownum <= 25;

and an index on artist1, cnt, artist2
and an index on artist2, cnt, artist1

would minimize the work. We'd get 25 records max from each index using a range scan (should be 1, maybe 2 leaf blocks at most each) and then sort the resulting set of up to 50 records and pull 25.

Either that, or use an IOT and double the size of the table and store

(19,25,...)
(25,19,...)

store it backwards and forwards so you can just:

select * from (
select * from t where artist1 = :bv order by cnt desc, artist2 desc
) where rownum <= 25;

I'd benchmark it to make sure what I'm assuming holds up ;) But those are the two ideas I would look at first.

Tuning update

a reader, September 19, 2006 - 8:46 am UTC

I have a table T1 which has 65 million records. It has no index. It is range partitioned on column COL1 (a number column). Few columns in this table are not populated.

I have another table T2 which has 1 million records. I want to compare T1 and T2 tables based on column COL2. If there are any match then update T1 table with the columns from T2. If the records in T2 than don't exist in T1 then I want to create these entries in table T1. I am using 10g database.

In order to achieve this, I used MERGE statement. It has been running for long time now (around 4 hours). I have copied the runtime execution plan. Please could you

1. Explain why it is taking that long and
2. Advise on tuning this query.

---------------------------------------------------------------------------------
|Id| Operation | Name | Rows | Bytes |Cost(%CPU)| Pstart| Pstop |
---------------------------------------------------------------------------------
|0 | MERGE STATEMENT | | | | 29G(100)| | |
|1 | MERGE | T1 | | | | | |
|2 | VIEW | | | | | | |
|3 | NESTED LOOPS OUTER | | 6830M| 1399G| 29G (6)| | |
|4 | TABLE ACCESS FULL | T2 | 1036K| 63M| 1597 (5)| | |
|5 | PARTITION RANGE ALL| | 6590 | 1003K| 28714 (6)| 1 | 100 |
|6 | VIEW | | 6590 | 1003K| 28714 (6)| | |
|*7 | TABLE ACCESS FULL| T1 | 6590 | 308K| 28714 (6)| 1 | 100 |
---------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

7 - filter("T1"."COL2"="T2"."COL2")


Thank you for your help.


blurred View

Karmit, September 19, 2006 - 12:47 pm UTC

Hi Tom,

We have 2 tables (both tables have the exact same structure)
and a view as follows:

a) TICKET_CURRENT_DAT - holds data for current month only.
b) TICKET_ARCHIVE_DAT - holds data for rolling 2 years.
c) VW_TICKET_ALL - is the view and is made by a simple
SELECT * FROM.. and UNION of both the DAT tables.

The end user has been given the view VW_TICKET_ALL to access, and I see a lot of queries which go like:

SELECT ...
FROM VW_TICKET_ALL
WHERE TIMESTAMP > SYSDATE - 15

and so on...

Now, these type of queries take ages, because of
selecting from the view which does a UNION ALL and inspite
of the end-user trying to restrict the data by date (or other predicates), the UNION ALL is performed as the first step in the plan anyway - which does a FTS of both base
tables.

Am I correct in saying that there is no way to tune these queries without rewriting these queries to individually
accessing the base tables rather than the view?

Idea being that, by individual access to the table we could
(optionally) provide hints and also the CBO can choose a better access path depending upon the predicates.

Please comment.

Regards,
Karmit


Tom Kyte
September 19, 2006 - 2:53 pm UTC

c) hope you mean simple UNION ALL- to avoid the distinct that UNION implies!!!

given that - as described - no one could really tell that the date column would not 'know' that the data in the view doesn't apply... and we don't know what the tables or anything looks like...



Lev, September 19, 2006 - 4:18 pm UTC

If you partition these tables by date this query will probably run faster.

Lev

CASE WHEN

Su Baba, September 19, 2006 - 7:00 pm UTC

The example below shows that the 2 SQLs executed have the same query plan. The only difference is that the 2nd query which uses CASE WHEN uses a lot more logical IOs. Is there any reaason that the plan does not show the subquery that's inside the CASE WHEN statement? Is there a more efficient way to write the second query?

CREATE TABLE x AS
SELECT object_id, object_name
FROM all_objects;

CREATE SEQUENCE y_seq START WITH 1;

CREATE TABLE y AS
SELECT y_seq.NEXTVAL y_id, object_id,
DECODE(MOD(object_id, 3), 0, 'Y', 'N') key_flag
FROM all_objects;

INSERT INTO y
SELECT y_seq.NEXTVAL, object_id,
DECODE(MOD(object_id, 5), 0, 'Y', 'N') key_flag
FROM all_objects;

commit;

ALTER TABLE x ADD CONSTRAINT x_pk PRIMARY KEY (object_id);
CREATE INDEX x_n1 ON x(object_Name);

ALTER TABLE y ADD CONSTRAINT y_pk PRIMARY KEY (y_id);


exec dbms_stats.gather_table_stats( user, 'X', cascade => TRUE);
exec dbms_stats.gather_table_stats( user, 'Y', cascade => TRUE);


SELECT *
FROM (SELECT temp.*, rownum rownumber
FROM (SELECT object_id, object_name
FROM x
ORDER BY object_name DESC
) temp
WHERE rownum <= 50
)
WHERE rownumber >= 1;

----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 50 | 2150 | 26 (0)|
|* 1 | VIEW | | 50 | 2150 | 26 (0)|
|* 2 | COUNT STOPKEY | | | | |
| 3 | VIEW | | 50 | 1500 | 26 (0)|
| 4 | TABLE ACCESS BY INDEX ROWID| X | 41461 | 1214K| 26 (0)|
| 5 | INDEX FULL SCAN DESCENDING| X_N1 | 50 | | 2 (0)|
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("ROWNUMBER">=1)
2 - filter(ROWNUM<=50)


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
25 consistent gets
0 physical reads
0 redo size
2732 bytes sent via SQL*Net to client
414 bytes received via SQL*Net from client
5 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
50 rows processed


SELECT *
FROM (SELECT temp.*, rownum rownumber
FROM (SELECT object_id, object_name,
CASE WHEN object_id IN (SELECT object_id FROM y WHERE key_flag = 'Y')
THEN 'Yes' ELSE 'No'
END Matched
FROM x
ORDER BY object_name DESC
) temp
WHERE rownum <= 50
)
WHERE rownumber >= 1;

Execution Plan
----------------------------------------------------------

----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 50 | 2300 | 26 (0)|
|* 1 | VIEW | | 50 | 2300 | 26 (0)|
|* 2 | COUNT STOPKEY | | | | |
| 3 | VIEW | | 50 | 1650 | 26 (0)|
| 4 | TABLE ACCESS BY INDEX ROWID| X | 41461 | 1214K| 26 (0)|
| 5 | INDEX FULL SCAN DESCENDING| X_N1 | 50 | | 2 (0)|
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("ROWNUMBER">=1)
2 - filter(ROWNUM<=50)


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
8923 consistent gets
0 physical reads
0 redo size
2949 bytes sent via SQL*Net to client
414 bytes received via SQL*Net from client
5 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
50 rows processed




Tom Kyte
September 20, 2006 - 2:51 pm UTC

because not all subqueries used in procedural like processes as you are doing appear in the plan, they are part of the "function that is case", not really part of the overall query plan itself.


the indexing on Y does not see to be well thought out given the query being asked?

blurred View

Karmit, September 20, 2006 - 2:29 am UTC

Hi Tom,

Yes, it does a UNION ALL.

The view looks like below:

( TICKET_NUMBER NUMBER
CODEVAL VARCHAR2(20)
C_INTERFACE VARCHAR2(40)
TIMESTAMP DATE
SOURCE_SYS NUMBER
TARGET_SYS NUMBER
C_USERNAME VARCHAR2(30)
)

Question is - is the only way to tune these SQL is to re-write them, so that they access the individual base tables
rather than the view?

To Lev,
Even if we partition the underlying tables by date, will a
query on the view use partition pruning? (I don't think so)

Thanks,
Karmit

Tom Kyte
September 20, 2006 - 3:02 pm UTC

it would use partition pruning.

partitioning would definitely be a valid approach. And help with the 'aging' of data problem you have.

what I meant by the tables was - well - the ddl, including indexes for example....

but partitioning would definitely be something to consider (no VIEW, no TWO TABLE, just a table)



Tuning update

a reader, September 20, 2006 - 4:30 am UTC

I have a table T1 which has 65 million records. It has no index. It is range
partitioned on column COL1 (a number column). Few columns in this table are not
populated.

I have another table T2 which has 1 million records. I want to compare T1 and T2
tables based on column COL2. If there are any match then update T1 table with
the columns from T2. If the records in T2 than don't exist in T1 then I want to
create these entries in table T1. I am using 10g database.

In order to achieve this, I used MERGE statement. It has been running for long
time now (around 4 hours). I have copied the runtime execution plan. Please
could you

1. Explain why it is taking that long and
2. Advise on tuning this query.

Query:

MERGE INTO T1
USING T2
ON (T1.COL2 = T2.COL2)
WHEN MATCHED THEN
UPDATE
SET
t1.col3 = t2.col3, t1.col4 = t2.col4,
t1.col5 = t2.col5, t1.col6 = t2.col6,
t1.col7 = t2.col7, t1.col8 = t2.col8,
t1.col9 = t2.col9
WHEN NOT MATCHED THEN
INSERT (
t1.col1, t1.col2, t1.col3, t1.col4,
t1.col5, t1.col6, t1.col7, t1.col8,
t1.col9)
VALUES (
t2.col1, t2.col2, t2.col3, t2.col4,
t2.col5, t2.col6, t2.col7, t2.col8,
t2.col9);


---------------------------------------------------------------------------------

|Id| Operation | Name | Rows | Bytes |Cost(%CPU)| Pstart| Pstop
|
---------------------------------------------------------------------------------

|0 | MERGE STATEMENT | | | | 29G(100)| |
|
|1 | MERGE | T1 | | | | |
|
|2 | VIEW | | | | | |
|
|3 | NESTED LOOPS OUTER | | 6830M| 1399G| 29G (6)| |
|
|4 | TABLE ACCESS FULL | T2 | 1036K| 63M| 1597 (5)| |
|
|5 | PARTITION RANGE ALL| | 6590 | 1003K| 28714 (6)| 1 | 100
|
|6 | VIEW | | 6590 | 1003K| 28714 (6)| |
|
|*7 | TABLE ACCESS FULL| T1 | 6590 | 308K| 28714 (6)| 1 | 100
|
---------------------------------------------------------------------------------


Predicate Information (identified by operation id):

---------------------------------------------------

7 - filter("T1"."COL2"="T2"."COL2")


Thank you for your help.


Tuning Merge

a reader, September 21, 2006 - 10:07 am UTC

Tom,

Please could you reply to my queries above (related to tuning MERGE statement).

Thanks


Tuning Merge statement

A Reader, September 24, 2006 - 5:27 pm UTC

Any suggestions for tuning the above merge statement?


Tom Kyte
September 25, 2006 - 2:20 am UTC

well, I cannot reproduce your plan and it is a strange one. I cannot see why it is using the slow by slow approach here with nested loops. I get a nice juicy plan like this:



Execution Plan
----------------------------------------------------------
Plan hash value: 3084598981

------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%C
------------------------------------------------------------------------
| 0 | MERGE STATEMENT | | 65M| 18G| | 564K
| 1 | MERGE | T1 | | | |
| 2 | VIEW | | | | |
|* 3 | HASH JOIN OUTER | | 65M| 12G| 106M| 564K
| 4 | TABLE ACCESS FULL | T2 | 1000K| 95M| | 3183
| 5 | PARTITION RANGE ALL| | 65M| 6198M| | 206K
| 6 | TABLE ACCESS FULL | T1 | 65M| 6198M| | 206K
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

3 - access("T1"."COL2"(+)="T2"."COL2")


which is what I expect.


So, what non-default optimizer parameters do you have set - let's see the output of:

select name, value from v$parameter where isdefault='FALSE';


Tuning merge statement

A reader, September 25, 2006 - 10:13 am UTC

NAME VALUE
----------------------------------- ------------------------------------------------------------
processes 300
sessions 335
timed_statistics TRUE
resource_limit TRUE
event 10262 trace name context forever, level 4000
sga_max_size 1069547520
pre_page_sga TRUE
lock_sga FALSE
shared_pool_size 264241152
large_pool_size 83886080
java_pool_size 67108864
streams_pool_size 50331648
nls_language AMERICAN
nls_territory AMERICA
nls_date_format DD-MON-RR
disk_asynch_io FALSE
tape_asynch_io TRUE
dbwr_io_slaves 0
backup_tape_io_slaves TRUE
resource_manager_plan system_plan
control_files /export/data/redo1/ATSMETL1/ctl1ATSMETL1.ctl, /export/data/r
edo3/ATSMETL1/ctl3ATSMETL1.ctl

control_file_record_keep_time 14
db_block_checksum true
db_block_size 16384
db_cache_size 536870912
db_keep_cache_size 62914560
db_writer_processes 8
db_cache_advice READY
compatible 10.2.0.1.0
log_archive_dest
log_archive_dest_1 LOCATION=/export/data/archives/ATSMETL1/atsmetl1_ MANDATORY
log_archive_dest_state_1 ENABLE
log_archive_max_processes 2
log_archive_trace 0
log_archive_format log%t_%s_%r.arc
log_buffer 2136064
db_files 1024
db_file_multiblock_read_count 32
fast_start_mttr_target 180
log_checkpoints_to_alert TRUE
recovery_parallelism 4
dml_locks 5000
undo_management AUTO
undo_tablespace undo
undo_retention 10800
fast_start_parallel_rollback false
db_block_checking TRUE
_kgl_large_heap_warning_threshold 8388608
remote_os_authent FALSE
remote_login_passwordfile EXCLUSIVE
db_domain ARTLESS
global_names FALSE
distributed_lock_timeout 60
instance_name ATSMETL1
service_names ATSMETL1.ARTLESS
dispatchers (PROTOCOL=TCP) (SERVICE=ATSMETL1XDB)
local_listener list_102
cursor_space_for_time FALSE
session_cached_cursors 200
utl_file_dir *
job_queue_processes 4
cursor_sharing similar
parallel_min_servers 8
parallel_max_servers 32
background_dump_dest /app/oracle/admin/ATSMETL1/bdump
user_dump_dest /app/oracle/admin/ATSMETL1/udump
max_dump_file_size 1048576
core_dump_dest /app/oracle/admin/ATSMETL1/cdump
session_max_open_files 30
open_links 100
audit_trail TRUE
sort_area_size 10485760
sort_area_retained_size 10485760
db_name ATSMETL1
open_cursors 500
os_authent_prefix
optimizer_mode CHOOSE
query_rewrite_enabled TRUE
pga_aggregate_target 1610612736
workarea_size_policy AUTO
statistics_level TYPICAL


Tom Kyte
September 25, 2006 - 3:12 pm UTC

what are the events for?
why the _ parameter?
you DO UNDERSTAND what a very very very bad idea utl_file_dir like that is right? I mean - wow, that is a really bad bad idea
cursor_sharing similar??????? ouch, that hurts, just just plain HURTS.

i really suggest you immediately get rid of utl_file_dir, that is just a really bad thing.

I'll try to reproduce in a couple of days (traveling and all) but can you do this for me:

a) verify your version and OS
b) try creating your table and using dbms_stats.set table stats on a test system WITH DEFAULT INIT.ORA SETTINGS see what plan you get?

Alberto Dell'Era, September 25, 2006 - 3:26 pm UTC

_kgl_large_heap_warning_threshold is an innocent parameter; this undocumented parameter is ... documented ;) in note 330239.1.

It just changes some warning traces...

Tom Kyte
September 26, 2006 - 2:04 am UTC

(i know what they all are, I'm just wondering if the people running the system know what they all are)

Tuning merge statement

a reader, September 26, 2006 - 11:20 am UTC

events - 10026 event was setup a while ago to trace a memory leakage issue. forgot to take it out as it is now resolved. i will take it out.

_kgl_large_heap_warning_threshold - this parameter was setup because we kept getting the warning messages in the alert log. there was a reason for it at the time. would you recommend not to set this on production database?

cursor_sharing - didn't know that this was set to similar. i shall change it to EXACT.

utl_file_dir - this database is used for development. the software is being developed by a third party supplier, hence utl_file_dir has been set to '*'. the supplier have multiple developers using this environment and they keep coming back with different directories to be added to the list. our recommendation of using DIRECTORY objects has been declined because of known political reasons. i do realise that this is not a good practice and we follow the standards. i totally agree with you, it is a security hole.

regarding os, its SunOS, Release = 5.8, KernelID = Generic_117350-38.

unfortunately i do not have an environment to test this using the default init ora parameters (all the envs are being used). i shall try it as soon as i can. apparently i setup the table stats (T1 to 65,000,000 rows and T2 to 1,000,000 rows) with cursor_sharing EXACT at session level. it still comes back with the same execution plan.


Tom Kyte
September 26, 2006 - 4:48 pm UTC

... using DIRECTORY objects has been declined because of known political reasons
...

no, for "stupidity" reasons, for "reasons of ignorance".. Please don't say "political", that might have reason behind it. "for lack of thinking" that would be OK.

I shall try to try your example in the morning.

Odd execution plan

Jonathan Lewis, September 26, 2006 - 5:27 pm UTC

The rowsource for the 'second table' is a view, derived from the partitioned table. Since there is no view name, I think it has to be an internally generated view (? is there a security predicate on the table) creating a non-mergeable view with a non-pushable predicate.

That still leaves the puzzle about why the filter doesn't show an "outer" comparison like: filter("T1"."ID"="V1"."ID"(+))


Tom Kyte
September 26, 2006 - 5:51 pm UTC

I concurr (but did not thing about FGAC, note to self...)

guess I would like the DDL for the underlying objects even more now... Please TRIM the example, we don't need all N thousand partitions, just a few will do...

Tuning merge statement

A reader, September 27, 2006 - 5:36 am UTC

Thanks Tom and Jon.

No FGAC has been defined on any of these tables. I am the culprit here.

I am embarassed that I stripped out few things in the process of replacing original table names with T1 and T2. What I mistakenly stripped out was a predicate. Please see below the correct merge statement and the execution plan without any stripping. Please note that I did not intend to mislead you, I just did not think straight, silly me...

Sorry Tom, I haven't supplied the DDL with this note as I hope that the predicate that I missed earlier may explain the execution plan. I can certainly supply the DDL if you still want it (with the original table names).

I know it was on my part to supply you lack of details but could you do the honours of explaining the reason for slow running of the query and or choosing this execution plan.

MERGE INTO T1
USING T2
ON (T1.COL2 = T2.COL2 and T2.col3 in ('I', 'U'))
WHEN MATCHED THEN
UPDATE
SET
t1.col3 = t2.col3, t1.col4 = t2.col4,
t1.col5 = t2.col5, t1.col6 = t2.col6,
t1.col7 = t2.col7, t1.col8 = t2.col8,
t1.col9 = t2.col9
WHEN NOT MATCHED THEN
INSERT (
t1.col1, t1.col2, t1.col3, t1.col4,
t1.col5, t1.col6, t1.col7, t1.col8,
t1.col9)
VALUES (
t2.col1, t2.col2, t2.col3, t2.col4,
t2.col5, t2.col6, t2.col7, t2.col8,
t2.col9);


---------------------------------------------------------------------------------
|Id| Operation | Name | Rows | Bytes |Cost(%CPU)| Pstart| Pstop
|
--------------------------------------------------------------------------------
|0 | MERGE STATEMENT | | | | 29G(100)| |
|
|1 | MERGE | T1 | | | | |
|
|2 | VIEW | | | | | |
|
|3 | NESTED LOOPS OUTER | | 6830M| 1399G| 29G (6)| |
|
|4 | TABLE ACCESS FULL | T2 | 1036K| 63M| 1597 (5)| |
|
|5 | PARTITION RANGE ALL| | 6590 | 1003K| 28714 (6)| 1 | 100
|
|6 | VIEW | | 6590 | 1003K| 28714 (6)| |
|
|*7 | TABLE ACCESS FULL| T1 | 6590 | 308K| 28714 (6)| 1 | 100
|
---------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
7 - filter(("T1"."COL2"="T2"."COL2" AND INTERNAL_FUNCTION("T2"."COL3")))



Tom Kyte
September 27, 2006 - 7:15 am UTC

give me short DDL, rather not look at it until I see that.

by short I mean - well - short.

best would be:

create this table
create that table
use dbms_stats.set_table_stats like this for first table
use dbms_stats.set_table_stats like this for other table
run this merge

and... just a thought, what does:

MERGE INTO T1
USING (select * from t2 where col3 in ('I','U') ) T2
ON (T1.COL2 = T2.COL2)
WHEN MATCHED THEN.....

do for you?

Any suggestions

Rambabu, September 27, 2006 - 7:35 am UTC

Sir,

What could be the reason for cost being so high? Will rewriting help this? I have analyzed the tables.




SELECT /*+ PARALLEL 4 */ PRODUCT_BACKORDERS.SBN as SBN,
PRODUCT_BACKORDERS.DOC_REF as DocumentRef,
PRODUCT_BACKORDERS.ENT_BATCH_NO as BatchNo,
PRODUCT_BACKORDERS.ENT_DOC_NO as DocumentNo,
PRODUCT_BACKORDERS.ENT_LINE_NO as LineNo,
PRODUCT_BACKORDERS.TDD_CUST as CustomerId,
PRODUCT_BACKORDERS.SBN as ProductId,
PRODUCT_BACKORDERS.CUST_REF as PurchaseOrder,
PRODUCT_BACKORDERS.DOC_DATE as DocumentDate,
PRODUCT_BACKORDERS.DOC_TYPE as DocumentTypeCode,
PRODUCT_BACKORDERS.REC_STA as OrderStatus,
PRODUCT_BACKORDERS.SUPPLY_SITE as SiteCode,
PRODUCT_BACKORDERS.INV_C_N_PRO as BackorderTypeCode,
PRODUCT_BACKORDERS.DUE_QTY as Quantity,
PRODUCT_BACKORDERS.BRICK as BrickCode,
PRODUCT_BACKORDERS.SOURCE as OrderSourceCode,
PRODUCT_BACKORDERS.DUE_MONTHS as DueMonths,
PRODUCT_BACKORDERS.CURRENCY as CurrencyCode,
PRODUCT_BACKORDERS.PUB_VAL as OrderValue,
PRODUCT_BACKORDERS.DISC_PERC as Discount,
PRODUCT_BACKORDERS.NET_VAL as NetValue,
PRODUCT_BACKORDERS.CUST_REF as OrderReference,
PRODUCT_BACKORDERS.OPERATOR as OperatorCode,
PRODUCT_BACKORDERS.REP_CODE as RepCode,
CUSDUE.CUST As OverriddenAddress,
PRODUCT_BACKORDERS.TDC_OV_DEL_ADDRESS AS OvDeliveryAddress,
PRODUCT_BACKORDERS.TDM_ACT_ADDRESS_FILE AS ActAddressFile,
INTMAS.STATE as State
FROM PRODUCT_BACKORDERS LEFT OUTER JOIN CUSDUE ON PRODUCT_BACKORDERS.CUST_REF = CUSDUE.CUST
AND PRODUCT_BACKORDERS.DOC_REF = CUSDUE.DOC_REF
LEFT OUTER JOIN INTMAS ON PRODUCT_BACKORDERS.TDD_CUST = INTMAS.ACCOUNT
WHERE PRODUCT_BACKORDERS.REC_STA <> 'X'


Execution Plan
----------------------------------------------------------
Plan hash value: 3181602933

----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 22257 | 2390K| | 9543 (2)| 00:01:55 |
|* 1 | HASH JOIN RIGHT OUTER| | 22257 | 2390K| | 9543 (2)| 00:01:55 |
| 2 | INDEX FAST FULL SCAN| CUSDUE_PK | 11357 | 199K| | 13 (0)| 00:00:01 |
|* 3 | HASH JOIN OUTER | | 22257 | 1999K| 2000K| 9529 (2)| 00:01:55 |
|* 4 | TABLE ACCESS FULL | PRODUCT_BACKORDERS | 22257 | 1738K| | 643 (4)| 00:00:08 |
| 5 | TABLE ACCESS FULL | INTMAS | 677K| 7933K| | 7995 (2)| 00:01:36 |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - access("PRODUCT_BACKORDERS"."DOC_REF"="CUSDUE"."DOC_REF"(+) AND
"PRODUCT_BACKORDERS"."CUST_REF"="CUSDUE"."CUST"(+))
3 - access("PRODUCT_BACKORDERS"."TDD_CUST"="INTMAS"."ACCOUNT"(+))
4 - filter("PRODUCT_BACKORDERS"."REC_STA"<>'X')

Thanks


Tom Kyte
September 27, 2006 - 3:01 pm UTC

why does a high cost bother you? when you actually run it, what happens.

scanning a table again and again

abz, September 27, 2006 - 8:01 am UTC

I am running the below query, there is a table CI_BILL_CHAR in this query inside a scalar subquery. When I run this query and see in "long operations" tab in OEM, I see that
the it is scanning the table CI_BILL_CHAR again and again.
Because of this problem the query is very slow.
How can I solve this.
Oracle 9i Release 2

SELECT
A.BILL_CYC_CD,
COUNT(A.ACCT_ID) AS TOTAL,
(select COUNT(B.BILL_ID)
from
CI_BILL B,
CI_BILL_CHAR BC
where
BC.BILL_ID=B.BILL_ID AND
BC.CHAR_TYPE_CD='BILL-MTH' AND
B.BILL_STAT_FLG='C' AND
B.bill_cyc_cd=A.Bill_Cyc_Cd AND BC.ADHOC_CHAR_VAL='200608') AS bILLED
FROM
CI_ACCT A, ci_sa sa,CI_SA_TYPE_CHAR STC
where a.acct_id = sa.acct_id
AND SA.SA_TYPE_CD=STC.SA_TYPE_CD
AND STC.CHAR_TYPE_CD='SA-CAT'
AND STC.CHAR_VAL='10'
and sa.SA_STATUS_FLG in ('20','30','40','50')
GROUP BY BILL_CYC_CD

Tom Kyte
September 27, 2006 - 3:05 pm UTC

laughing out loud, how could anyone say anything....

without a schema, indexing scheme, etc....

I would guess that the scalar subquery needs a full scan to run. And scalar subqueries are in general run for each row. Hence you are full scanning over and over and yet over again........



Tuning Merge Statement

a reader, September 27, 2006 - 12:26 pm UTC

-- DDL for partitioned table.
create table T1
(
ppdrecnum number(10), version number(10),
value number(8,1), rawvalue float(24),
estimationmethod char(1), tag varchar2(16),
flag number(1), reasoncode char(2),
utcperiodnumber char(2), clocktimeperiodnumber number(10),
actualestimatedindicator char(1), estimationreasoncode char(1),
validationstatus number(1), crdrecnum number(10), crdrecnum2 number(10)
)
partition by range ( crdrecnum )
(
partition p001 values less than ( 1416689 ),
...
...
partition p099 values less than ( 143017419 ),
partition p100 values less than ( maxvalue )
)
pctfree 0
compress
nologging
tablespace medium_t01
/

-- DDL for normal table.
create table T2
(
ppdrecnum number (10), version number (10), value number(8,1), rawvalue float (24),
estimationmethod char(1), tag varchar2 (16), flag number (1), reasoncode char(2),
utcperiodnumber char (2), clocktimeperiodnumber number (10),
actualestimatedindicator char (1), estimationreasoncode char (1),
validationstatus number (1), crdrecnum number (10), crdrecnum2 number (10)
)
pctfree 0
nologging
compress
tablespace medium_t01
/

-- Set table stats for T1.
execute dbms_stats.set_table_stats('ABC', 'T1', numrows => 65000000, numblks => 130000);

-- Set table stats for T2.
execute dbms_stats.set_table_stats('ABC', 'T2', numrows => 1000000, numblks => 5000);

-- Merge statement
MERGE INTO T1 dcppd
USING dcprocessedperioddata_p2 dcppd_p2
ON (T1.PPDRecNum = T2.PPDRecNum AND T2.delta_type IN ('U', 'I'))
WHEN MATCHED THEN
UPDATE
SET T1.VERSION = T2.VERSION, T1.VALUE = T2.VALUE, T1.RAWVALUE = T2.RAWVALUE,
T1.ESTIMATIONMETHOD = T2.ESTIMATIONMETHOD,T1.TAG = T2.TAG, T1.FLAG = T2.FLAG,
T1.REASONCODE = T2.REASONCODE, T1.UTCPERIODNUMBER = T2.UTCPERIODNUMBER,
T1.CLOCKTIMEPERIODNUMBER = T2.CLOCKTIMEPERIODNUMBER, T1.ACTUALESTIMATEDINDICATOR = T2.ACTUALESTIMATEDINDICATOR,
T1.ESTIMATIONREASONCODE = T2.ESTIMATIONREASONCODE, T1.VALIDATIONSTATUS = T2.VALIDATIONSTATUS,
T1.CRDRECNUM = T2.CRDRECNUM, T1.CRDRECNUM2 = T2.CRDRECNUM2
WHEN NOT MATCHED THEN
INSERT (
T1.PPDRECNUM, T1.VERSION, T1.VALUE, T1.RAWVALUE, T1.ESTIMATIONMETHOD, T1.TAG,
T1.FLAG, T1.REASONCODE, T1.UTCPERIODNUMBER, T1.CLOCKTIMEPERIODNUMBER,
T1.ACTUALESTIMATEDINDICATOR, T1.ESTIMATIONREASONCODE, T1.VALIDATIONSTATUS,
T1.CRDRECNUM, T1.CRDRECNUM2
)
VALUES (
T2.PPDRECNUM, T2.VERSION, T2.VALUE, T2.RAWVALUE, T2.ESTIMATIONMETHOD,
T2.TAG, T2.FLAG, T2.REASONCODE, T2.UTCPERIODNUMBER, T2.CLOCKTIMEPERIODNUMBER,
T2.ACTUALESTIMATEDINDICATOR, T2.ESTIMATIONREASONCODE, T2.VALIDATIONSTATUS,
T2.CRDRECNUM, T2.CRDRECNUM2)
/

Re merge statement, T1 and T2 have same structure. T2 contains the incremental data (updates and inserts). So all the changes made to the data since T1 is loaded, need to be applied to the T1 table. All the new records will be inserted in T1 table. This is only done for delta type 'I' (Insert) or 'U' (Update) in T2 table. Hence MERGE using join condition and an extra predicate on T2.delta_type.

Many Thanks for your time so far.


Tom Kyte
September 27, 2006 - 3:57 pm UTC

dcprocessedperioddata_p2 not found, change that to "t2" and then t2.delta_type is not found.

please run test case in your database, reproduce plan and then add it here (entirely again)

ABS to get diff DATE value ?

Yoav, September 27, 2006 - 4:45 pm UTC

Hi tom,
Table t1:
=========
a number;
b date;

Table t2
=========
c number;
d date;

I nead to fetch all the rows that the has more then
1 second diff in tha last 24HR

select t1.*
from t1 , t2
where t1.a = t2.c
and ABS(t1.b-t2.d) > 1/(60*60*24) <=====

Can you suggest a better way to to that instead of:
ABS(t1.b-t2.d) > 1/(60*60*24)

Thanks

Tom Kyte
September 27, 2006 - 5:32 pm UTC

what is wrong with that, that just about does it.



Tuning merge statement

a reader, September 28, 2006 - 5:22 am UTC

This time I've tested the scripts myself in a new schema. So it should be fine.

-- DDL for partitioned table.
create table T1
(
ppdrecnum number(10), version number(10),
value number(8,1), rawvalue float(24),
estimationmethod char(1), tag varchar2(16),
flag number(1), reasoncode char(2),
utcperiodnumber char(2), clocktimeperiodnumber number(10),
actualestimatedindicator char(1), estimationreasoncode char(1),
validationstatus number(1), crdrecnum number(10), crdrecnum2 number(10)
)
partition by range ( crdrecnum )
(
partition p001 values less than ( 1416689 ),
partition p099 values less than ( 143017419 ),
partition p100 values less than ( maxvalue )
)
pctfree 0
compress
nologging
tablespace medium_t01
/

-- DDL for normal table.
create table T2
(delta_id number(13), delta_type char(1), delta_date date,
ppdrecnum number (10), version number (10), value number(8,1), rawvalue float
(24),
estimationmethod char(1), tag varchar2 (16), flag number (1), reasoncode
char(2),
utcperiodnumber char (2), clocktimeperiodnumber number (10),
actualestimatedindicator char (1), estimationreasoncode char (1),
validationstatus number (1), crdrecnum number (10), crdrecnum2 number (10)
)
pctfree 0
nologging
compress
tablespace medium_t01
/

-- Set table stats for T1.
execute dbms_stats.set_table_stats('PARESH', 'T1', numrows => 65000000, numblks => 130000);

-- Set table stats for T2.
execute dbms_stats.set_table_stats('PARESH', 'T2', numrows => 1000000, numblks => 5000);

-- Merge statement
MERGE INTO T1
USING T2
ON (T1.PPDRecNum = T2.PPDRecNum AND T2.delta_type IN ('U', 'I'))
WHEN MATCHED THEN
UPDATE
SET T1.VERSION = T2.VERSION, T1.VALUE = T2.VALUE, T1.RAWVALUE = T2.RAWVALUE,
T1.ESTIMATIONMETHOD = T2.ESTIMATIONMETHOD,T1.TAG = T2.TAG, T1.FLAG =
T2.FLAG,
T1.REASONCODE = T2.REASONCODE, T1.UTCPERIODNUMBER = T2.UTCPERIODNUMBER,
T1.CLOCKTIMEPERIODNUMBER = T2.CLOCKTIMEPERIODNUMBER,
T1.ACTUALESTIMATEDINDICATOR = T2.ACTUALESTIMATEDINDICATOR,
T1.ESTIMATIONREASONCODE = T2.ESTIMATIONREASONCODE, T1.VALIDATIONSTATUS =
T2.VALIDATIONSTATUS,
T1.CRDRECNUM = T2.CRDRECNUM, T1.CRDRECNUM2 = T2.CRDRECNUM2
WHEN NOT MATCHED THEN
INSERT (
T1.PPDRECNUM, T1.VERSION, T1.VALUE, T1.RAWVALUE, T1.ESTIMATIONMETHOD, T1.TAG,
T1.FLAG, T1.REASONCODE, T1.UTCPERIODNUMBER, T1.CLOCKTIMEPERIODNUMBER,
T1.ACTUALESTIMATEDINDICATOR, T1.ESTIMATIONREASONCODE, T1.VALIDATIONSTATUS,
T1.CRDRECNUM, T1.CRDRECNUM2
)
VALUES (
T2.PPDRECNUM, T2.VERSION, T2.VALUE, T2.RAWVALUE, T2.ESTIMATIONMETHOD,
T2.TAG, T2.FLAG, T2.REASONCODE, T2.UTCPERIODNUMBER, T2.CLOCKTIMEPERIODNUMBER,
T2.ACTUALESTIMATEDINDICATOR, T2.ESTIMATIONREASONCODE, T2.VALIDATIONSTATUS,
T2.CRDRECNUM, T2.CRDRECNUM2)
/


Tom Kyte
September 28, 2006 - 7:09 am UTC

ok. please do what I suggested a couple of items ago...

MERGE INTO T1
USING (select * from t2 where col3 in ('I','U') ) T2
ON (T1.COL2 = T2.COL2)
WHEN MATCHED THEN.....

do for you?


You'll be much happier I believe

Tuning merge statement

a reader, September 28, 2006 - 7:35 am UTC

I am now getting nice juicy plan as you did at your first attempt.

1. Could you explain what is the difference between the two and why its now choosing HASH JOIN OUTER as against NESTED LOOPS OUTER? My guess is that Oracle was made to believe that the join is on both the conditions (including delta_type), hence it filters the records whilst joining both the tables, however, that doesn't explain why it chose NESTED LOOP given the numrows for the two tables.

2. If for any reason I want to put the hints to get the same execution plan (not that I like hints over tuning the sql itself), how would I achieve that?

Thanks for your tips. Hats off to you.


Tom Kyte
September 28, 2006 - 7:52 am UTC

1) i'm not sure why it chose the nested loops. I can say putting the condition in the "on" for the IN ('I', 'U') is not really appropriate there.

2) don't waste time on "hints" here, just use the right sql. I'm not going to play with hints - it may or may not be possible.

Turn a simple query

Jennifer Chen, October 09, 2006 - 11:57 pm UTC

I have a very simple join. it returns 60,000 rows. how can i make it fast so that user can query and down load result set faster to their machine?

SELECT "TOE_Attributes"."TYPE_SUP_CD" "Type_Support_Code",
"TOE_Attributes"."FY" "Fiscal_Year", "TOE_Attributes"."UIC" "UIC",
"TOE_Attributes"."TOE_NAME" "Unit_Name",
"BIC_Attributes"."MAPPED_BILLET" "Mapped_Billet",
"BIC_Attributes"."BILLET_RECORD_CD" "Billet_Record_Code",
"BIC_Attributes"."BILLET_ID_CODE" "c7",
"BIC_Attributes"."SECURITY_CLRNC_CD" "Security_Clearance",
"BIC_Attributes"."WEAPON_CD" "Weapon_Code",
CASE
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" =
'M'
AND ( "BIC_Attributes"."RESERVE_TYPE_CD" IN ('W', 'Z')
OR "BIC_Attributes"."RESERVE_TYPE_CD" IS NULL
)
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'A'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Marine Active Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'M'
AND "BIC_Attributes"."RESERVE_TYPE_CD" IN ('A')
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R', 'C')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'V'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Marine Reserve SMCR Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'M'
AND "BIC_Attributes"."RESERVE_TYPE_CD" IN ('B')
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R', 'C')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'V'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Marine Reserve AR Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'M'
AND "BIC_Attributes"."RESERVE_TYPE_CD" IN ('D')
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R', 'C')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'V'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Marine Reserve IMA Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'M'
AND "BIC_Attributes"."RESERVE_TYPE_CD" IN ('G')
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R', 'C')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'V'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Marine Reserve IRR Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'M'
AND "BIC_Attributes"."RESERVE_TYPE_CD" IN ('A', 'B', 'D', 'G')
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R', 'C')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'V'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Marine Reserve Chargeable - All'
WHEN ( "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'W'
OR "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" IS NULL
)
AND ( "BIC_Attributes"."RESERVE_TYPE_CD" IN ('W', 'Z')
OR "BIC_Attributes"."RESERVE_TYPE_CD" IS NULL
)
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('A', 'R')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'C'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Civilian Graded/Ungraded Chargeable '
WHEN ( "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'W'
OR "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" IS NULL
)
AND ( "BIC_Attributes"."RESERVE_TYPE_CD" IN ('W', 'Z')
OR "BIC_Attributes"."RESERVE_TYPE_CD" IS NULL
)
AND "BIC_Attributes"."BILLET_STATUS_CD" IN ('O')
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'C'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Civilian NAFI Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'N'
AND ( "BIC_Attributes"."RESERVE_TYPE_CD" IN ('W', 'Z')
OR "BIC_Attributes"."RESERVE_TYPE_CD" IS NULL
)
AND "BIC_Attributes"."BILLET_STATUS_CD" = 'A'
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'A'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Navy Active Chargeable'
WHEN "BIC_Attributes"."UNIFORMED_SRVC_BRN_CD" = 'N'
AND "BIC_Attributes"."RESERVE_TYPE_CD" = 'D'
AND "BIC_Attributes"."BILLET_STATUS_CD" = 'A'
AND "BIC_Attributes"."MNPWR_TYPE_CD" = 'V'
AND SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Navy Selective Reserve Chargeable'
WHEN SUBSTR ("BIC_Attributes"."BILLET_ID_CODE", 1, 6) =
"BIC_Attributes"."UIC"
AND "BIC_Attributes"."BILLET_RECORD_CD" = 'E'
AND "TOE_Attributes"."TOE_TYPE_CD" = 'S'
THEN 'Non Chargeable'
ELSE 'Other'
END "Chargeable_Category",
"BIC_Attributes"."RESERVE_TYPE_CD" "Reserve_Type_Code",
"BIC_Attributes"."MCC" "MCC", "BIC_Attributes"."IHG_CRITERIA_CD" "c21",
"BIC_Attributes"."IHG_FUNCTION_CD" "c22",
TO_NUMBER ("BIC_Attributes"."ASR_IND_CD") "Authorized_Strength",
"BIC_Attributes"."FOOTNOTE_DSCRPTN_TXT" "Footnote_Description"
FROM "TFSMS_PUBLISHED"."C_TFSMS_TOE_ATTRIBUTES_MV" "TOE_Attributes" INNER JOIN "TFSMS_PUBLISHED"."C_TFSMS_BIC_ATTRIBUTES_MV" "BIC_Attributes" ON "TOE_Attributes"."FY" =
"BIC_Attributes"."FY"
AND "TOE_Attributes"."UIC" =
"BIC_Attributes"."UIC"
AND "TOE_Attributes"."FY" =
'2007'
AND "TOE_Attributes"."TYPE_SUP_CD" =
'A';

Tom Kyte
October 10, 2006 - 7:38 am UTC

make sure you are using the cost based optimizer and consider increasing your array size in whatever client programming language you used.

query tuning

Irfan Hadi, October 11, 2006 - 3:54 am UTC

following query is causing error:ORA-01652: unable to extend temp segment by 128 in tablespace TEMP02
ORA-06512: at "FIN7GIC_GI.FINPROC_FGIC009_DEPTWISE", line 358

Can you Please help me on this?

SELECT OST_SUB_ACNT_CODE, OST_CURR_CODE, SUM(DECODE(AD_DOC_TYPE,'1',1, '3',1,'4',1,'5',1,'6',1,'7',1,'8',1,'16',1,'18',1,'19',1,'20',1,'22',1,'23',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1)) PREM_AMT, SUM((DECODE(OST_DEPT_CODE, '02',1,0) * DECODE(AD_DOC_TYPE,'1',1, '3',1,'4',1,'5',1,'6',1,'7',1,'8',1,'16',1,'18',1,'19',1,'20',1,'22',1,'23',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1))) MOTOR_PREM_AMT, SUM((DECODE(OST_DEPT_CODE, '03',1,0) * DECODE(AD_DOC_TYPE,'1',1, '3',1,'4',1,'5',1,'6',1,'7',1,'8',1,'16',1,'18',1,'19',1,'20',1,'22',1,'23',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1))) FGA_PREM_AMT, SUM((DECODE(OST_DEPT_CODE, '04',1,0) * DECODE(AD_DOC_TYPE,'1',1, '3',1,'4',1,'5',1,'6',1,'7',1,'8',1,'16',1,'18',1,'19',1,'20',1,'22',1,'23',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1))) MARINE_PREM_AMT, SUM((DECODE(OST_DEPT_CODE, '02',0,'03',0,'04',0,1) * DECODE(AD_DOC_TYPE,'1',1, '3',1,'4',1,'5',1,'6',1,'7',1,'8',1,'16',1,'18',1,'19',1,'20',1,'22',1,'23',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1))) OTHER_PREM_AMT, SUM(DECODE(AD_DOC_TYPE,'9',1, '10',1,'11',1,'12',1,'13',1,'14',1,'15',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1)) CLM_AMT, SUM(DECODE(AD_DOC_TYPE,'2',1, '17',1,'32',1,0) * DECODE(OST_DRCR_FLAG,'D', OST_LC_AMT, OST_LC_AMT *-1)) COMM_AMT FROM FV_OS, FW_FGIC009, (SELECT DISTINCT AD_SEG_01, AD_ACNT_YEAR, AD_TRAN_CODE, AD_DOC_NO, AD_DOC_DT, AD_DOC_TYPE FROM FV_PGIT_ACNT_DOC WHERE AD_SEG_01 = :B3 AND AD_DOC_DT BETWEEN :B2 AND :B1 AND EXISTS (SELECT 'X' FROM FV_OS, FW_FGIC009 WHERE OST_COMP_CODE = :B3 AND OST_MAIN_ACNT_CODE BETWEEN :B6 AND :B5 AND OST_DOC_DT BETWEEN :B2 AND :B1 AND OST_SUB_ACNT_CODE = FGIC009_SUB_ACNT_CODE AND OST_CURR_CODE = FGIC009_CURR_CODE AND FGIC009_REP_KEY_NO = :B4 AND AD_SEG_01 = OST_COMP_CODE AND AD_ACNT_YEAR = OST_ACNT_YEAR AND AD_TRAN_CODE = OST_TRAN_CODE AND AD_DOC_NO = OST_DOC_NO AND AD_DOC_DT = OST_DOC_DT) ) WHERE OST_COMP_CODE = :B3 AND OST_MAIN_ACNT_CODE BETWEEN :B6 AND :B5 AND OST_DOC_DT BETWEEN :B2 AND :B1 AND OST_SUB_ACNT_CODE = FGIC009_SUB_ACNT_CODE AND OST_CURR_CODE = FGIC009_CURR_CODE AND FGIC009_REP_KEY_NO = :B4 AND AD_SEG_01 = OST_COMP_CODE AND AD_ACNT_YEAR = OST_ACNT_YEAR AND AD_TRAN_CODE = OST_TRAN_CODE AND AD_DOC_NO = OST_DOC_NO AND AD_DOC_DT = OST_DOC_DT GROUP BY OST_SUB_ACNT_CODE, OST_CURR_CODE


Tom Kyte
October 11, 2006 - 8:10 am UTC

alter tablespace temp ......


add space?

Syedhadi, October 12, 2006 - 3:56 am UTC

ALready 6GB of temp is allocated for temp. Only this query is causing problem. DO you see any problem with the query?



Tom Kyte
October 12, 2006 - 8:18 am UTC

just 6gb? must be a small database ;) 6gb only "sounds big".

there is nothing fundementally wrong with that query, it would be purely a function of the amount of data it has to generate/churn through.

followup

syedhadi, October 12, 2006 - 9:06 am UTC

yes, Database size is 46 GB, so Temp is 6GB, do you recommend to increase temp further?

Tom Kyte
October 12, 2006 - 11:35 am UTC

well, do you desire this query to run to completion?

(you can also look at your memory settings to ensure your pga aggregate target is set appropriately)

SORT ORDER BY

Ian, October 12, 2006 - 12:21 pm UTC

Tom

Are the (cr=xx r=x w=x time=xxx us) figures for SORT ORDER BY a rollup of all the operations before? Can you get the actual figures for this operation by subtracting the previous levels figures?

Does the same apply to NESTED LOOPS operations?

Thanks and Regards

Ian

Tom Kyte
October 13, 2006 - 6:43 am UTC

the cr= r= w= values are rolled up as the hierarchy goes up in the plan.

not sure I'd expect the sort order by to be doing anymore CR's

you may "subtract" but for the ones you listed, i would mostly expect "0" (could do r/w for temp read and writes though)

SORT ORDER BY

Ian, October 13, 2006 - 6:18 pm UTC

You didn't mention the time element. I am guessing that it is also a rollup - but would welcome confirmation - as it was excluded from your response.

Is there anywhere these sort of details are publicly documented?

Thanks and Regards

Ian

Tom Kyte
October 13, 2006 - 7:21 pm UTC

there are likely notes on metalink regarding this...

the time should be a rollup, yes.

Metalink

Ian, October 14, 2006 - 6:55 pm UTC

"there are likely notes on metalink regarding this"

Sadly not. Not at this level of detail.

Ian

combining multiple union selects into one select...

Srinivas Narashimalu, October 16, 2006 - 10:08 am UTC

Hi Tom,

I have this sql, where I would get the maximum performance gain by replacing all the unions with just 1 sql, but I need to apply all the conditions of the having clause of the subqueries which are combined using union in 1 having clause of sql. Basically I want to implement an "OR" in the having clause, can you please suggest me how to do this or any better way of doing this?

I have replaced union with union all, in with exists but not much gain.

select distinct olf.invoice_date, TO_CHAR(olf.invoice_date,'DAY'), trunc(create_date), count(*)
from order_line_fact olf
where invoice_date in
(-- invoice date loaded on more than 1 day
select distinct invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
having count(distinct trunc(create_date)) > 2
group by invoice_date
union
-- invoice date not loaded next day
select distinct invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
and ((invoice_date > trunc(create_date))
or (invoice_date < trunc(create_date) - 1))
union
-- invoice date record count outside of normal range (Mon-Fri)
select distinct invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
and to_number(to_char(invoice_date, 'D')) <> 1
and to_number(to_char(invoice_date, 'D')) <> 7
having count(*) < 10000 or count(*) > 17000
group by invoice_date
union
-- invoice date record count outside of normal range (Sat)
select distinct invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
and to_number(to_char(invoice_date, 'D')) = 7
having count(*) <= 0 or count(*) > 1700
group by invoice_date
union
-- invoice date record count outside of normal range (Sun)
select distinct invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
and to_number(to_char(invoice_date, 'D')) = 1
having count(*) < 0 or count(*) > 50
group by invoice_date
)
group by olf.invoice_date, TO_CHAR(olf.invoice_date,'DAY'), trunc(create_date);


Thanks,
Srinivas

Tom Kyte
October 16, 2006 - 11:08 am UTC

umm, well - the keyword:

OR

always worked well for me when I need to - OR :)




some of your comments look "funny"

-- invoice date loaded on more than 1 day
select distinct invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr'))
and sysdate-2
having count(distinct trunc(create_date)) > 2


you seem to be getting more than 2 days???


anyway, just move the predicate logic into the having using a CASE statement with count:

select invoice_date
from order_line_fact
where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
having count(distinct trunc(create_date)) > 2
or count( case when invoice_date > trunc(create_date) or invoice_date < trunc(create_date)-1
then 1
end ) > 0
or NOT count( case when to_char(invoice_date) NOT IN ('1','7')
then 1
end ) between 10000 and 17000
or count( case when to_char(invoice_date) = '7'
then 1
end ) > 1700
.....
group by invoice_date


A reader, October 16, 2006 - 1:02 pm UTC

Tom,
One of the queries before tuning as below. I did not write this :)
(This takes around 16 minutes)

SELECT ivd.item_number, ivm.case_pack, ivm.wh_id
FROM T_master ivm
INNER JOIN T_detail ivd
ON ivm.hu_id = ivd.hu_id
AND ivm.wh_id = ivd.wh_id
INNER JOIN t_pp_items ppitm
ON ivd.item_number = ppitm.item_number
AND ivd.wh_id = ppitm.wh_id
WHERE ivm.type = 'IV'
AND ivm.status = 'A'
GROUP BY ivd.item_number, ivm.case_pack, ivm.wh_id;

Query after tuning is below (Takes aroung 10 seconds).

SELECT a.item_number,a.case_pack,a.wh_id
from
(
SELECT distinct ivd.item_number, ivm.case_pack, ivm.wh_id
FROM T_master ivm
INNER JOIN T_detail ivd
ON ivm.hu_id = ivd.hu_id
AND ivm.wh_id = ivd.wh_id
WHERE ivm.type = 'IV'
AND ivm.status = 'A'
) a,
(SELECT DISTINCT item_number,wh_id from t_pp_items) b
WHERE
a.wh_id = b.wh_id and
a.item_number = b.item_number;

Tom,
You could notice that I just forced to join different order.
I hate to force join order where optimizer can take wise decisions.

Data facts and tried the following so I do not need to force join order.
1. T_PP_ITEMS is a global temporary table so set optimizer dynamic sampling was set 5 . This table has 2000 rows.
2. status=’A’ pulls 100 rows out of 1M+. Therefore, histogram built
3. Removed inner join and joined all tables together.
4. T_master,T_detail both has > 1M+
5. Hard parsed to see if bind peeking causing issue.
6. Removed group by and added distinct key.

None of them made any difference.
SO I had to try the second query where I forced to join and worked great (completes less than 10 seconds).

Do you think there are certain cases still CBO is not able to find best join order so we had to change SQL statements like I did in second query OR
My approach is wrong. I believe I am missing something in my method.

Strange to me is DISTINCT in second query is not required as primary /unique keys set but unfortunately; performance was bad if I take away distinct key word.



Tom Kyte
October 16, 2006 - 5:21 pm UTC

I'll ask the question I always ask.....

were the estimated cardinalities used by the optimizer (from an explain plan/autotrace) ANYWHERE NEAR reality (as seen in tkprof)

that is where to always start, if they are way off, we need to ask "why"

Thanks much!

A reader, October 16, 2006 - 1:55 pm UTC

Thanks much for the response Tom!

Greatly appreciate your help. Sorry about the comment...just typed it too quick :D

Thanks again!

-Srinivas

small clarification...

Srinivas Narashimalu, October 16, 2006 - 6:07 pm UTC

Tom,

When I used count(*) in the script -

1   select distinct invoice_date
  2    from order_line_fact
  3    where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
  4    having count(case when to_number(to_char(invoice_date, 'D')) NOT IN (1,7) then 1 end) NOT BETWEEN 10000 and 17000
  5    or count(distinct trunc(create_date)) > 2
  6*   group by invoice_date
SQL> /
64 rows selected.

 1   select distinct invoice_date
  2    from order_line_fact
  3    where invoice_date between to_date('01-JAN'||to_char(sysdate-2, '-rr')) and sysdate-2
  4    having sum(case when to_number(to_char(invoice_date, 'D')) NOT IN (1,7) then 1 end) NOT BETWEEN 10000 and 17000
  5    or count(distinct trunc(create_date)) > 2
  6*   group by invoice_date
SQL> /

INVOICE_D
---------
02-JAN-06
03-JAN-06
05-JAN-06
21-MAR-06
04-APR-06
14-APR-06
29-MAY-06
31-MAY-06
04-JUL-06
07-AUG-06
15-AUG-06
25-AUG-06
04-SEP-06
26-SEP-06

14 rows selected.

Could you tell what the count(*) is counting as opposed to sum. The correct answer (the one that I want, the one the original query returned) is 14 rows.

Thanks as always!
Srinivas 

Tom Kyte
October 16, 2006 - 6:11 pm UTC

do you understand what I was doing in the count ( case .... )?

why don't you add the counts to the select list, and debug away...

don't forget, you are seeing the output of what you union used to return there, not just one part of it.

Thanks much!

A reader, October 17, 2006 - 3:18 pm UTC

Thanks much Tom...I got it fixed. It's running in 4mins now compared to 16mins before.

-Srinivas

Please help in understanding this query.

Rahul, October 31, 2006 - 4:32 pm UTC

Tom,

I have this XML sqlx based query I wrote and I am trying to tune this one. Couldn't get to go anywhere. I am able to run this query for smaller XMLs, but, then, if the XML size increases, the query time increases EXPONENTIALLY. Here is the TKPROF output of that query.

********************************************************************************

SELECT XMLELEMENT("Root", XMLAGG(XMLELEMENT("Record", XMLATTRIBUTES(ROWNUM AS
"Index"), XMLELEMENT("ValueMark", XMLATTRIBUTES(11 AS "Index"),
XMLELEMENT("SubValueMark", XMLATTRIBUTES(1 AS "Index", 'KEY' AS "Name",
'001!EDI!ORD!' || S.STID || '!' || TO_CHAR(TO_NUMBER(EXTRACTVALUE(VALUE(K),
'/PO1/PO101'))) AS "Value"))), XMLELEMENT("ValueMark", XMLATTRIBUTES(12 AS
"Index"), XMLELEMENT("SubValueMark", XMLATTRIBUTES(1 AS "Index", 'PROD.NUM'
AS "Name", EXTRACTVALUE(VALUE(K), '/PO1/PO107') AS "Value"))),
XMLELEMENT("ValueMark", XMLATTRIBUTES(13 AS "Index"),
XMLELEMENT("SubValueMark", XMLATTRIBUTES(1 AS "Index", 'QTY' AS "Name",
EXTRACTVALUE(VALUE(K), '/PO1/PO102') AS "Value"))), XMLELEMENT("ValueMark",
XMLATTRIBUTES(17 AS "Index"), XMLELEMENT("SubValueMark", XMLATTRIBUTES(1 AS
"Index", 'CUST.LINE.NUM' AS "Name", EXTRACTVALUE(VALUE(K), '/PO1/PO101') AS
"Value"))), XMLELEMENT("ValueMark", XMLATTRIBUTES(21 AS "Index"),
XMLELEMENT("SubValueMark", XMLATTRIBUTES(1 AS "Index", 'DEST.FILE.ATTR' AS
"Name", S.DESTFILEATTR1 AS "Value")), XMLELEMENT("SubValueMark",
XMLATTRIBUTES(2 AS "Index", 'DEST.FILE.ATTR' AS "Name", S.DESTFILEATTR2 AS
"Value")), XMLELEMENT("SubValueMark", XMLATTRIBUTES(3 AS "Index",
'DEST.FILE.ATTR' AS "Name", S.DESTFILEATTR3 AS "Value"))),
XMLELEMENT("ValueMark", XMLATTRIBUTES(22 AS "Index"),
XMLELEMENT("SubValueMark", XMLATTRIBUTES(1 AS "Index", 'DEST.FILE.DATA' AS
"Name", 'PO Line # ' || EXTRACTVALUE(VALUE(K), '/PO1/PO101') || ' QTY ' ||
EXTRACTVALUE(VALUE(K), '/PO1/PO102') || ' Price: ' || EXTRACTVALUE(VALUE(K),
'/PO1/PO104') || ' (' || EXTRACTVALUE(VALUE(K), '/PO1/PO106') || ') ' ||
EXTRACTVALUE(VALUE(K), '/PO1/PO107') || NVL2(EXTRACTVALUE(VALUE(K),
'/PO1/PO108'), ' (' || EXTRACTVALUE(VALUE(K), '/PO1/PO108') || ') ',
CHR(253)) || EXTRACTVALUE(VALUE(K), '/PO1/PO109') ||
NVL2(EXTRACTVALUE(VALUE(K), '/PO1/PO110'), ' (' || EXTRACTVALUE(VALUE(K),
'/PO1/PO110') || ') ', CHR(253)) || EXTRACTVALUE(VALUE(K), '/PO1/PO111') ||
NVL2(EXTRACTVALUE(VALUE(K), '/PO1/PID/PID05'), ' Description: ' ||
EXTRACTVALUE(VALUE(K), '/PO1/PID/PID05'), NULL) AS "Value")),
XMLELEMENT("SubValueMark", XMLATTRIBUTES(3 AS "Index", 'UNIT.OF.MEASURE' AS
"Name", 'Unit of Measure Code: ' || EXTRACTVALUE(VALUE(K), '/PO1/PO103') AS
"Value")))))) XML
FROM
EDI_XML_INT T, EDI_ISA I, EDI_GS G, EDI_ST S,
TABLE(XMLSEQUENCE(EXTRACT(X12_850, '/X12/TS_850'))) M,
TABLE(XMLSEQUENCE(EXTRACT(VALUE(M), '/TS_850/GROUP_11/PO1'))) K WHERE
S.GSID = G.GSID AND G.ISAID = I.ISAID AND T.ISAID = I.ISAID AND
S.TRANSACTIONSETCONTROLNUMBER = EXTRACTVALUE(VALUE(M), '/TS_850/ST/ST02')
AND T.PROCESSEDDATE IS NULL ORDER BY S.STID


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.03 0.03 0 162 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 3131.81 570.90 1445976 1580230 3642942 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 3131.84 570.93 1445976 1580392 3642942 1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 74 (XXDANCO) (recursive depth: 2)

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE (cr=1572605 pr=1445976 pw=0 time=570640973 us)
6891 COUNT (cr=1566250 pr=1445976 pw=0 time=4066130431 us)
6891 NESTED LOOPS (cr=1566250 pr=1445976 pw=0 time=4066109755 us)
302 NESTED LOOPS (cr=1566250 pr=1445976 pw=0 time=3208578583 us)
302 NESTED LOOPS (cr=380 pr=0 pw=0 time=8018 us)
1 NESTED LOOPS (cr=13 pr=0 pw=0 time=187 us)
1 NESTED LOOPS (cr=11 pr=0 pw=0 time=159 us)
8 INDEX FULL SCAN EDI_ISA_PK (cr=1 pr=0 pw=0 time=33 us)(object id 80118)
1 TABLE ACCESS BY INDEX ROWID EDI_XML_INT (cr=10 pr=0 pw=0 time=122 us)
8 INDEX RANGE SCAN EDI_XML_INT_FK (cr=2 pr=0 pw=0 time=57 us)(object id 80132)
1 TABLE ACCESS BY INDEX ROWID EDI_GS (cr=2 pr=0 pw=0 time=21 us)
1 INDEX RANGE SCAN EDI_GS_FK (cr=1 pr=0 pw=0 time=10 us)(object id 80123)
302 TABLE ACCESS BY INDEX ROWID EDI_ST (cr=367 pr=0 pw=0 time=7242 us)
302 INDEX RANGE SCAN EDI_ST_FK (cr=3 pr=0 pw=0 time=1214 us)(object id 80126)
302 COLLECTION ITERATOR PICKLER FETCH XMLSEQUENCEFROMXMLTYPE (cr=1565870 pr=1445976 pw=0 time=3203749996 us)
6891 COLLECTION ITERATOR PICKLER FETCH XMLSEQUENCEFROMXMLTYPE (cr=0 pr=0 pw=0 time=1196615 us)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT MODE: ALL_ROWS
1 SORT (AGGREGATE)
6891 COUNT
6891 NESTED LOOPS
302 NESTED LOOPS
302 NESTED LOOPS
1 NESTED LOOPS
1 NESTED LOOPS
8 INDEX MODE: ANALYZED (FULL SCAN) OF 'EDI_ISA_PK'
(INDEX (UNIQUE))
1 TABLE ACCESS MODE: ANALYZED (BY INDEX ROWID) OF
'EDI_XML_INT' (TABLE)
8 INDEX MODE: ANALYZED (RANGE SCAN) OF
'EDI_XML_INT_FK' (INDEX)
1 TABLE ACCESS MODE: ANALYZED (BY INDEX ROWID) OF
'EDI_GS' (TABLE)
1 INDEX MODE: ANALYZED (RANGE SCAN) OF 'EDI_GS_FK'
(INDEX)
302 TABLE ACCESS MODE: ANALYZED (BY INDEX ROWID) OF
'EDI_ST' (TABLE)
302 INDEX MODE: ANALYZED (RANGE SCAN) OF 'EDI_ST_FK'
(INDEX)
302 COLLECTION ITERATOR (PICKLER FETCH) OF
'XMLSEQUENCEFROMXMLTYPE' (PROCEDURE)
6891 COLLECTION ITERATOR (PICKLER FETCH) OF
'XMLSEQUENCEFROMXMLTYPE' (PROCEDURE)

********************************************************************************

This sql is on just ONE XML which is stored as a CLOB in another tablespace with chunksize of 32k (max, i think) and pctversion of 50. I increased these after reading about LOBs in your book. By the way, I tried Schema based XML too instead of CLOB based, but, didn't help me.

Also, if it is relevant here, my PGA_AGGREGATE target was 1.5G and SGA was 1G (no particular reason other than that I might need more PGA and SGA doesn't really matter in this case).

Any thoughts on this?

Thank you,
Rahul



Join order - Nikhil

Nikhil, November 02, 2006 - 2:01 am UTC

Hello Tom,
I was going through the Oracle® Database Performance Tuning Guide 10g Release 2 (10.2). I came across the following in the section "Controlling the Access Path and Join Order with Hints"

The following example shows how to tune join order effectively:

SELECT info
FROM taba a, tabb b, tabc c
WHERE a.acol BETWEEN 100 AND 200
AND b.bcol BETWEEN 10000 AND 20000
AND c.ccol BETWEEN 10000 AND 20000
AND a.key1 = b.key1
AND a.key2 = c.key2;

1. Choose the driving table and the driving index (if any).
The first three conditions in the previous example are filter conditions applying to
only a single table each. The last two conditions are join conditions.
Filter conditions dominate the choice of driving table and index. In general, the
driving table is the one containing the filter condition that eliminates the highest
percentage of the table. Thus, because the range of 100 to 200 is narrow compared
with the range of acol, but the ranges of 10000 and 20000 are relatively large,
taba is the driving table, all else being equal.
With nested loop joins, the joins all happen through the join indexes, the indexes
on the primary or foreign keys used to connect that table to an earlier table in the
join tree. Rarely do you use the indexes on the non-join conditions, except for the
driving table. Thus, after taba is chosen as the driving table, use the indexes on
b.key1 and c.key2 to drive into tabb and tabc, respectively.

2. Choose the best join order, driving to the best unused filters earliest.
The work of the following join can be reduced by first joining to the table with the
best still-unused filter. Thus, if "bcol BETWEEN ..." is more restrictive (rejects a
higher percentage of the rows seen) than "ccol BETWEEN ...", the last join can be
made easier (with fewer rows) if tabb is joined before tabc.

3. You can use the ORDERED or STAR hint to force the join order.

Question:
(Point 2) has confused me as I always thought join order in the WHERE clause does not matter. Am I correct? If not please explain me.


Tom Kyte
November 02, 2006 - 7:03 am UTC

I'd rather not use hints here at all, let the optimizer figure it out

I don't agree with everything that is printed.

Thanks for rge reply - Nikhil

Nikhil, November 03, 2006 - 12:10 am UTC

Hello Tom,
The above part was from Oracle 10g PT manual. Then should we believe it or not :)?

Tom Kyte
November 03, 2006 - 9:20 am UTC

read my original response....

Consistent gets

Rajesh, November 03, 2006 - 4:57 am UTC

Hi Tom,

I have a problem with my query.
Here is the query
SELECT t.tmp_contact_list_id, t.src_pkg_detail_id, t.time_slot_id, t.sentdate
FROM ccm.ccm_tmp_contact_list t
WHERE EXISTS (
SELECT h.recipient
FROM (SELECT recipient, sentdate
FROM ccm.ccm_sent_history_2006_10
WHERE sentdate >= TO_DATE ('24/10/2006', 'DD/MM/YYYY')
AND sentdate < TO_DATE ('26/10/2006', 'DD/MM/YYYY')) h
WHERE t.src_pkg_tpchannel_id = 96051
AND EXISTS (
SELECT l.recipient
FROM ccm.ccm_tmp_contact_list l
WHERE l.src_pkg_tpchannel_id = 96051
AND l.recipient = h.recipient)
AND NOT EXISTS (
SELECT r.recipient
FROM ccm.ccm_mrt_drule_info r
WHERE r.drules_id = 100
AND r.recipient = h.recipient)
AND h.recipient = t.recipient
GROUP BY h.recipient
HAVING COUNT (*) > 0)
;



This query used to run fast. Now it is taking long time to get the data (doing more consistent gets)

Please see both good and bad explain plan.

Good plan
=========
PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
----------------------------------------------------

--------------------------------------------------------------------------------
--------------------
| Id | Operation | Name |
Rows | Bytes | Cost |
--------------------------------------------------------------------------------
--------------------
| 0 | SELECT STATEMENT | |
52983 | 2017K| 849K|
|* 1 | FILTER | |
| | |
| 2 | TABLE ACCESS FULL | CCM_TMP_CONTACT_LIST |
52983 | 2017K| 1836 |
|* 3 | FILTER | |
| | |
| 4 | SORT GROUP BY NOSORT | |
1 | 17 | 16 |
|* 5 | FILTER | |
| | |
|* 6 | INDEX SKIP SCAN | IDX_CCM_SENT_HISTORY_2006_10_4 |
1 | 17 | 16 |
|* 7 | TABLE ACCESS BY INDEX ROWID| CCM_TMP_CONTACT_LIST |
1 | 14 | 5 |
|* 8 | INDEX RANGE SCAN | IDX_CCM_TMP_CONTACT_LIST_03 |
2 | | 3 |
|* 9 | TABLE ACCESS BY INDEX ROWID| CCM_MRT_DRULE_INFO |
2 | 24 | 4 |
|* 10 | INDEX RANGE SCAN | IDX_CCM_MRT_DRULE_INFO_1 |
2 | | 3 |
--------------------------------------------------------------------------------
--------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter( EXISTS (SELECT /*+ */ 0 FROM "CCM"."CCM_SENT_HISTORY_2006_10"
"SYS_ALIAS_2" WHERE
:B1=97307 AND "SYS_ALIAS_2"."RECIPIENT"=:B2 AND
"SYS_ALIAS_2"."SENTDATE">=TO_DATE('2006-10-24
00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND
"SYS_ALIAS_2"."SENTDATE"<TO_DATE('2006-10-26 00:00:00',
'yyyy-mm-dd hh24:mi:ss') AND EXISTS (SELECT /*+ */ 0 FROM
"CCM"."CCM_TMP_CONTACT_LIST" "L" WHERE
"L"."RECIPIENT"=:B3 AND "L"."SRC_PKG_TPCHANNEL_ID"=97307) AND
NOT EXISTS (SELECT /*+ */ 0 FROM
"CCM"."CCM_MRT_DRULE_INFO" "R" WHERE "R"."RECIPIENT"=:B4 AND
"R"."DRULES_ID"=100) GROUP BY
"SYS_ALIAS_2"."RECIPIENT" HAVING COUNT(*)>0))
3 - filter(COUNT(*)>0)
5 - filter(:B1=97307)
6 - access("SYS_ALIAS_2"."RECIPIENT"=:B1 AND
"SYS_ALIAS_2"."SENTDATE">=TO_DATE('2006-10-24
00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND
"SYS_ALIAS_2"."SENTDATE"<TO_DATE('2006-10-26 00:00:00',
'yyyy-mm-dd hh24:mi:ss'))
filter("SYS_ALIAS_2"."RECIPIENT"=:B1 AND
"SYS_ALIAS_2"."SENTDATE">=TO_DATE('2006-10-24
00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND
"SYS_ALIAS_2"."SENTDATE"<TO_DATE('2006-10-26 00:00:00',
'yyyy-mm-dd hh24:mi:ss') AND EXISTS (SELECT /*+ */ 0 FROM
"CCM"."CCM_TMP_CONTACT_LIST" "L" WHERE
"L"."RECIPIENT"=:B2 AND "L"."SRC_PKG_TPCHANNEL_ID"=97307) AND
NOT EXISTS (SELECT /*+ */ 0 FROM
"CCM"."CCM_MRT_DRULE_INFO" "R" WHERE "R"."RECIPIENT"=:B3 AND
"R"."DRULES_ID"=100))
7 - filter("L"."SRC_PKG_TPCHANNEL_ID"=97307)
8 - access("L"."RECIPIENT"=:B1)
9 - filter("R"."DRULES_ID"=100)
10 - access("R"."RECIPIENT"=:B1)

Bad plan
=========

--------------------------------------------------------------------------------
--------------------
| Id | Operation | Name |
Rows | Bytes | Cost |
--------------------------------------------------------------------------------
--------------------
| 0 | SELECT STATEMENT | |
5025 | 225K| 35243 |
|* 1 | FILTER | |
| | |
| 2 | TABLE ACCESS FULL | CCM_TMP_CONTACT_LIST |
5025 | 225K| 68 |
|* 3 | FILTER | |
| | |
| 4 | SORT GROUP BY NOSORT | |
1 | 36 | 1 |
|* 5 | FILTER | |
| | |
|* 6 | FILTER | |
| | |
|* 7 | TABLE ACCESS BY INDEX ROWID| CCM_SENT_HISTORY_2006_10 |
1 | 36 | 1 |
|* 8 | INDEX RANGE SCAN | IDX_CCM_SENT_HISTORY_2006_10_7 |
1 | | 2 |
|* 9 | TABLE ACCESS BY INDEX ROWID | CCM_TMP_CONTACT_LIST |
1 | 14 | 2 |
|* 10 | INDEX RANGE SCAN | IDX_CCM_TMP_CONTACT_LIST_03 |
1 | | 1 |
|* 11 | TABLE ACCESS BY INDEX ROWID | CCM_MRT_DRULE_INFO |
2 | 20 | 4 |
|* 12 | INDEX RANGE SCAN | IDX_CCM_MRT_DRULE_INFO_1 |
2 | | 3 |
--------------------------------------------------------------------------------
--------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter( EXISTS (SELECT /*+ */ 0 FROM "CCM"."CCM_SENT_HISTORY_2006_10"
"SYS_ALIAS_2" WHERE
EXISTS (SELECT /*+ */ 0 FROM "CCM"."CCM_TMP_CONTACT_LIST" "L"
WHERE "L"."RECIPIENT"=:B1 AND
"L"."SRC_PKG_TPCHANNEL_ID"=96051) AND NOT EXISTS (SELECT /*+ */
0 FROM "CCM"."CCM_MRT_DRULE_INFO"
"R" WHERE "R"."RECIPIENT"=:B2 AND "R"."DRULES_ID"=100) AND
:B3=96051 AND
"SYS_ALIAS_2"."SENTDATE"<TO_DATE('2006-10-26 00:00:00',
'yyyy-mm-dd hh24:mi:ss') AND
"SYS_ALIAS_2"."SENTDATE">=TO_DATE('2006-10-24 00:00:00',
'yyyy-mm-dd hh24:mi:ss') AND
"SYS_ALIAS_2"."RECIPIENT"=:B4 GROUP BY "SYS_ALIAS_2"."RECIPIENT"
HAVING COUNT(*)>0))
3 - filter(COUNT(*)>0)
5 - filter( EXISTS (SELECT /*+ */ 0 FROM "CCM"."CCM_TMP_CONTACT_LIST" "L"
WHERE
"L"."RECIPIENT"=:B1 AND "L"."SRC_PKG_TPCHANNEL_ID"=96051) AND
NOT EXISTS (SELECT /*+ */ 0 FROM
"CCM"."CCM_MRT_DRULE_INFO" "R" WHERE "R"."RECIPIENT"=:B2 AND
"R"."DRULES_ID"=100))
6 - filter(:B1=96051)
7 - filter("SYS_ALIAS_2"."RECIPIENT"=:B1)
8 - access("SYS_ALIAS_2"."SENTDATE">=TO_DATE('2006-10-24 00:00:00',
'yyyy-mm-dd hh24:mi:ss') AND
"SYS_ALIAS_2"."SENTDATE"<TO_DATE('2006-10-26 00:00:00',
'yyyy-mm-dd hh24:mi:ss'))
9 - filter("L"."SRC_PKG_TPCHANNEL_ID"=96051)
10 - access("L"."RECIPIENT"=:B1)
11 - filter("R"."DRULES_ID"=100)
12 - access("R"."RECIPIENT"=:B1)


The following is the statistics of good performance and bad performance:
Good performance:
=================
Buffer Gets Executions Gets per Exec %Total Time (s) Time (s) Hash
Value
--------------- ------------ -------------- ------ -------- ---------
----------
8,477,955 71 119,407.8 8.4 213.74 208.67
1439232027
Module: JDBC Thin Client
SELECT T.TMP_CONTACT_LIST_ID, T.SRC_PKG_DETAIL_ID, T.TIME_SLOT_
ID, T.SENTDATE FROM CCM_TMP_CONTACT_LIST T WHERE EXISTS ( SELECT
H.RECIPIENT FROM ( SELECT RECIPIENT, SENTDATE FROM CCM_SENT_HISTORY_2006_08
WHERE SENTDATE >= TO_DATE('06/08/2006', 'DD/MM/YYYY
') AND SENTDATE < TO_DATE('09/08/2006', 'DD/MM/YYYY') ) H WHERE

Bad performance:
=================
Snaps: 11097 -11100 (3 Nov 2006)
Buffer Gets Executions Gets per Exec %Total Time (s) Time (s) Hash
Value
--------------- ------------ -------------- ------ -------- ---------
----------
68,707,993 28 2,453,856.9 9.1 1470.72 1602.69
2940048277
Module: JDBC Thin Client
SELECT T.TMP_CONTACT_LIST_ID, T.SRC_PKG_DETAIL_ID, T.TIME_SLOT_
ID, T.SENTDATE FROM CCM_TMP_CONTACT_LIST T WHERE EXISTS ( SELECT
H.RECIPIENT FROM ( SELECT RECIPIENT, SENTDATE FROM CCM_SENT_HIS
TORY_2006_10 WHERE SENTDATE >= TO_DATE('31/10/2006', 'DD/MM/YYYY
') AND SENTDATE < TO_DATE('03/11/2006', 'DD/MM/YYYY') UNION ALL

Please give some input on why it is doing more consistent gets and how to reduce it.There is no change in data in the table.

Thank you,
Rajesh


Tom Kyte
November 03, 2006 - 10:39 am UTC

what changed - why did the row count on the full scan go way way down for example?

Fishy!!

A reader, November 03, 2006 - 7:52 pm UTC

Either the stats are out of date, seems improbable, or a lot of deletion has taken place. Suggest you reset the HW Mark of the table in question there.
Tom, am I right?

How to test response time of the query

Dilipkumar Patel, November 09, 2006 - 7:25 am UTC

Hi Tom,

I have to test several queries for tuning which can return 40 to 50 Million rows, if I execute query and spool result in some file, my file system my get out of space, so what is the most effective way to test the response time of the query.

Right now I am using following method to test the query.

SQL> set timi on
SQL> 
SQL> select count(1) from
  2  (
  3  select <set_of_columns>
  6  from fact_table
  7  where 1 = 1
  8  and day_key between to_number(to_char(to_date('20061103', 'YYYYMMDD') -6, 'YYYYMMDD'), 99999999)
  9              and to_number(to_char(to_date('20061103', 'YYYYMMDD') -1, 'YYYYMMDD'), 99999999)
 10  )
 11  ;

  COUNT(1)
----------
  37085193

Elapsed: 00:00:09.09
SQL>

Please give your openion, is this fullproof way to test?

Thanks

Dilipkumar Patel 

Tom Kyte
November 09, 2006 - 8:55 am UTC

set autotrace traceonly
set arraysize 100 (or whatever size your program will use, to fetch millions, at least 100 to 500ish)
set timing on
alter session set sql_trace=true;
run query1
run query2...

exit


and tkprof it.

query consuming over 5Gb of temp tbs

San, November 10, 2006 - 3:27 pm UTC

Tom,

This is on 9i rel2, HP-UX 11i. The following query is consuming over 5 Gb of temp space and the db size is 1.6 Gb. I extracted the query from v$sort_usage while it consuimg all the temp space.
I cannot figure out a solution to it.

SELECT m.konctyp,m.koncern,m.bol,f.frper,MIN(l.toper) as toper,
m.percown,m.percvote,m.niva,m.modtyp,m.percdown
FROM UGECS_CLCKSTRCMNL_TMPSTRC1_4 m,
UGECS_CLCKSTRCMNL_TMPSTRC1_4 f,
UGECS_CLCKSTRCMNL_TMPSTRC1_4 l
WHERE m.konctyp = f.konctyp
AND m.koncern = f.koncern
AND m.bol=f.bol
AND m.percown = f.percown
AND m.percvote = f.percvote
AND m.niva=f.niva
AND m.modtyp = f.modtyp
AND m.percdown=f.percdown
AND m.metkonc = f.metkonc
AND m.ant = f.ant
AND m.konctyp = l.konctyp
AND m.koncern = l.koncern
AND m.bol=l.bol
AND m.percown=l.percown
AND m.percvote = l.percvote
AND m.niva=l.niva
AND m.modtyp = l.modtyp
AND m.percdown = l.percdown
AND m.metkonc = l.metkonc
AND m.ant = l.ant
AND f.frper <= l.toper
AND NOT exists (
SELECT * from UGECS_CLCKSTRCMNL_TMPSTRC1_4 p
WHERE p.toper = f.pper
AND p.percvote = f.percvote
AND p.konctyp = f.konctyp
AND p.percown = f.percown
AND p.bol = f.bol
AND p.koncern = f.koncern
AND p.niva = f.niva
AND p.modtyp = f.modtyp
AND p.percdown = f.percdown
AND p.metkonc = f.metkonc
AND p.ant = f.ant)
AND NOT exists(
SELECT * from UGECS_CLCKSTRCMNL_TMPSTRC1_4 n
WHERE n.frper = l.nper
AND n.percvote = l.percvote
AND n.konctyp = l.konctyp
AND n.percown = l.percown
AND n.bol = l.bol
AND n.koncern = l.koncern
AND n.niva = l.niva
AND n.modtyp = l.modtyp
AND n.percdown = l.percdown
AND n.metkonc = l.metkonc AND n.ant = l.ant)
GROUP BY m.konctyp,m.koncern,m.bol,f.frper,m.percown,m.percvote,m.niva,m.modtyp,m.percdown,m.metkonc ORDER BY m.konctyp,m.koncern,m.bol,f.frper

The execution plan is

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=58 Card=1 Bytes=152)
1 0 SORT (GROUP BY) (Cost=58 Card=1 Bytes=152)
2 1 HASH JOIN (ANTI) (Cost=45 Card=1 Bytes=152)
3 2 HASH JOIN (Cost=36 Card=1 Bytes=122)
4 3 NESTED LOOPS (Cost=27 Card=1 Bytes=96)
5 4 HASH JOIN (ANTI) (Cost=19 Card=1 Bytes=64)
6 5 TABLE ACCESS (FULL) OF 'UGECS_CLCKSTRCMNL_TMPSTRC1_4' (Cost=8 Card=4320 Bytes=146880)
7 5 TABLE ACCESS (FULL) OF 'UGECS_CLCKSTRCMNL_TMPSTRC1_4' (Cost=8 Card=4320 Bytes=129600)
8 4 TABLE ACCESS (FULL) OF 'UGECS_CLCKSTRCMNL_TMPSTRC1_4' (Cost=8 Card=4320 Bytes=138240)
9 3 TABLE ACCESS (FULL) OF 'UGECS_CLCKSTRCMNL_TMPSTRC1_4' (Cost=8 Card=4320 Bytes=112320)
10 2 TABLE ACCESS (FULL) OF 'UGECS_CLCKSTRCMNL_TMPSTRC1_4' (Cost=8 Card=4320 Bytes=129600)

Thanks
San

Tom Kyte
November 10, 2006 - 3:29 pm UTC

you don't really say "how big" these tables are - are the estimated cards= values even close to reality.

the plan looks PERFECT though.


your pga settings are "what"?

Temp tbs blowup

San, November 10, 2006 - 4:00 pm UTC

Sorry about that Tom.
The table count is 0 as of now but this is after i increased the temp tbs to 6 Gb and the module went through. It was during the execution of the module that i got the query and that was the only ACTIVE session.
The pga is 500 Mb.

Thanks
San

Tom Kyte
November 10, 2006 - 6:55 pm UTC

what does a table count of 0 mean?

Strange page behaviour in Firefox 2.0

S, November 10, 2006 - 8:56 pm UTC

Every time I try to view this thread my Firefox 2.0 on Windows XP gets stuck. After a while I'm asked if I want to let the script continue running or to stop it. It took me a few attempts to realize that when I choose stop I can see the page without problems. Any ideas?

Tom Kyte
November 11, 2006 - 8:10 am UTC

not me - works fine here

windows XP

firefox 2.0

Weird query...what does it do

Gary, November 13, 2006 - 2:27 am UTC

"the plan looks PERFECT though."
This is almost on a par with "The operation was a success but the patient died"

I've done a couple of tests (in 9iR2) and joining a table to itself on a couple of not null columns tends to massively underestimate the cardinality of the result set.
It doesn't seem to cater for the special case that a row will always match to itself. Given this example has ten joining columns and the table is joined to two other copies of itself (and two more on subqueries), I'd be amazed if Oracle can get any reasonable cardinality estimates.

Also, the 'm' version of UGECS_CLCKSTRCMNL_TMPSTRC1_4 actually looks superfluous. The columns you select from it are the same as the 'f' version, so you can get the columns from there and join 'f' directly to 'l' and drop 'm' from the query.




Tom Kyte
November 13, 2006 - 3:15 am UTC

this is not at all like "the operation...."

for the given query, and the supplied information, that is exactly the plan I would like to see - period.

big hash joins with anti joins for the not exists. I would guess that the card= values are way way off however - but we don't know that yet.

Temp tablespace blowup

San, November 14, 2006 - 12:58 pm UTC

Tom,

Ref. post "query consuming over 5Gb of temp tbs November 10, 2006", the number of rows in table UGECS_CLCKSTRCMNL_TMPSTRC1_4 is 4321. The query is a part of an insert statement and is executed within the application. There is little control we have over the code as it's a third party application. We can always suggest an alternative. For academic purposes too, i'd want to learn the optimized means of writing this query and why is it consuming an exorbitant amount of temp space.

Thanks
San

Tom Kyte
November 15, 2006 - 6:44 am UTC

but 5gb is not "outrageously large"

however, if the row count is really that low, I doubt it took 5gb, so "prove it", show me exactly how you measured this.

Trace

San, November 15, 2006 - 10:23 am UTC

Tom,

I'd generate the trace for the session when it executes again. Would post the trace output.

Regards
San

Trace output

San, November 15, 2006 - 5:14 pm UTC

Tom

I generated a 10046 trace event on the particular session. The trace file is 13Mb in size and the tkprof is also big enough.

I also have the output from

select sid,sess.username, sql.sql_text, sort.blocks,SEGRFNO#
FROM v$session sess,
v$sqltext sql,
v$sort_usage sort
WHERE sess.serial# = sort.session_num
AND sort.sqladdr = sql.address
AND sort.sqlhash = sql.hash_value
AND sort.blocks > 100
order by sid,piece
/

Since it wouldn't be feasible to post the logs here, how should i get it across ?

Thanks
San

Tom Kyte
November 16, 2006 - 8:27 am UTC

why do you have a trace? I didn't ask for one

serial# in v$session is not unique, that is a problem there -- just use v$sort_usage to "show this" (or that and v$sqltext, you need no more)

sort segment usage

San, November 16, 2006 - 12:07 pm UTC

select sid, sess.sql_address,(sum(sort.blocks)*8192)/(1024*1024) tmp_tbs_used
,sqt.sql_text TEXT
FROM v$session sess,
v$sort_usage sort,
v$sql sqt
WHERE sess.serial# = sort.session_num
and sess.sql_address=sort.sqladdr
and sess.sql_address=sqt.address
group by sid,sess.sql_address,sqt.sql_text
order by sid
/


SID SQL_ADDRESS TMP_TBS_USED TEXT
---- ---------------- ------------ -----------------------------------------------------------------------------
21 C000000126F31338 4695 INSERT INTO UGECS_CLCKSTRCMNL_TMPSTRC2_3 SELECT m.konctyp,m.koncern,m.bol,f.
frper,MIN(l.toper) as toper,m.percown,m.percvote,m.niva,m.modtyp,m.percdown
FROM UGECS_CLCKSTRCMNL_TMPSTRC1_4 m,UGECS_CLCKSTRCMNL_TMPSTRC1_4 f,UGECS_CLCK
STRCMNL_TMPSTRC1_4 l WHERE m.konctyp = f.konctyp AND m.koncern = f.koncern l=
f.bol AND m.percown = f.percown AND m.percvote = f.percvote AND m.niva=f.niva
AND m.modtyp = f.modtyp AND m.percdown = f.percdown AND m.metkonc = f.metkonc
AND m.ant = f.ant AND m.konctyp = l.konctyp AND m.koncern = l.koncern AND m.bo
l=l.bol AND m.percown =l.percown AND m.percvote = l.percvote AND m.niva=l.niva
AND m.modtyp = l.modtyp AND m.percdown = l.percdown AND m.modtyp = l.modtyp AND
m.percdown = l.percdown AND m.metkonc = l.metkonc AND m.ant = l.ant AND f.frper
<= l.toper AND NOT exists (SELECT * from UGECS_CLCKSTRCMNL_TMPSTRC1_4 p WHERE
p.toper = f.pper AND p.percvote = f.percvote AND p.konctyp = f.konctyp AND
p.percown = f.percown AND p.bol = f.bol AND p.koncern = f.koncern AND p.niva =
f.niva AND p.modtyp = f.modtyp AND p.percdown = f.percdown AND p.metkonc = f.
metkonc AND p.ant = f.ant) AND NOT exists(SELECT * from UGECS_CLCKSTRCMNL_TMPS
TRC1_4 n WHERE n.frper = l.nper AND n.percvote = l.percvote AND n.konctyp = l.
konctyp AND n.percown = l.percown AND n.bol = l.bol AND n.koncern = l.koncern
AND n.niva = l.niva AND n.modtyp = l.modtyp AND n.percdown = l.percdown AND n.
metkonc = l.metkonc AND n.ant = l.ant) GROUP BY m.konctyp,m.koncern,m.bol,f.fr
per,m.percown, m.percvote,m.niva,m.modtyp,m.percdown,m.metkonc ORDER BY m.konc
typ,m.koncern,m.bol,f.frper


Thanks
San

Tom Kyte
November 16, 2006 - 3:33 pm UTC

indexes?


meaning, is this just the select (just run the select, what does IT do). remember temp segments are converted to "real" after the fact in many cases.


and prove those row counts please

and how many rows get inserted (eg: got all of your joins right there?)

Same query different response time

Sujit Mondal, November 16, 2006 - 2:43 pm UTC

Tom,
I have the below query placed within a stored procedure.
Sometime I am getting response in milliseconds and
sometimes its going to about a minute. There is no other
operation going on in this database. Can you please give
me a clue on the same about where i am going wrong.
/********************************************************/
SELECT *
FROM (SELECT A.*,ROWNUM rnum
FROM (SELECT
a.activity_id activityid
,a.activity_type activity_type_id
,a.activity_status activity_status_id
,(select long_description from system_codes where
code_value = a.activity_status
AND system_code_id = a.activity_status_cd) activity_status
,CASE
WHEN (a.locked_by_party_id IS NOT NULL)
THEN 1
WHEN ( a.locked_by_party_id IS NULL AND a.activity_state = am_constants.c_investigating)
THEN 2
WHEN ( a.locked_by_party_id IS NULL AND a.activity_state <> am_constants.c_investigating)
THEN 0
END isactivitylocked
,CASE WHEN ( a.locked_by_party_id IS NULL AND a.activity_state = am_constants.c_investigating )
THEN a.investigating_party_id
ELSE NULL
END entityinvestigating
,CASE WHEN ( a.locked_by_party_id IS NULL AND a.activity_state = am_constants.c_investigating )
THEN (SELECT DISPLAY_NAME FROM ENTITY WHERE ENTITY_ID = a.INVESTIGATING_PARTY_ID)
ELSE NULL
END entitynameinvestigating
,(select long_description from system_codes where
code_value = a.activity_type
AND system_code_id = a.activity_type_cd) type_description
,(select long_description from system_codes where
code_value = a.activity_desc
AND system_code_id = a.activity_desc_cd) activity_description
,CASE WHEN ( a.assigned_to_party_id IS NOT NULL )
THEN (SELECT display_name FROM ENTITY WHERE ENTITY_ID = a.assigned_to_party_id)
ELSE NULL
END assigned_to_team
,(select reverse_alias_desc from relationship_alias_desc
where reverse_relationship_type=a.assigned_rel_type) assigned_to_role
,a.workable_item_due_dt AT LOCAL deadline
,CASE WHEN CURRENT_TIMESTAMP > a.workable_item_due_dt
THEN 1
ELSE 0
END over_due_flg
,CASE
WHEN a.processing_schedule_id IS NOT NULL
THEN 1
ELSE 0
END isrecurring
,CASE
WHEN CURRENT_TIMESTAMP > a.workable_item_due_dt
THEN '-1'
ELSE
EXTRACT (DAY FROM a.workable_item_due_dt - CURRENT_TIMESTAMP)*24+EXTRACT (HOUR FROM a.workable_item_due_dt- CURRENT_TIMESTAMP)
|| ':'|| EXTRACT (MINUTE FROM a.workable_item_due_dt- CURRENT_TIMESTAMP)
END timeuntildeadline
,CASE WHEN ( a.locked_by_party_id IS NOT NULL )
THEN (SELECT display_name FROM ENTITY WHERE ENTITY_ID = a.LOCKED_BY_PARTY_ID)
ELSE NULL
END lockedby
FROM activity a
WHERE
a.activity_state IN (
am_constants.c_pendingapproval,
am_constants.c_pendingresolution,
am_constants.c_pendingcompletion,
am_constants.c_pendingreview,
am_constants.c_investigating,
am_constants.c_pendingcancellation
)
AND a.assigned_to_party_id IN (select t1.assigned_to_party_id from (SELECT * FROM TABLE (CAST (Tab_Data3 as AM_SUMMARY_ARRAY3))) t1)
--AND a.assigned_to_party_id IN (13,14,16,24,25,100006)
ORDER BY 1) A
WHERE ROWNUM <=l_rows_to)
WHERE rnum >=l_rows_from
/*********************************************************/

Here is part of the tkprof output from trace file for two situations , please let me know if you need the complete tkprof output of the trace file in two situations.
Case 1:
/******************************************************/
SELECT *
FROM
(SELECT A.*,ROWNUM RNUM FROM (SELECT A.ACTIVITY_ID ACTIVITYID ,
A.ACTIVITY_TYPE ACTIVITY_TYPE_ID ,A.ACTIVITY_STATUS ACTIVITY_STATUS_ID ,
(SELECT LONG_DESCRIPTION FROM SYSTEM_CODES WHERE CODE_VALUE =
A.ACTIVITY_STATUS AND SYSTEM_CODE_ID = A.ACTIVITY_STATUS_CD)
ACTIVITY_STATUS ,CASE WHEN (A.LOCKED_BY_PARTY_ID IS NOT NULL) THEN 1 WHEN (
A.LOCKED_BY_PARTY_ID IS NULL AND A.ACTIVITY_STATE = :B2 ) THEN 2 WHEN (
A.LOCKED_BY_PARTY_ID IS NULL AND A.ACTIVITY_STATE <> :B2 ) THEN 0 END
ISACTIVITYLOCKED ,CASE WHEN ( A.LOCKED_BY_PARTY_ID IS NULL AND
A.ACTIVITY_STATE = :B2 ) THEN A.INVESTIGATING_PARTY_ID ELSE NULL END
ENTITYINVESTIGATING ,CASE WHEN ( A.LOCKED_BY_PARTY_ID IS NULL AND
A.ACTIVITY_STATE = :B2 ) THEN (SELECT DISPLAY_NAME FROM ENTITY WHERE
ENTITY_ID = A.INVESTIGATING_PARTY_ID) ELSE NULL END ENTITYNAMEINVESTIGATING
,(SELECT LONG_DESCRIPTION FROM SYSTEM_CODES WHERE CODE_VALUE =
A.ACTIVITY_TYPE AND SYSTEM_CODE_ID = A.ACTIVITY_TYPE_CD) TYPE_DESCRIPTION ,
(SELECT LONG_DESCRIPTION FROM SYSTEM_CODES WHERE CODE_VALUE =
A.ACTIVITY_DESC AND SYSTEM_CODE_ID = A.ACTIVITY_DESC_CD)
ACTIVITY_DESCRIPTION ,CASE WHEN ( A.ASSIGNED_TO_PARTY_ID IS NOT NULL ) THEN
(SELECT DISPLAY_NAME FROM ENTITY WHERE ENTITY_ID = A.ASSIGNED_TO_PARTY_ID)
ELSE NULL END ASSIGNED_TO_TEAM ,(SELECT REVERSE_ALIAS_DESC FROM
RELATIONSHIP_ALIAS_DESC WHERE REVERSE_RELATIONSHIP_TYPE=A.ASSIGNED_REL_TYPE)
ASSIGNED_TO_ROLE ,A.WORKABLE_ITEM_DUE_DT AT LOCAL DEADLINE ,CASE WHEN
CURRENT_TIMESTAMP > A.WORKABLE_ITEM_DUE_DT THEN 1 ELSE 0 END OVER_DUE_FLG ,
CASE WHEN A.PROCESSING_SCHEDULE_ID IS NOT NULL THEN 1 ELSE 0 END
ISRECURRING ,CASE WHEN CURRENT_TIMESTAMP > A.WORKABLE_ITEM_DUE_DT THEN '-1'
ELSE EXTRACT (DAY FROM A.WORKABLE_ITEM_DUE_DT - CURRENT_TIMESTAMP)
*24+EXTRACT (HOUR FROM A.WORKABLE_ITEM_DUE_DT- CURRENT_TIMESTAMP) || ':'||
EXTRACT (MINUTE FROM A.WORKABLE_ITEM_DUE_DT- CURRENT_TIMESTAMP) END
TIMEUNTILDEADLINE ,CASE WHEN ( A.LOCKED_BY_PARTY_ID IS NOT NULL ) THEN
(SELECT DISPLAY_NAME FROM ENTITY WHERE ENTITY_ID = A.LOCKED_BY_PARTY_ID)
ELSE NULL END LOCKEDBY FROM ACTIVITY A WHERE A.ACTIVITY_STATE IN ( :B6 ,
:B5 , :B4 , :B3 , :B2 , :B1 ) AND A.ASSIGNED_TO_PARTY_ID IN (SELECT
T1.ASSIGNED_TO_PARTY_ID FROM (SELECT * FROM TABLE (CAST (:B7 AS
AM_SUMMARY_ARRAY3))) T1) ORDER BY 1) A WHERE ROWNUM <=:B8 ) WHERE RNUM >=
:B9


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.18 0.23 0 8 0 0
Fetch 21 0.01 0.01 0 334 0 20
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 23 0.20 0.24 0 342 0 20

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 67 (PEDB) (recursive depth: 1)

Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT MODE: ALL_ROWS
0 VIEW
0 COUNT (STOPKEY)
0 VIEW
0 SORT (ORDER BY STOPKEY)
0 HASH JOIN (RIGHT SEMI)
0 COLLECTION ITERATOR (PICKLER FETCH)
0 TABLE ACCESS MODE: ANALYZED (FULL) OF 'ACTIVITY'
(TABLE)

/******************************************************/
Case 2
/******************************************************/
SELECT *
FROM
(SELECT A.*,ROWNUM RNUM FROM (SELECT A.ACTIVITY_ID ACTIVITYID ,
A.ACTIVITY_TYPE ACTIVITY_TYPE_ID ,A.ACTIVITY_STATUS ACTIVITY_STATUS_ID ,
(SELECT LONG_DESCRIPTION FROM SYSTEM_CODES WHERE CODE_VALUE =
A.ACTIVITY_STATUS AND SYSTEM_CODE_ID = A.ACTIVITY_STATUS_CD)
ACTIVITY_STATUS ,CASE WHEN (A.LOCKED_BY_PARTY_ID IS NOT NULL) THEN 1 WHEN (
A.LOCKED_BY_PARTY_ID IS NULL AND A.ACTIVITY_STATE = :B2 ) THEN 2 WHEN (
A.LOCKED_BY_PARTY_ID IS NULL AND A.ACTIVITY_STATE <> :B2 ) THEN 0 END
ISACTIVITYLOCKED ,CASE WHEN ( A.LOCKED_BY_PARTY_ID IS NULL AND
A.ACTIVITY_STATE = :B2 ) THEN A.INVESTIGATING_PARTY_ID ELSE NULL END
ENTITYINVESTIGATING ,CASE WHEN ( A.LOCKED_BY_PARTY_ID IS NULL AND
A.ACTIVITY_STATE = :B2 ) THEN (SELECT DISPLAY_NAME FROM ENTITY WHERE
ENTITY_ID = A.INVESTIGATING_PARTY_ID) ELSE NULL END ENTITYNAMEINVESTIGATING
,(SELECT LONG_DESCRIPTION FROM SYSTEM_CODES WHERE CODE_VALUE =
A.ACTIVITY_TYPE AND SYSTEM_CODE_ID = A.ACTIVITY_TYPE_CD) TYPE_DESCRIPTION ,
(SELECT LONG_DESCRIPTION FROM SYSTEM_CODES WHERE CODE_VALUE =
A.ACTIVITY_DESC AND SYSTEM_CODE_ID = A.ACTIVITY_DESC_CD)
ACTIVITY_DESCRIPTION ,CASE WHEN ( A.ASSIGNED_TO_PARTY_ID IS NOT NULL ) THEN
(SELECT DISPLAY_NAME FROM ENTITY WHERE ENTITY_ID = A.ASSIGNED_TO_PARTY_ID)
ELSE NULL END ASSIGNED_TO_TEAM ,(SELECT REVERSE_ALIAS_DESC FROM
RELATIONSHIP_ALIAS_DESC WHERE REVERSE_RELATIONSHIP_TYPE=A.ASSIGNED_REL_TYPE)
ASSIGNED_TO_ROLE ,A.WORKABLE_ITEM_DUE_DT AT LOCAL DEADLINE ,CASE WHEN
CURRENT_TIMESTAMP > A.WORKABLE_ITEM_DUE_DT THEN 1 ELSE 0 END OVER_DUE_FLG ,
CASE WHEN A.PROCESSING_SCHEDULE_ID IS NOT NULL THEN 1 ELSE 0 END
ISRECURRING ,CASE WHEN CURRENT_TIMESTAMP > A.WORKABLE_ITEM_DUE_DT THEN '-1'
ELSE EXTRACT (DAY FROM A.WORKABLE_ITEM_DUE_DT - CURRENT_TIMESTAMP)
*24+EXTRACT (HOUR FROM A.WORKABLE_ITEM_DUE_DT- CURRENT_TIMESTAMP) || ':'||
EXTRACT (MINUTE FROM A.WORKABLE_ITEM_DUE_DT- CURRENT_TIMESTAMP) END
TIMEUNTILDEADLINE ,CASE WHEN ( A.LOCKED_BY_PARTY_ID IS NOT NULL ) THEN
(SELECT DISPLAY_NAME FROM ENTITY WHERE ENTITY_ID = A.LOCKED_BY_PARTY_ID)
ELSE NULL END LOCKEDBY FROM ACTIVITY A WHERE A.ACTIVITY_STATE IN ( :B6 ,
:B5 , :B4 , :B3 , :B2 , :B1 ) AND A.ASSIGNED_TO_PARTY_ID IN (SELECT
T1.ASSIGNED_TO_PARTY_ID FROM (SELECT * FROM TABLE (CAST (:B7 AS
AM_SUMMARY_ARRAY3))) T1) ORDER BY 1) A WHERE ROWNUM <=:B8 ) WHERE RNUM >=
:B9


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.03 0.04 0 18 0 0
Execute 1 0.04 0.04 0 0 0 0
Fetch 21 21.54 57.23 178016 178986 0 20
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 23 21.62 57.32 178016 179004 0 20

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 67 (PEDB) (recursive depth: 1)

Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT MODE: ALL_ROWS
0 VIEW
0 COUNT (STOPKEY)
0 VIEW
0 SORT (ORDER BY STOPKEY)
0 HASH JOIN (RIGHT SEMI)
0 COLLECTION ITERATOR (PICKLER FETCH)
0 TABLE ACCESS MODE: ANALYZED (FULL) OF 'ACTIVITY'
(TABLE)


/******************************************************/

Tom Kyte
November 16, 2006 - 3:37 pm UTC

it is not obvious?

different inputs (binds) cause different amounts of work.

In both the cases I am passing the same input

Sujit Mondal, November 16, 2006 - 3:49 pm UTC

Tom,
In both cases I am passing the same Input and also the output is same.

Tom Kyte
November 16, 2006 - 4:06 pm UTC

quote "I doubt it"

"prove it"

Temp tablespace consumption

San, November 16, 2006 - 5:01 pm UTC

Tom

The result set of the sorting query was in reference to the posts

***** query consuming over 5Gb of temp tbs  November 10, 2006 
Reviewer:  San  from Mahwah, NJ

***** Temp tbs blowup  November 10, 2006
Reviewer:  San  from Mahwah, NJ

***** Temp tablespace blowup  November 14, 2006 
Reviewer:  San  from Mahwah, NJ 

***** Trace  November 15, 2006 
Reviewer:  San  from Mahwah, NJ 

***** Trace output  November 15, 2006 
Reviewer:  San  from Mahwah, NJ 

***** sort segment usage  November 16, 2006 
Reviewer:  San  from Mahwah, NJ 

Apparently i figured out that the tables, in which the data is being fed, are temporary tables. 

SQL> select owner, object_name, object_type, status, temporary
   from dba_objects
    where object_name = 'UGECS_CLCKSTRCMNL_TMPSTRC2_3';

OWNER                          OBJECT_NAME                    OBJECT_TYPE        STATUS  T
------------------------------ ------------------------------ ------------------ ------- -
COGNOS                         UGECS_CLCKSTRCMNL_TMPSTRC2_3   TABLE              VALID   Y

The insert is not the only sql executing at that point in time, BUT it is the only sql that's consuming temp tablespace in excess of 5 Gb. 

Tkprof output from 10046 event trace, that i generated against the module executing this query.

INSERT INTO UGECS_CLCKSTRCMNL_TMPSTRC2_3  SELECT m.konctyp,m.koncern,m.bol,
  f.frper,MIN(l.toper) as toper,                        m.percown,m.percvote,
m.niva,m.modtyp,m.percdown                                    FROM 
  UGECS_CLCKSTRCMNL_TMPSTRC1_4 m,UGECS_CLCKSTRCMNL_TMPSTRC1_4 f,
  UGECS_CLCKSTRCMNL_TMPSTRC1_4 l                                    WHERE 
  m.konctyp = f.konctyp AND m.koncern = f.koncern                             
               AND m.bol=f.bol AND m.percown = f.percown                      
                        AND m.percvote = f.percvote AND m.niva=f.niva         
                                 AND m.modtyp = f.modtyp AND m.percdown = 
  f.percdown                                  AND m.metkonc = f.metkonc AND 
  m.ant = f.ant                                   AND m.konctyp = l.konctyp 
  AND m.koncern = l.koncern                                         AND m.bol=
  l.bol AND m.percown = l.percown                                            
  AND m.percvote = l.percvote AND m.niva=l.niva                               
           AND m.modtyp = l.modtyp AND m.percdown = l.percdown                
                    AND m.metkonc = l.metkonc AND m.ant = l.ant               
                     AND f.frper <= l.toper                                   
                            AND NOT exists                                    
                                         (SELECT * from 
  UGECS_CLCKSTRCMNL_TMPSTRC1_4 p WHERE p.toper = f.pper                       
                AND p.percvote = f.percvote AND p.konctyp = f.konctyp         
                         AND p.percown = f.percown AND p.bol = f.bol          
                                  AND p.koncern = f.koncern AND p.niva = 
  f.niva                                        AND p.modtyp = f.modtyp AND 
  p.percdown = f.percdown                                  AND p.metkonc = 
  f.metkonc AND p.ant = f.ant)                                 AND NOT exists 
                                                                            
  (SELECT * from UGECS_CLCKSTRCMNL_TMPSTRC1_4 n WHERE n.frper = l.nper        
                               AND n.percvote = l.percvote AND n.konctyp = 
  l.konctyp                                AND n.percown = l.percown AND 
  n.bol = l.bol                                          AND n.koncern = 
  l.koncern AND n.niva = l.niva                                        AND 
  n.modtyp = l.modtyp AND n.percdown = l.percdown                             
       AND n.metkonc = l.metkonc AND n.ant = l.ant)                           
      GROUP BY m.konctyp,m.koncern,m.bol,f.frper,m.percown,                   
                        m.percvote,m.niva,m.modtyp,m.percdown,m.metkonc       
                        ORDER BY m.konctyp,m.koncern,m.bol,f.frper


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        3      0.03       0.02          0          0          0           0
Execute      4    289.87     751.02     909615     566282        764       19698
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        7    289.90     751.04     909615     566282        764       19698

Misses in library cache during parse: 3
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 22  

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  direct path write                           42897        0.00          0.05
  direct path read                            60641        0.00          0.06
  log file sync                                   4        0.03          0.03
  SQL*Net message to client                       4        0.00          0.00
  SQL*Net message from client                     4        0.00          0.00
********************************************************************************

Thanks
San 

Tom Kyte
November 16, 2006 - 5:11 pm UTC

well, so, can you VERIFY that your row counts are even remotely close to accurate, since you didn't even know these where global temporary tables, at the time of the "BLOWOUT" of temp.

Inquiring readers want to know (and sort of "doubt it")

Guess so

San, November 16, 2006 - 5:31 pm UTC

Tom,

While creating an index specifying the tablespace, eventually receiving an error, i realized that these were global temporary tables.
I presume that the row count from the trace is close to accurate at the time of temp tablespace blowout.
Considering that be the case, is it viable to look at the query and start optimizing it ?
Am requesting for suggestions.

Regards
San

Tom Kyte
November 17, 2006 - 3:11 am UTC

the question is how big are the objects referenced in the query itself, you should really have a bit of knowledge about that you can share.

I want to know from this query what should be avoided

Razani, November 20, 2006 - 6:58 am UTC

select i.contrno, e.equipid, i.subno, i.applied,
trunc(nvl(decode((i.changed - i.discon) - abs(i.changed - i.discon), 0,i.changed,i.discon),i.changed)) discon,
m.maf,m.usage
from cmk_manas_mother m, crm_user_info i, crm_user_equipments e
where m.subno = i.subno
and i.subno = e.subno
and e.equipid like 'EQ%'



Tom Kyte
November 20, 2006 - 1:39 pm UTC

that has to be among the most strange questions I've ever received.

I absolutely have no idea how to respond.

Temp tablespace blowup

San, November 20, 2006 - 3:40 pm UTC

Tom, Ref Post "*****Guess so November 16, 2006
Reviewer: San from Mahwah, NJ "

I generated a trace again to determine how many rows are being inserted and simultaneously took a snapshot of the query consuming over 5Gb of temp space.
Below is the tkprof output

INSERT INTO UGECS_CLCKSTRCMNL_TMPSTRC2_3 SELECT m.konctyp,m.koncern,m.bol,f.frper,MIN(l.toper) as toper,m.percown,m.percvote,m.niva,m.modtyp,m.percdown FROM
UGECS_CLCKSTRCMNL_TMPSTRC1_4 m,UGECS_CLCKSTRCMNL_TMPSTRC1_4 f, UGECS_CLCKSTRCMNL_TMPSTRC1_4 l WHERE m.konctyp = f.konctyp AND m.koncern = f.koncern AND
m.bol=f.bol AND m.percown = f.percown AND m.percvote = f.percvote AND m.niva=f.niva AND m.modtyp = f.modtyp AND m.percdown =f.percdown AND m.metkonc
=f.metkonc AND m.ant = f.ant AND m.konctyp = l.konctyp AND m.koncern = l.koncern AND m.bol= l.bol AND m.percown = l.percown AND m.percvote = l.percvote AND
m.niva=l.niva AND m.modtyp = l.modtyp AND m.percdown = l.percdown AND m.metkonc = l.metkonc AND m.ant = l.ant AND f.frper <= l.toper AND NOT exists (SELECT *
from UGECS_CLCKSTRCMNL_TMPSTRC1_4 p WHERE p.toper = f.pper AND p.percvote = f.percvote AND p.konctyp = f.konctyp AND p.percown = f.percown AND p.bol = f.bol
AND p.koncern = f.koncern AND p.niva = f.niva AND p.modtyp = f.modtyp AND p.percdown = f.percdown AND p.metkonc = f.metkonc AND p.ant = f.ant) AND NOT exists
(SELECT * from UGECS_CLCKSTRCMNL_TMPSTRC1_4 n WHERE n.frper = l.nper AND n.percvote = l.percvote AND n.konctyp = l.konctyp AND n.percown = l.percown AND
n.bol = l.bol AND n.koncern = l.koncern AND n.niva = l.niva AND n.modtyp = l.modtyp AND n.percdown = l.percdown AND n.metkonc = l.metkonc AND n.ant =
l.ant) GROUP BY m.konctyp,m.koncern,m.bol,f.frper,m.percown, m.percvote,m.niva,m.modtyp,m.percdown,m.metkonc ORDER BY m.konctyp,m.koncern,m.bol,f.frper


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3 0.02 0.02 0 0 0 0
Execute 4 328.70 856.16 917896 568832 768 19788
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 7 328.72 856.18 917896 568832 768 19788

Misses in library cache during parse: 3
Misses in library cache during execute: 1
Optimizer goal: CHOOSE
Parsing user id: 22

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
direct path read 25722 0.00 0.02
db file sequential read 1 0.01 0.01
log file sync 4 0.02 0.03
SQL*Net message to client 4 0.00 0.00
SQL*Net message from client 4 0.00 0.00
direct path write 17847 0.00 0.02
********************************************************************************

Output of
select sid, sess.sql_address,(sum(sort.blocks)*8192)/(1024*1024) tmp_tbs_used
,sqt.sql_text TEXT
FROM v$session sess,
v$sort_usage sort,
v$sql sqt
WHERE sess.serial# = sort.session_num
AND sort.blocks > 100
and sess.sql_address=sqt.address
and sort.sqladdr=sess.sql_address
group by sid,sess.sql_address,sqt.sql_text
order by sid

SID SQL_ADDRESS TMP_TBS_USED TEXT
---- ---------------- ------------ ----------------------------------------------------------------------
17 C000000102C28A30 5467 INSERT INTO UGECS_CLCKSTRCMNL_TMPSTRC2_3 SELECT m.konctyp,m.koncern,m.bol,f.frper,MIN(l.toper) as toper, m.percown,m.percvote,m.niva,m.modtyp,m.percdown FROM UGECS_CLCKSTRCMNL_TMPSTRC1_4 m,UGECS_CLCKSTRCMNL_TMPSTRC1_4 f,UGECS_CLCKSTRCMNL_TMPSTRC1_4 l

Thanks
San


Matthew, November 21, 2006 - 1:52 pm UTC

If my 8.1.7.antique database is using 'too much' CPU, but is doing fine for I/O then what diagnostics should I be looking at to find out where the low hanging fruit are?

Bitmap index

Lise, November 30, 2006 - 5:04 am UTC

Is it the case that Oracle can choose to use a bitmap index on a query with many AND/ORs in the WHERE clause, even though no bitmap index has been created for any of the tables in the query?

Tom Kyte
November 30, 2006 - 9:59 am UTC

Oracle can choose to do a b*tree bitmap conversion - yes. It'll create in effect a bitmap index on the fly for the query to use.

Its was usefull

Navendu Badal Mohanty, December 02, 2006 - 3:50 am UTC

Hi Tom,
Your contribution to all the DBAs are really very appreciable,i liked it.

I would also like to ask you few queries,so please let me have your email id so that i can send you my queries thorugh email.

Thankx
Navendu Badal Mohanty

Tom Kyte
December 02, 2006 - 1:03 pm UTC

hahaha, yeah, that'd be a way to really increase my throughput.

to "Navendu Badal Mohanty" from India

mlot, December 03, 2006 - 3:07 am UTC

sheesh...what is it with you people ?
Yes, I have seen it several times on this site in particular.
It is almost always "you people" that post verbally polite but bonehead questions like yours.

Tom Kyte
December 03, 2006 - 7:42 am UTC

Well, then again, there are posts like yours here which add equally as much value (or less perhaps as it does appear stereotypical in nature)

These come from all over the planet...

Query Performance with NULL predicate

A reader, December 27, 2006 - 2:33 am UTC

HI, Tom,

I have a table at Oracle9i RAC database defined as:
create table my_table
(class_id varchar2(8),
alert_id varchar2(10),
severity_level number(2,0),
alert_clear_date date);

create index my_index on my_table (class_id, alert_id)

There are total about 9.5M rows in the table, and there are about 60 rows with alert_clear_date is null.

The update statement below runs very slow:
update my_table set alert_clear_date=sysdate where class_id=:b0 and alert_id=:b1 and alert_clear_date is null

The update statements took average of 9 seconds for a single execution.

I did an analyze on the table for all indexes and all columns, and the performance is even worse that now it takes 300 to 600 seconds for one execution.

My questions:
1) Why my analyze generates much worse performance?
2) How can I tune such statement involving a predicate of NULL?

Thanks

Tom Kyte
December 28, 2006 - 8:37 am UTC

got plans - you should be using sql_trace and tkprof like you see in use on this site over and over again to see what is happening here.

If you added "alert_clear_date" to the index, it would be pretty helpful probably - as we would be able to find JUST the sixty rows of interest fast without having to hip hop between index and table.

In fact, placing alert_clear_date first in said index would be "most efficient" for this particular update (remember I said for this particular update, might not be the best thing for other queries that currently use this index, only you can answer that)

Full Table Scan

Kubilay, December 29, 2006 - 8:57 am UTC

Hi Tom

Happy New Year!

I am working on your book "Effective Oracle by Design" page 305 trying to get the BIG_TABLE (s) to full scan and not to use the index, to prove to myself that full scans are not evil and indexes are not always good.

But it still does use the index and doesn't choose to do a full scan even if stats are calculated ok, index is there and I am using CBO.
NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
optimizer_dynamic_sampling           integer     0
optimizer_features_enable            string      10.2.0.1
optimizer_index_caching              integer     0
optimizer_index_cost_adj             integer     100
optimizer_mode                       string      CHOOSE
optimizer_secure_view_merging        boolean     TRUE



No matter CBO or RBO hint the Explain plan is like below.

The BIG_TABLE has got 2mil rows and this is the autotrace report, why doesn't it full scan?

SQL> l
  1  select  t1.object_name, t2.object_name
  2  from big_table t1, big_table t2
  3  where t1.object_id = t2.object_id
  4* and t1.owner='SYSTEM'
SQL>


Execution Plan
----------------------------------------------------------
Plan hash value: 1234373641

------------------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name                | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                     | 62848 |  4050K|       | 13926   (1)| 00:02:48 |
|*  1 |  HASH JOIN                   |                     | 62848 |  4050K|  2952K| 13926   (1)| 00:02:48 |
|   2 |   TABLE ACCESS BY INDEX ROWID| BIG_TABLE           | 62848 |  2209K|       |  2061   (1)| 00:00:25 |
|*  3 |    INDEX RANGE SCAN          | BIG_TABLE_OWNER_IDX | 62848 |       |       |   151   (2)| 00:00:02 |
|   4 |   TABLE ACCESS FULL          | BIG_TABLE           |  1996K|    57M|       |  7705   (2)| 00:01:33 |
------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("T1"."OBJECT_ID"="T2"."OBJECT_ID")
   3 - access("T1"."OWNER"='SYSTEM')


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
      86329  consistent gets
      22720  physical reads
          0  redo size
   51125972  bytes sent via SQL*Net to client
     793305  bytes received via SQL*Net from client
      72078  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
    7207620  rows processed

Tom Kyte
December 29, 2006 - 10:03 am UTC

use a hint then.

things change over time - especially with 10g and cpu costing and such.

partition access

abz, December 29, 2006 - 11:22 am UTC

select * from customer where code='B'

The customer table is LIST partitioned on code column.
There are alltogather 3 distinct values for code and that is 'A', 'B' and 'C', and therefore 3 partitions namely code_a, code_b, code_c.
There is an index on customer.code column.

The plan of above query shows that it first accesses
the index and then access the code_b partition.

Why it not directly and only access the code_b partition,
why extra work of accessing the index.

Every thing is analyzed.


Tom Kyte
December 30, 2006 - 8:52 am UTC

show us, show us the REAL query and the REAL plan.

cut and pasted, right out of sqlplus.

Oracle consulting company tips for tuning

tc, December 29, 2006 - 9:23 pm UTC

Wanted to know what you thought about the tuning tips suggested by a consulting company:
Tips for more efficient SQL

* Never do a calculation on an indexed column (e.g., WHERE salary*5 > :myvalue).

* Whenever possible, use the UNION statement instead of OR conditions.

* Avoid the use of NOT IN or HAVING in the WHERE clause. Instead, use the NOT EXISTS clause.

* Always specify numeric values in numeric form and character values in character form (e.g., WHERE emp_number = 565, WHERE emp_name = `Jones¿).

* Avoid specifying NULL in an indexed column.

* Avoid the LIKE parameter if = will suffice. Using any Oracle function will invalidate the index, causing a full-table scan.

* Never mix data types in Oracle queries, as it will invalidate the index. If the column is numeric, remember not to use quotes (e.g., salary = 50000). For char index columns, always use single quotes (e.g., name = 'X').

* Avoid using subqueries when a JOIN will do the job.

* Use the Oracle ¿decode¿ function to minimize the number of times a table has to be selected.

* To turn off an index you do not want to use (only with a cost-based optimizer), concatenate a null string to the index column name (e.g., name||') or add zero to a numeric column name (e.g., salary+0). With the rule-based optimizer, this allows you to manually choose the most selective index to service your query.

* If your query will return more than 20 percent of the rows in the table, a full-table scan may be better than an index scan.

* Always use table aliases when referencing columns.

Tom Kyte
December 30, 2006 - 9:35 am UTC

1) not doing the function on a database column makes sense.

2) using union - not sensible and leads to a different answer. Union implies an expensive "unique" operation on the result set.

ops$tkyte%ORA10GR2> create table t ( x int, y int );

Table created.

ops$tkyte%ORA10GR2> insert into t values ( 1, 1 );

1 row created.

ops$tkyte%ORA10GR2> insert into t values ( 1, 1 );

1 row created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select * from t where x = 1 or y = 1;

         X          Y
---------- ----------
         1          1
         1          1

ops$tkyte%ORA10GR2> select * from t where x = 1
  2  union
  3  select * from t where y = 1;

         X          Y
---------- ----------
         1          1

ops$tkyte%ORA10GR2>


3) nope. First of all - having is not in the where clause, it is a clause itself and is the only thing you can use to filter on aggregated information. So to say "don't use", well that is not smart.

And the CBO understands when not in and not exists are equivalent (and then again, when they are NOT, because they - like union - return different answers!!!). It'll cost out both. You don't have to avoid not in.

4) yes, the rule of life is "compare strings to strings, numbers to numbers, dates to dates - avoid IMPLICIT CONVERSIONS LIKE THE PLAGUE"

5) no, the rule is "assert NOT NULL for all NOT NULLABLE COLUMNS", period. Nulls are indexed, we can use indexes to find "nulls" easily. You use constraints to provide for data integrity.

6) well, they should have stopped with:

avoid the like 'parameter' (well, it is an operator, but...) if = will suffice.

That way they would look "smarter", to contain on and say 'because it will invalidate the index, causing a full table scan' makes them look less smart. It will never 'invalidate' the index first of all - never. And it'll never "cause" (eg: force) a full scan.


drop table t;
create table t as select * from all_objects;
create index t_idx on t(object_name);
variable x varchar2(30)
exec :x := 'X%';
set termout off
alter session set sql_trace=true;
select * from t where object_name like 'X%';
select * from t where object_name like :x;
set termout on


select *
from
 t where object_name like 'X%'

Rows     Row Source Operation
-------  ---------------------------------------------------
    250  TABLE ACCESS BY INDEX ROWID T (cr=131 pr=0 pw=0 time=3314 us)
    250   INDEX RANGE SCAN T_IDX (cr=20 pr=0 pw=0 time=541 us)(object id 61890)
********************************************************************************
select *
from
 t where object_name like :x

Rows     Row Source Operation
-------  ---------------------------------------------------
    250  TABLE ACCESS BY INDEX ROWID T (cr=131 pr=0 pw=0 time=3808 us)
    250   INDEX RANGE SCAN T_IDX (cr=20 pr=0 pw=0 time=1036 us)(object id 61890)




7) Again, they should have been more terse :)

Or used the right reasoning. it will not necessarily 'invalidate' the index (well, it'll NEVER invalidate it, it might preclude it from being considered!!!)

but this is just #4 all over again

8) ouch. No. see
https://www.oracle.com/technetwork/issue-archive/2006/06-nov/o66asktom-099001.html
last bit of that article.

9) eh? no idea what that means

10) no.

11) if your query will return 5% that might be true also. They should just say "indexes are not all goodness, full scans are not all evil"

12) that is solid advice, avoids issues like this:

ops$tkyte%ORA10GR2> select * from scott.dept where deptno in (select deptno from dual);

DEPTNO DNAME LOC
---------- -------------- -------------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON

cut/paste from sqlplus

abz, January 03, 2007 - 5:02 am UTC

SQL> explain plan for select * from customer_history where unit_code='A';

Explained.

SQL> select plan_table_output from table(dbms_xplan.display('PLAN_TABLE',null,'ALL'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1968561208

-----------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 18M| 2964M| 92840 (2)| 00:18:35 | | |
| 1 | TABLE ACCESS BY GLOBAL INDEX ROWID| CUSTOMER_HISTORY | 18M| 2964M| 92840 (2)| 00:18:35 | 1 | 1 |
|* 2 | INDEX RANGE SCAN | CUSTHIST_UNTCUST | 18M| | 10540 (2)| 00:02:07 | | |
-----------------------------------------------------------------------------------------------------------------------

Tom Kyte
January 05, 2007 - 7:56 am UTC

so? what is your point?

NOT IN and NOT EXISTS

abz, January 03, 2007 - 5:12 am UTC

Can you please show us how can be the answers of
NOT IN and NOT EXISTS be different.
Tom Kyte
January 05, 2007 - 8:06 am UTC

ops$tkyte%ORA9IR2> create table t1 ( x int );

Table created.

ops$tkyte%ORA9IR2> insert into t1 values ( 1 );

1 row created.

ops$tkyte%ORA9IR2> create table t2 ( y int );

Table created.

ops$tkyte%ORA9IR2> insert into t2 values (null);

1 row created.

ops$tkyte%ORA9IR2>
ops$tkyte%ORA9IR2> select *
  2    from t1
  3   where x not in (select y from t2);

no rows selected

ops$tkyte%ORA9IR2>
ops$tkyte%ORA9IR2> select *
  2    from t1
  3   where NOT EXISTS (select null from t2 where t2.y = t1.x);

         X
----------
         1



all about nulls...

my point

abz, January 05, 2007 - 8:32 am UTC

My point was , I did SELECT *
which means I want all columns, there is a separate,
only one, partition for unit_code='A',
there is no other predicate, then it should be simply
full scan of partition.
Why the overhead of scanning an index and then the
partition.

Excellent example of NOT IN and NOT EXISTS.

Tom Kyte
January 05, 2007 - 9:58 am UTC

need more information. can you reproduce this for us (using dbms_stats.set_.... to set statistics to replicate your existing system)

curious

me, January 05, 2007 - 8:51 am UTC

I am curious as to why "select * from scott.dept where deptno in (select deptno from dual); " works.
Tom Kyte
January 05, 2007 - 9:59 am UTC

select * from scott.dept where deptno in (select deptno from dual)

is identical to

select * from scott.dept where deptno in (select dept.deptno from dual)


it was a correlated subquery, the row from the outer query is available to the inner query.

statistics

abz, January 05, 2007 - 10:28 am UTC

Can't actually get what you mean but,

Here are the statistics of the table

Last Analyzed Dec 31, 2006 1:48:53 AM
Empty Blocks 0
Average Space 0
Number of Rows 25840085
Sample Size 947092
Average Row Length 172
Continued Row Count 0
Average Space Freelist Blocks 0
Number of Freelist Blocks 0

And here are the statistics of the index
Last Analyzed 2006-12-31 01:49:08
Blevel 3
Distinct Keys 1941377
Clustering Factor 811092
Leaf Blocks 103645
Average Leaf Blocks Per Key 1
Average Data Blocks Per Key 1
Number of Rows 26538816
Sample Size 299583








Tom Kyte
January 06, 2007 - 8:15 am UTC

what you need to do is.....

provide me a test case, just like I do for you.


we don't know your schema AT ALL.

NOT IN and NOT EXISTS

abz, January 05, 2007 - 11:39 am UTC

Ok, so can we say that
if all the columns involved are NOT NULL
then there is no difference between
the answers of NOT IN and NOT EXISTS?

Tom Kyte
January 06, 2007 - 8:32 am UTC

correct, and the optimizer is fully well aware of that fact itself (the cost based one is in any case).

SQL

A reader, January 09, 2007 - 4:15 pm UTC

Tom,

Following query takes a long time to execute. Could you please suggest alternatives to reduce the number of outer joins?

select a.ssn_nbr as member_id,
a.first_nm,
a.last_nm,
b.get_application_seq,
b.cntrct_id,
b.co_id,
trunc(b.application_submit_dt) as submit_dt,
trunc(b.intl_add_dtt) as app_add,
trunc(b.complete_dt) as complete_dt,
l.family_status_descp as family_status_cd,
b.appl_is_mbr_flg,
nvl(b.submission_method_cd, 'Unknown Origin') as submission_method_cd,
nvl(d.prdct_id, '') as product_id,
nvl(c.decision_cd, '') as decision_cd,
nvl(c.decision_dt, '') as decision_dt,
initcap(nvl(e.decision_class, '')) as decision_class,
d.shrt_nm as prdct_nm,
initcap(nvl(f.reason_cd, 'Unknown')) as reason_cd,
nvl(g.servicing_ee_grp_offc_cd, 'Unassigned') as office,
initcap(nvl(i.region_nm, 'Unassigned')) as region,
trunc(min(decode(j.event_cd, 'FSET', j.start_dt))) as file_setup_dt,
trunc(min(decode(j.event_cd, 'NOMB', j.start_dt))) as NOMB_dt,
(trunc(b.complete_dt) - trunc(b.application_submit_dt))+1 as actual_days,
c.get_application_coverage_seq
from get_person a,
get_application b,
get_application_coverage c,
product d,
get_decision e,
get_cvrg_decision_rsn f,
gac_active_pln_srvc_emp g,
sic_sales_office h,
sic_region i,
get_uwtg_event j,
get_family_status l
where a.get_person_seq = b.applicant_get_person_seq (+)
and b.get_application_seq = c.get_application_seq (+)
and c.product_id = d.product_id (+)
and c.co_id = d.co_id (+)
and c.decision_cd = e.decision_cd (+)
and c.co_id = e.co_id (+)
and c.get_application_seq = f.get_application_seq (+)
and c.get_application_coverage_seq = f.get_application_coverage_seq (+)
and b.cntrct_id = g.contract_nbr (+)
and g.servicing_ee_grp_offc_cd = h.sales_offc_cd
and g.co_id = h.co_id (+)
and h.sic_region_seq = i.sic_region_seq (+)
and b.get_application_seq = j.get_application_seq (+)
and b.family_status_cd = l.family_status_cd
and b.co_id in ('SI', 'YI')
and (trunc(b.application_submit_dt) >= '18-DEC-2006' or trunc(c.decision_dt) >= '18-DEC-2006') -- this needs to be current year-3
group by a.ssn_nbr,
a.first_nm,
a.last_nm,
b.get_application_seq,
b.cntrct_id,
b.co_id,
trunc(b.application_submit_dt),
trunc(b.intl_add_dtt),
trunc(b.complete_dt),
l.family_status_descp,
b.appl_is_mbr_flg,
nvl(b.submission_method_cd, 'Unknown Origin'),
nvl(d.prdct_id, ''),
nvl(c.decision_cd, ''),
nvl(c.decision_dt, ''),
nvl(e.decision_class, ''),
d.shrt_nm,
initcap(nvl(f.reason_cd, 'Unknown')),
nvl(g.servicing_ee_grp_offc_cd, 'Unassigned'),
initcap(nvl(i.region_nm, 'Unassigned')),
c.get_application_coverage_seq

SQL

A reader, January 10, 2007 - 1:16 pm UTC

I rewrote the query above but still not getting the best.
Tables have 1:m relationships so can't write scalar subqueries much here. Can you please help??

select distinct a.ssn_nbr as member_id,
a.first_nm,
a.last_nm,
b.get_application_seq,
b.cntrct_id,
b.co_id,
trunc(b.application_submit_dt) as submit_dt,
trunc(b.intl_add_dtt) as app_add,
trunc(b.complete_dt) as complete_dt,
l.family_status_descp as family_status_cd,
b.appl_is_mbr_flg,
nvl(b.submission_method_cd, 'Unknown Origin') as submission_method_cd,
d.prdct_id as product_id,
c.decision_cd as decision_cd,
c.decision_dt as decision_dt,
initcap(nvl(e.decision_class, '')) as decision_class,
d.shrt_nm as prdct_nm,
initcap(nvl(f.reason_cd, 'Unknown')) as reason_cd,
nvl(g.servicing_ee_grp_offc_cd, 'Unassigned') as office,
initcap(nvl(i.region_nm, 'Unassigned')) as region,
(select trunc(min(decode(j.event_cd, 'FSET', j.start_dt))) ||
trunc(min(decode(j.event_cd, 'NOMB', j.start_dt)))
from get_uwtg_event j
where b.get_application_seq = j.get_application_seq
) file_setup_dt,
(trunc(b.complete_dt) - trunc(b.application_submit_dt))+1 as actual_days,
c.get_application_coverage_seq
from get_person a,
get_application b,
get_application_coverage c,
product d,
get_decision e,
get_cvrg_decision_rsn f,
gac_active_pln_srvc_emp g,
sic_sales_office h,
sic_region i,
get_family_status l
where a.get_person_seq = b.applicant_get_person_seq
and b.get_application_seq = c.get_application_seq (+)
and c.product_id = d.product_id (+)
and c.co_id = d.co_id (+)
and c.get_application_seq = f.get_application_seq (+)
and c.get_application_coverage_seq = f.get_application_coverage_seq (+)
and c.decision_cd = e.decision_cd (+)
and c.co_id = e.co_id (+)
and b.cntrct_id = g.contract_nbr (+)
and g.servicing_ee_grp_offc_cd = h.sales_offc_cd
and g.co_id = h.co_id (+)
and h.sic_region_seq = i.sic_region_seq (+)
and b.family_status_cd = l.family_status_cd
and b.co_id in ('SI', 'YI')
and (b.application_submit_dt >= '18-DEC-2006' or c.decision_dt >= '18-DEC-2006') -- this needs to be current year-3

SQL tuning group,

A reader, January 11, 2007 - 10:23 pm UTC

Within the DBA organization, if there is a new group called "SQL Tuning Group" to help different segments about writing efficient SQL queries, what would you think the services the group can offer to them (most likely developers)?

What should we highlight in our message about SQL tuning?

Do you think in a global company this kind of group make sense?

Just curious to know your opinion.

Thanks,

High consistent reads

Ravi, January 26, 2007 - 6:42 am UTC

hi Tom,
i am running the following query on an HP Unix,6CPU box.
I can see lot of I/O happening.
select
table_case.objid as elm_objid,
table_user.objid as user_objid,
table_condition.objid as condition_objid,
table_gbst_elm.objid as gbst_elm_objid,
table_case.id_number as id_number,
table_case.title as title,
table_condition.condition as clarify_state,
table_condition.title as condition,
table_gbst_elm.title as status,
table_user.login_name as owner,
table_case.creation_time as creation_time,
table_case.is_supercase as is_supercase,
table_case.x_svc_id as x_svc_id,
table_case.x_equip_id as x_equip_id,
table_case.x_clearcode1 as x_clearcode1,
table_case.x_clearcode2 as x_clearcode2,
table_case.x_clearcode3 as x_clearcode3,
table_case.case_type_lvl1 as x_case_type,
table_case.x_cp_fault_reference as x_cp_fault_reference,
table_case.x_fault_create_dt as x_fault_create_dt,
table_case.x_time_of_closure as x_time_of_closure
from table_gbst_elm
inner join table_case on table_gbst_elm.objid = table_case.casests2gbst_elm
inner join table_user on table_user.objid = table_case.case_owner2user
inner join table_condition on table_condition.objid = table_case.case_state2condition

1388595 rows selected.


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=5553206 Card=138
5391 Bytes=346347750)

1 0 NESTED LOOPS (Cost=5553206 Card=1385391 Bytes=346347750)
2 1 NESTED LOOPS (Cost=4167815 Card=1385391 Bytes=321410712)
3 2 NESTED LOOPS (Cost=2782424 Card=1385391 Bytes=29647367
4)

4 3 TABLE ACCESS (FULL) OF 'TABLE_CASE' (Cost=11630 Card
=1385397 Bytes=260454636)

5 3 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_CONDITION' (
Cost=2 Card=1 Bytes=26)

6 5 INDEX (UNIQUE SCAN) OF 'SYS_C008395' (UNIQUE) (Cos
t=1 Card=1)

7 2 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_USER' (Cost=1
Card=1 Bytes=18)

8 7 INDEX (UNIQUE SCAN) OF 'SYS_C008983' (UNIQUE)
9 1 TABLE ACCESS (BY INDEX ROWID) OF 'TABLE_GBST_ELM' (Cost=
1 Card=1 Bytes=18)

10 9 INDEX (UNIQUE SCAN) OF 'SYS_C008584' (UNIQUE)




Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
8893640 consistent gets
211341 physical reads
0 redo size
74237511 bytes sent via SQL*Net to client
648280 bytes received via SQL*Net from client
92574 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1388595 rows processed


Do you see any other way to reduce the high LIO.
I suggested to add one more filter to the query. But the Production support group says there is no other filter that can be added to reduce the number of rows.

can you please look into the query and suggest some way to reduce the LIO's

Thanks in advance,
Ravi

count(*)

Branka, January 31, 2007 - 11:06 am UTC

I have select
SELECT APPLICATION_ID FROM ST_APPLICATION
WHERE STATUS=:1

I wanted to get execution time, so I thought that I can use SELECT count(*) FROM ST_APPLICATION
WHERE STATUS=:1

I run executionplan for both of them, and find that second one is using index, and first one is not.

How can I get timing for select?

Thanks
Tom Kyte
January 31, 2007 - 12:21 pm UTC

run the select of course.

never never NEVER use select count(*) in place of "select columns from t" - it doesn't even begin to make sense!!!

the number of logical IO's will be radically different in most cases (meaning the cpu time will be radically decreased for the count(*) over the select columns)

the plan will likely change - as we don't need to go to the table to get the columns - so we might just use an index instead of index PLUS table, or change from using a table to using an index (as you observed)

the number of rows returned are obviously different - and that is part of your runtime too.


sql_trace=true and tkprof the trace file.

or, in sqlplus, set autotrace traceonly - run the query. sqlplus will fetch but not print the data and show you other interesting statistics about the execution of the query

count(*)

Branka, January 31, 2007 - 1:44 pm UTC

Great explanation. Thanks

SQL behaves differently when run from Toad vs from a batch program

PMKR, February 05, 2007 - 4:00 pm UTC

Hello Tom,

This is my first post in here. I need some help in tuning the following query :

SELECT apih.lbl_header_id,
apid.lbl_detail_id,
apih.job_id,
apid.geo_packet_id,
max(aced.ship_date) ship_date
FROM adcust_gl_postage_intf_hdr apih ,
adcust_gl_postage_intf_dtl apid ,
( SELECT job_id ,
geo_packet_id ,
MAX(ship_date) ship_date
FROM adcust_ope_client_event_details
WHERE process_status <> 'D'
GROUP BY job_id ,
geo_packet_id ) aced
WHERE apih.processed_ind IN ('N','E','Y')
AND apih.shared_solo_ind = decode(:p_type,'S','R','P','M','F','M','A',apih.shared_solo_ind )
AND apih.run_code = DECODE(:p_type,'S','F','P','P','F','F','A',apih.run_code)
AND apih.run_code IN ('P','F')
AND (apid.ship_date IS NULL OR
nvl(apid.ship_date,sysdate) <> aced.ship_date )
AND aced.ship_date IS NOT NULL
AND apih.job_id = aced.job_id
AND apid.geo_packet_id = aced.geo_packet_id
AND apih.lbl_header_id = apid.lbl_header_id
GROUP BY apih.lbl_header_id,
apid.lbl_detail_id,
apih.job_id,
apid.geo_packet_id
/

One of our developers says that, when this is run from TOAD after commenting out the parameter usage in the where clause, it completes in a few minutes. But when it's run in a batch program with that parameter usage, it runs for hours. I did a trace of that batch session after it was running for 2 hours and found that, the trace file contained only waiting on "db file sequential read" event and didn't move ahead.

Here're the statistics :

Table- Indexes :
----------------

TABLE_NAME INDEX_NAME COLUMN_NAME
------------------------------ ------------------------------ ----------------------------
ADCUST_GL_POSTAGE_INTF_DTL ADCUST_GL_POSTAGE_INTF_DTL_D1 LBL_HEADER_ID
ADCUST_GL_POSTAGE_INTF_DTL_U1 LBL_DETAIL_ID
ADCUST_GL_POSTAGE_INTF_HDR ADCUST_GL_POSTAGE_INTF_HDR_D1 LBL_HEADER_ID
PROCESSED_IND
FOREIGN_PERMIT
POSTAL_CLASS
SHARED_SOLO_IND
RUN_CODE
ADCUST_GL_POSTAGE_INTF_HDR_U1 LBL_HEADER_ID
ADCUST_OPE_CLIENT_EVENT_DETAILS ACED_AGP_FK GEO_PACKET_ID
ACED_AIGD_FK AIGD_ID
ACED_PK CLIENT_EVENT_DETAIL_ID
ACED_RCTA_FK CUSTOMER_TRX_ID
ACED_RCTLA_FK CUSTOMER_TRX_LINE_ID
ADCUST_OPE_CED_IDX1 JOB_ID
PROFILE_GEOGRAPHY_ID
PROCESS_STATUS
ADCUST_OPE_CLIENT_EVENT_DTLS_B1 COMPONENT_TYPE
PROCESS_STATUS
SMF_STATUS
ADCUST_OPE_CLIENT_EVENT_DTLS_C1 CSI_ITEM_INSTANCE_ID
JOB_ID
AIGD_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N1 PROFILE_GEOGRAPHY_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N10 IN_HOME_DATE
ADCUST_OPE_CLIENT_EVENT_DTLS_N2 JOB_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N3 CUSTOMER_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N4 CSI_ITEM_INSTANCE_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N5 INVENTORY_ITEM_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N6 FINAL_INVOICE_SALES_ORDER_ID
ADCUST_OPE_CLIENT_EVENT_DTLS_N7 JOB_ID
WRAP_COMPOSITE_ID
COMPONENT_TYPE
SMF_STATUS
ADCUST_OPE_CLIENT_EVENT_DTLS_N8 JOB_ID
COMPONENT_TYPE
ADCUST_OPE_CLIENT_EVENT_DTLS_N9 FINAL_INVOICE_GROUPING_NUM


Row counts :
------------
adcust_ope_client_event_details -- 18,988,576
adcust_gl_postage_intf_dtl -- 27,360,561
adcust_gl_postage_intf_hdr -- 61,733

Plan table output with the parameters :
---------------------------------------

PLAN_TABLE_OUTPUT
-----------------

-----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost |
-----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 8 | 480 | | 150K|
| 1 | SORT GROUP BY | | 8 | 480 | | 150K|
|* 2 | HASH JOIN | | 8 | 480 | 6624K| 150K|
| 3 | TABLE ACCESS BY INDEX ROWID| ADCUST_GL_POSTAGE_INTF_DTL | 551 | 13224 | | 57 |
| 4 | NESTED LOOPS | | 130K| 5094K| | 13729 |
|* 5 | TABLE ACCESS FULL | ADCUST_GL_POSTAGE_INTF_HDR | 237 | 3792 | | 220 |
|* 6 | INDEX RANGE SCAN | ADCUST_GL_POSTAGE_INTF_DTL_D1 | 551 | | | 7 |
| 7 | VIEW | | 8182K| 156M| | 129K|
| 8 | SORT GROUP BY | | 8182K| 163M| 565M| 129K|
|* 9 | TABLE ACCESS FULL | ADCUST_OPE_CLIENT_EVENT_DETAILS | 8182K| 163M| | 93182 |
-----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("APIH"."JOB_ID"="ACED"."JOB_ID" AND "APID"."GEO_PACKET_ID"="ACED"."GEO_PACKET_ID")
filter("APID"."SHIP_DATE" IS NULL OR "ACED"."SHIP_DATE"<>NVL("APID"."SHIP_DATE",SYSDATE@!))
5 - filter(("APIH"."PROCESSED_IND"='E' OR "APIH"."PROCESSED_IND"='N' OR "APIH"."PROCESSED_IND"='Y')
AND "APIH"."SHARED_SOLO_IND"=DECODE(:Z,'S','R','P','M','F','M','A',"APIH"."SHARED_SOLO_IND") AND
"APIH"."RUN_CODE"=DECODE(:Z,'S','F','P','P','F','F','A',"APIH"."RUN_CODE") AND ("APIH"."RUN_CODE"='F'
OR "APIH"."RUN_CODE"='P') AND (DECODE(:Z,'S','F','P','P','F','F','A',"APIH"."RUN_CODE")='P' OR
DECODE(:Z,'S','F','P','P','F','F','A',"APIH"."RUN_CODE")='F'))
6 - access("APIH"."LBL_HEADER_ID"="APID"."LBL_HEADER_ID")
9 - filter("ADCUST_OPE_CLIENT_EVENT_DETAILS"."SHIP_DATE" IS NOT NULL AND
"ADCUST_OPE_CLIENT_EVENT_DETAILS"."PROCESS_STATUS"<>'D')

Note: cpu costing is off


*****
*****

Plan table output without the parameters :
------------------------------------------

"
....
....
WHERE apih.processed_ind IN ('N','E','Y')
-- AND apih.shared_solo_ind = decode(:p_type,'S','R','P','M','F','M','A',apih.shared_solo_ind )
-- AND apih.run_code = DECODE(:p_type,'S','F','P','P','F','F','A',apih.run_code)
AND apih.run_code IN ('P','F')
....
....
"

-----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost |
-----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1550 | 89900 | | 198K|
| 1 | SORT GROUP BY | | 1550 | 89900 | | 198K|
|* 2 | HASH JOIN | | 1550 | 89900 | | 198K|
|* 3 | TABLE ACCESS FULL | ADCUST_GL_POSTAGE_INTF_HDR | 47558 | 650K| | 220 |
| 4 | MERGE JOIN | | 40M| 1690M| | 165K|
| 5 | TABLE ACCESS BY INDEX ROWID| ADCUST_GL_POSTAGE_INTF_DTL | 27M| 625M| | 826 |
| 6 | INDEX FULL SCAN | ADCUST_GL_POSTAGE_INTF_DTL_D2 | 27M| | | 26 |
|* 7 | FILTER | | | | | |
|* 8 | SORT JOIN | | | | | |
| 9 | VIEW | | 8182K| 156M| | 129K|
| 10 | SORT GROUP BY | | 8182K| 163M| 565M| 129K|
|* 11 | TABLE ACCESS FULL | ADCUST_OPE_CLIENT_EVENT_DETAILS | 8182K| 163M| | 93182 |
-----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("APIH"."LBL_HEADER_ID"="APID"."LBL_HEADER_ID" AND "APIH"."JOB_ID"="ACED"."JOB_ID")
3 - filter(("APIH"."PROCESSED_IND"='E' OR "APIH"."PROCESSED_IND"='N' OR "APIH"."PROCESSED_IND"='Y')
AND ("APIH"."RUN_CODE"='F' OR "APIH"."RUN_CODE"='P'))
7 - filter("APID"."SHIP_DATE" IS NULL OR "ACED"."SHIP_DATE"<>NVL("APID"."SHIP_DATE",SYSDATE@!))
8 - access("APID"."GEO_PACKET_ID"="ACED"."GEO_PACKET_ID")
filter("APID"."GEO_PACKET_ID"="ACED"."GEO_PACKET_ID")
11 - filter("ADCUST_OPE_CLIENT_EVENT_DETAILS"."SHIP_DATE" IS NOT NULL AND
"ADCUST_OPE_CLIENT_EVENT_DETAILS"."PROCESS_STATUS"<>'D')

Note: cpu costing is off

************************

Is there any other way to re-write this to improve the performance ?

Thanks and regards
PMKR
Tom Kyte
February 05, 2007 - 6:32 pm UTC

tell them to go to the last page of the results in toad.

after a couple of hours, they might get there.

toad gets a page and stops. this is not toad running it faster.

santosh, February 07, 2007 - 4:20 am UTC

hi tom,tuning tips were good. i have a problem i have set of update statements where like condition is used frequently for same column name can is there any way i can gruop those like statements
my statements looks like this,
update nidapps.custworkorders set kvh_prod_type='1.5M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '1.5M%');
commit;
update nidapps.custworkorders set kvh_prod_type='1.5M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '64K%');
commit;
update nidapps.custworkorders set kvh_prod_type='1.5M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '128K%');
commit;
update nidapps.custworkorders set kvh_prod_type='1G' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '1000BaseLX%');
commit;
update nidapps.custworkorders set kvh_prod_type='2G' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '1000BaseSX%');
commit;
update nidapps.custworkorders set kvh_prod_type='100M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '100BaseFX%');
commit;
update nidapps.custworkorders set kvh_prod_type='100M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '100BaseTX%');
commit;
update nidapps.custworkorders set kvh_prod_type='100M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '100Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='10M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '10Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='10G' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '1000BaseSX%');
commit;
update nidapps.custworkorders set kvh_prod_type='10M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '1000BaseSX%');
commit;
update nidapps.custworkorders set kvh_prod_type='1G' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '1Gbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='2.4G' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '2.4Gbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='20M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '20Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='2M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '2Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='30M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '30Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='40M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '40Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='4M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '4Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='50M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '50Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='5M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '5Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='622M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '622Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='7M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '7Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='8M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '8Mbps%');
commit;
update nidapps.custworkorders set kvh_prod_type='45M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '%45M%');
commit;
update nidapps.custworkorders set kvh_prod_type='155M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '%155M%');
commit;
update nidapps.custworkorders set kvh_prod_type='10M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '%10BaseT%');
commit;
update nidapps.custworkorders set kvh_prod_type='10M' where swo_id in ( select swo_id from siebeldata_mv@siebelcust where x_kvh01_bandwidth like '%10M%');
commit;
regards
santosh
Tom Kyte
February 07, 2007 - 6:40 pm UTC

update (select a.kvh_prod_type, s.x_kvh01_bandwidth
from custworkorders a, s_mv@s s
where s.swo_id = a.swo_id
and ( a.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..."
or s.x_kvh01_bandwidth like '..." ........
)
set kvh_prod_type = case when x_kvh01_bandwidth like '...' then '...'
when x_kvh01_bandwidth like '...' then '...'
.....
end


design to perform better

Subbu, February 11, 2007 - 8:36 am UTC

Dear Tom,

The current table design is as follows:
We have table X, Y and Z. Table X contains 7 columns namely a, b, c, d, e, f, g. Table Y contains columns a and b of Table X. Table Z contains columns "a" of Table X and another new column "h". The transaction needs to insert in all the columns of all these tables.

Like to know which would be the best design practice from performance perspective for different query and insert/update scenarios.


Keep only table X adding only the new column h of table Z thereby remove redundancy of columns in other tables and avoid multiple insert statements in the code or continue with the existing design.

Pl. suggest.

Regards,
Subbu


Tom Kyte
February 12, 2007 - 10:24 am UTC

you are missing the most important facts here - relationship.

if the relationship between X,Y,Z is one to one then there should not be more than one table.

the purpose of Y in any case is beyond me. It seems utterly redundant.

And if X.A is not the primary key, then the relation between X and Z is not one to one but rather Z is the parent table and X is a child table and you would use the appropriate primary/foreign keys.

If X.A is the primary key of X, then you have a one to one relation between Z and X and there should just be one table.

This is awesome

Gaurav, February 14, 2007 - 9:45 am UTC

Well gone through the article this is awesome yet to go through the links here.

Dear Tom - Here is one query where i am facing issue with its performance
SELECT

CLIENT.ENT_ID "Client ID",

CLIENT.NAME "CLIENT",

-- FOLDER.ENT_ID "Folder ID",

-- FOLDER.NAME "FOLDER",

FOLDER_CB.ALL_CAP_CHARGE_TO_CODE "Folder BDC"

FROM CED.CORE_ENTITY CLIENT,

-- CED.CORE_ENTITY FOLDER,

DAC_CLIENTBOOK FOLDER_CB

WHERE

FN_GET_FOLDER_LEVEL(CLIENT.ENT_ID) IS NOT NULL AND

FN_GET_FOLDER_LEVEL(CLIENT.ENT_ID) <> CLIENT.ENT_ID AND -- FOLDER IS NOT THE CLIENT ITSELF

FN_GET_FOLDER_LEVEL(CLIENT.ENT_ID) = FOLDER_CB.CLIENT_ID(+)

Function FN_GET_FOLDER_LEVEL() is as :-

create or replace function ced.fn_get_folder_level (p_Ent_Id IN number,
p_Org_Id IN number default 7,
p_Entlinkty_Code IN varchar2 default 'SUB') return number is

cursor c1 is
select b.ent_id folder_ent_id
from client b,
core_entity a,
(select ent_id
from entity_hierarchy
start with ent_id = p_Ent_Id
and entlinkty_code = p_Entlinkty_Code
connect by ent_id = prior ent_id_par
and entlinkty_code = p_Entlinkty_Code) c
where c.ent_id = a.ent_id
and a.ent_id = b.ent_id (+)
and b.org_id(+) = p_Org_Id;

begin
for v1 in c1 loop

if v1.folder_ent_id is NOT NULL THEN
return v1.folder_ent_id;
end if;

end loop;

-- entity not found within a folder
return null;
end;

I am new to query Optimization, as per me using the function in the query is supressing the indexes to be used

Is there any other way to write this query without using this function,though i have tried but can not achive the perfect one .




Tom Kyte
February 14, 2007 - 2:24 pm UTC

this is not query optimization, this is a physical schema that is quite simply not designed to answer your questions.

that is a scary function - I don't get the logic - it seems to return the first random folder_ent_id - meaning, given the same inputs it could return a different answer against the same data!!!!! there is no order by on the query - I don't get it.

Why DBMS_ADVISOR recommends just 2 columns in index instead of 4 and result is the same?

Michael, February 17, 2007 - 9:52 pm UTC

I tried to use your simulation from

http://asktom.oracle.com/pls/asktom/f?p=100:11:285023949467302::::P11_QUESTION_ID:6601251003901

to understand how index works:

create table ps_sal_grade_tbl ( setid int, sal_admin_plan int, grade int, effdt date );
create table ps_job ( setid_salary int, sal_admin_plan int, grade int, effdt date );

insert /*+ APPEND */ into ps_job
select rownum, rownum, rownum, created
from all_objects
union all
select -rownum, -rownum, -rownum, created
from all_objects
/
commit;

78068 rows created.

Commit complete.

insert /*+ APPEND */ into ps_sal_grade_tbl
select setid_salary, sal_admin_plan, grade, effdt-r
from (select ps_job.*, rownum r from ps_job )
where mod(r,26) = 0;
commit;

Commit complete.

3002 rows created.

Then I ran your query to measure total time:

SET AUTOTRACE TRACEONLY
variable date2 VARCHAR2(255);
EXECUTE :date2 := to_char(sysdate, 'MM.DD.YYYY:HH24:MI:SS');
select to_char(to_date(:date2, 'MM.DD.YYYY:HH24:MI:SS'), 'MM.DD.YYYY:HH24:MI:SS') from dual;
SET SERVEROUTPUT ON SIZE 1000000
SET TIME ON
SET TIMING ON
DECLARE
v_sal_grade_cnt INT ;
BEGIN
FOR ps_job_rec IN (SELECT *
FROM ps_job) LOOP
BEGIN

SELECT COUNT(*)
INTO v_sal_grade_cnt
FROM ps_sal_grade_tbl a
WHERE setid = ps_job_rec.setid_salary
AND sal_admin_plan = ps_job_rec.sal_admin_plan
AND grade = ps_job_rec.grade
AND effdt = (SELECT MAX(effdt)
FROM ps_sal_grade_tbl
WHERE setid = a.setid
AND sal_admin_plan = a.sal_admin_plan
AND grade = a.grade
AND effdt <= ps_job_rec.effdt) ;
END ;

END LOOP;

END;
/
SET AUTOTRACE OFF
select (sysdate - to_date(:date2, 'MM.DD.YYYY:HH24:MI:SS')) * 24 * 60 * 60 from dual;

(SYSDATE-TO_DATE(:DATE2,'MM.DD.YYYY:HH24:MI:SS'))*24*60*60
----------------------------------------------------------
66

1 row selected.

and now repeat the same with index

create index ps_idx1 on ps_sal_grade_tbl(setid, sal_admin_plan, grade, effdt);
analyze table ps_sal_grade_tbl compute statistics
for table for all indexes for all indexed columns;


(SYSDATE-TO_DATE(:DATE2,'MM.DD.YYYY:HH24:MI:SS'))*24*60*60
----------------------------------------------------------
21

1 row selected.

Really 3 times faster!

Now

drop index ps_idx1;

and from TKPROF:

SELECT COUNT(*)
FROM
PS_SAL_GRADE_TBL A WHERE SETID = :B3 AND SAL_ADMIN_PLAN = :B2 AND GRADE =
:B1 AND EFFDT = (SELECT MAX(EFFDT) FROM PS_SAL_GRADE_TBL WHERE SETID =
A.SETID AND SAL_ADMIN_PLAN = A.SAL_ADMIN_PLAN AND GRADE = A.GRADE AND EFFDT
<= :B4 )

DECLARE
task_name VARCHAR2(30);
BEGIN
task_name := 'MYTASK10';

DBMS_ADVISOR.QUICK_TUNE(DBMS_ADVISOR.SQLACCESS_ADVISOR, task_name,
'SELECT COUNT(*)
FROM
PS_SAL_GRADE_TBL A WHERE SETID = :B3 AND SAL_ADMIN_PLAN = :B2 AND GRADE =
:B1 AND EFFDT = (SELECT MAX(EFFDT) FROM PS_SAL_GRADE_TBL WHERE SETID =
A.SETID AND SAL_ADMIN_PLAN = A.SAL_ADMIN_PLAN AND GRADE = A.GRADE AND EFFDT
<= :B4 )');
END;
/

VARIABLE workload_name VARCHAR2(255);
VARIABLE task_name VARCHAR2(255);
EXECUTE :task_name := 'MYTASK10';
EXECUTE :workload_name := 'MYWORKLOAD10';

SELECT REC_ID, RANK, BENEFIT
FROM USER_ADVISOR_RECOMMENDATIONS WHERE TASK_NAME = :task_name;

REC_ID RANK BENEFIT
---------- ---------- ----------
1 1 6

1 row selected.

SELECT 'Action Count', COUNT(DISTINCT action_id) cnt
FROM user_advisor_actions WHERE task_name = :task_name;

'ACTIONCOUNT' CNT
------------------------------------ ----------
Action Count 1

1 row selected.

SELECT rec_id, action_id, SUBSTR(command,1,30) AS command
FROM user_advisor_actions WHERE task_name = :task_name
ORDER BY rec_id, action_id;

REC_ID ACTION_ID COMMAND
---------- ---------- ------------------------------------------------------------------------------------------
1 1 CREATE INDEX

1 row selected.

set serveroutput on size 99999
EXECUTE show_recm(:task_name);

=========================================
Task_name = MYTASK10
Action ID: 1
Command : CREATE INDEX
Attr1 (name) : "SCOTT"."PS_SAL_GRADE_TB_IDX$$
Attr2 (tablespace):
Attr3 : "SCOTT"."PS_SAL_GRADE_TBL"
Attr4 : BTREE
Attr5 :
----------------------------------------
=========END RECOMMENDATIONS============

PL/SQL procedure successfully completed.

CREATE DIRECTORY ADVISOR_RESULTS10 AS 'C:\ORACLE_indexing\yuckscript';
GRANT READ ON DIRECTORY ADVISOR_RESULTS10 TO PUBLIC;
GRANT WRITE ON DIRECTORY ADVISOR_RESULTS10 TO PUBLIC;

EXECUTE DBMS_ADVISOR.CREATE_FILE(DBMS_ADVISOR.GET_TASK_SCRIPT('MYTASK10'), 'ADVISOR_RESULTS10', 'advscript10.sql');

from script advscript10.sql:

CREATE INDEX "SCOTT"."PS_SAL_GRADE_TB_IDX$$_01240001"
ON "SCOTT"."PS_SAL_GRADE_TBL"
("SETID","SAL_ADMIN_PLAN")
COMPUTE STATISTICS;

I e DBMS_ADVISOR recommends to create index but only using TWO columns of table PS_SAL_GRADE_TBL

CREATE INDEX "SCOTT"."PS_SAL_GRADE_TB_IDX$$_01240001"
ON "SCOTT"."PS_SAL_GRADE_TBL"
("SETID","SAL_ADMIN_PLAN")
COMPUTE STATISTICS;

analyze table ps_sal_grade_tbl compute statistics
for table for all indexes for all indexed columns;

SET AUTOTRACE TRACEONLY
variable date2 VARCHAR2(255);
EXECUTE :date2 := to_char(sysdate, 'MM.DD.YYYY:HH24:MI:SS');
select to_char(to_date(:date2, 'MM.DD.YYYY:HH24:MI:SS'), 'MM.DD.YYYY:HH24:MI:SS') from dual;
SET SERVEROUTPUT ON SIZE 1000000
SET TIME ON
SET TIMING ON
DECLARE
v_sal_grade_cnt INT ;
BEGIN
FOR ps_job_rec IN (SELECT *
FROM ps_job) LOOP
BEGIN

SELECT COUNT(*)
INTO v_sal_grade_cnt
FROM ps_sal_grade_tbl a
WHERE setid = ps_job_rec.setid_salary
AND sal_admin_plan = ps_job_rec.sal_admin_plan
AND grade = ps_job_rec.grade
AND effdt = (SELECT MAX(effdt)
FROM ps_sal_grade_tbl
WHERE setid = a.setid
AND sal_admin_plan = a.sal_admin_plan
AND grade = a.grade
AND effdt <= ps_job_rec.effdt) ;
END ;

END LOOP;

END;
/
SET AUTOTRACE OFF
select (sysdate - to_date(:date2, 'MM.DD.YYYY:HH24:MI:SS')) * 24 * 60 * 60 from dual;

(SYSDATE-TO_DATE(:DATE2,'MM.DD.YYYY:HH24:MI:SS'))*24*60*60
----------------------------------------------------------
20

1 row selected.

and now without index:

drop INDEX PS_SAL_GRADE_TB_IDX$$_01240001

(SYSDATE-TO_DATE(:DATE2,'MM.DD.YYYY:HH24:MI:SS'))*24*60*60
----------------------------------------------------------
71

Again with index 3 times faster than without index

But why DBMS_ADVISOR recommends just 2 columns in index and result is the same?

Thanks,

Michael


Is select * evil?

Shivdeep Modi, March 01, 2007 - 9:45 am UTC

Hi Tom,
I recently came across an article
PERFORMANCE OF IN LISTS | Rudy Limeback

I have a query where I dynamically generate the 'in' list. This can grow to several hundreds in some cases. The query just takes too long to execute, and I am trying to improve performance. What is the bestway to do this?

http://go.techtarget.com/r/1059374/5768760

In the link we'got :
Secondly, the dreaded, evil "select star" is bad. List only the columns you need (even if you need them all, I always say).

Apart from the rest of the contents, how true is this?

I tried:
/NCLDBA/NV02 > select count(*) from t;

COUNT(*)
----------
30870

/NCLDBA/NV02 >

I did a select * from t and then all select with all the columns. But the tkprof did not tell me any difference.

================================================================================
select *
from
t


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2059 0.26 0.27 393 2455 0 30870
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2061 0.26 0.27 393 2455 0 30870

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 47

Rows Row Source Operation
------- ---------------------------------------------------
30870 TABLE ACCESS FULL T
================================================================================

select OWNER,
OBJECT_NAME,
SUBOBJECT_NAME,
OBJECT_ID,
DATA_OBJECT_ID,
OBJECT_TYPE,
CREATED,
LAST_DDL_TIME,
TIMESTAMP,
STATUS,
TEMPORARY,
GENERATED,
SECONDARY
from t

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2059 0.27 0.28 393 2455 0 30870
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2061 0.27 0.28 393 2455 0 30870

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 47

Rows Row Source Operation
------- ---------------------------------------------------
30870 TABLE ACCESS FULL T

How true is the assertion? Personally I feel there should be any difference between the two. * is a wild card. It should be expanded to all the columns internally.

Regards,
Shivdeep Modi
Tom Kyte
March 02, 2007 - 11:41 am UTC

are you really trying to compare:

select count(*)

to

select *


if you are - you have a rather fundamental misunderstanding of what these things do.


select count(*) - this counts the number of records.
select * - this fetches all columns from all records.


select * is generally consider a really bad practice as it implicitly expands the list of all columns - and if someone adds or drops or reorders the columns - your code is HOSED. Explicitly listing just the columns you want is a good practice.

Is select * evil?

Shivdeep Modi, March 02, 2007 - 12:26 pm UTC

Hi,

I was trying to compare select * VS select col1, col2, ...

It did'nt occur to me that it is a matter of maintainability.

Thanks
Tom Kyte
March 04, 2007 - 6:18 pm UTC

it is a matter of performance too.

If you don't need all of the columns (the most common case - you typically do not), select * will be incredibly less performant in many cases.

subquery

A reader, March 02, 2007 - 6:41 pm UTC

I have aquery like

select d.detail_id,l.line_id from details d,lines l

where
d.account_id=l.account_id
and l.line_id=( select max(l2.line_id ) from lines l2 where l2.line_id=l.line_id and effective_date< sysdate )

the subquery goes for FTS on lines table which is very big table although there is index on line_id which is Primary key

How can I REWRITE the query to make use of index.


Tom Kyte
March 04, 2007 - 6:44 pm UTC

let us see the plan and comment on why the optimizer did the right thing here, so we can explain why indexes are not all good and full scans are not all evil.

Please confirm

Friend, March 12, 2007 - 8:35 am UTC

Tom,
Is "SYS_B_0" because CURSOR_SHARING is set to FORCE? Please confirm. Below is the example.

SQL> select c1 from T318 where rownum < 3;

C1
---------------
000000000000001
000000000000002

SQL> select sql_text , version_count
2 from v$sqlarea
3 where sql_text like 'select c1 from T318 where rownum%';

SQL_TEXT
-------------------------------------------------------------------------
VERSION_COUNT
-------------
select c1 from T318 where rownum < :"SYS_B_0"
1


SQL> select c1 from T318 where rownum < 2;

C1
---------------
000000000000001

SQL> select sql_text , version_count
2 from v$sqlarea
3 where sql_text like 'select c1 from T318 where rownum%';

SQL_TEXT
-------------------------------------------------------------------------
VERSION_COUNT
-------------
select c1 from T318 where rownum < :"SYS_B_0"
1

Tom Kyte
March 12, 2007 - 9:06 pm UTC

no, it is because cursor sharing is set to similar.

or force

or because (unlikely) a programmer used "SYS_B_0"

it typically indicates cursor sharing = force or similar was set however.

Unwanted predicates

Reader, March 21, 2007 - 10:55 am UTC

Tom,

This a query which has unwanted predicates.

SELECT Orders.C1,C655630312,C4,C536870920
FROM Orders
WHERE
(
(
(
(
0 = 1
AND Orders.C655630000 > 0
AND Orders.C600000138 IS NULL
AND Orders.C600000010 IS NULL
AND (Orders.C655500119 IS NULL OR Orders.C655500119 > 0)
AND Orders.C7 != 4
AND Orders.C7 != 1
AND (Orders.C655620007 = 4 OR Orders.C655620007 = 1)
)
OR
(
0 != 0
AND Orders.C655630000 > 0
AND Orders.C600000010 IS NULL
AND 0 != 0
AND (Orders.C655500119 IS NULL OR Orders.C655500119 > 0)
)
)
OR
(
0 = 0
AND Orders.C655630000 > 0
AND Orders.C1 = 'BOM000000931263'
AND Orders.C7 != 1
AND (Orders.C655620007 = 4 OR Orders.C655620007 = 1)
)
)
OR
(
0 = 2
AND Orders.C655630000 > 0
AND (Orders.C655632466 = ' ' OR Orders.C4 = ' ')
AND Orders.C7 != 1
AND (Orders.C655620007 = 4 OR Orders.C655620007 = 1)
)
)

Of this only the condition below will be validated.
0 = 0
AND Orders.C655630000 > 0
AND Orders.C1 = 'BOM000000931263'
AND Orders.C7 != 1
AND (Orders.C655620007 = 4 OR Orders.C655620007 = 1)

Because of the unwanted condition in the WHERE clause Iam observing the query takes lot of time. Though I could not justify my own analysis, can you tell me is my analysis true?



Tunning

Christian, March 28, 2007 - 11:24 am UTC

HI TOM.
im having some problems to tunning a querry, maybe u can help me.


SELECT cmp.cmp_numero_interno, substr(cmp.tcm_codigo||varios.numero_con_formato_abcx(cmp.tcm_codigo,cmp.cmp_numero),1,200) factura,
cln.cln_razon_social||'('|| cln.cln_denominacion_comercial||')' cliente,
agf.agf_descripcion || '-' ||
prv.prv_descripcion || '-' ||
decode(dom.dom_codigo_postal,null,'','CP:'||dom.dom_codigo_postal) || '-' ||
dom.dom_calle || ' ' ||
dom.dom_nro || ' ' ||
decode(dom.dom_piso,null, '','Piso:'||dom.dom_piso) Lugar_Entrega,
0 comprobantes
FROM grupos_procedimientos gcm,
tipos_comprobantes tcm,
comprobantes cmp,
clientes cln,
domicilios dom,
departamentos dep,
areas_geograficas agf,
provincias prv
WHERE gcm.gpc_orden = (SELECT gpc_orden + 1
FROM grupos_procedimientos gcm1
WHERE gcm1.prn_codigo = cmp.prn_codigo
AND gcm1.gcm_codigo = 'OC')
AND cmp.cln_numero = cln.cln_numero
AND agf.agf_codigo = dom.agf_codigo
AND dep.dep_codigo = agf.dep_codigo
AND prv.prv_codigo = dep.prv_codigo
AND cmp.dom_numero = dom.dom_numero
AND cmp.tcm_codigo = tcm.tcm_codigo
AND cmp.prn_codigo = gcm.prn_codigo
AND gcm.gcm_codigo = tcm.gcm_codigo
AND cmp.dom_numero = dom.dom_numero

AND not exists (SELECT 1
FROM comprobantes_hojas_ruta chr
WHERE nvl(chr.chr_entrego, 'N') = 'S'
AND chr.cmp_numero_interno = cmp.cmp_numero_interno)
AND nvl(cmp.dom_numero, 0) <> 1
AND cmp.cmp_estado = 'D'








SELECT STATEMENT, GOAL = CHOOSE Cost=165 Cardinality=1 Bytes=162
FILTER
NESTED LOOPS Cost=165 Cardinality=1 Bytes=162
NESTED LOOPS Cost=164 Cardinality=1 Bytes=149
NESTED LOOPS Cost=163 Cardinality=1 Bytes=142
NESTED LOOPS Cost=162 Cardinality=1 Bytes=122
HASH JOIN Cost=161 Cardinality=1 Bytes=115
HASH JOIN Cost=147 Cardinality=1194 Bytes=88356
NESTED LOOPS Cost=133 Cardinality=1378 Bytes=52364
TABLE ACCESS FULL Object Object name=GRUPOS_PROCEDIMIENTOS Cost=1 Cardinality=66 Bytes=594
TABLE ACCESS BY INDEX ROWID Object Object name=COMPROBANTES Cost=2 Cardinality=4111 Bytes=119219
INDEX RANGE SCAN Object Object name=CMP_PRN_FK_I Cost=1 Cardinality=4111
TABLE ACCESS BY INDEX ROWID Object Object name=GRUPOS_PROCEDIMIENTOS Cost=1 Cardinality=1 Bytes=9
INDEX UNIQUE SCAN Object Object name=GPC_PK Cardinality=1
TABLE ACCESS FULL Object Object name=CLIENTES Cost=13 Cardinality=3657 Bytes=131652
TABLE ACCESS FULL Object Object name=DOMICILIOS Cost=13 Cardinality=10470 Bytes=429270
TABLE ACCESS BY INDEX ROWID Object Object name=TIPOS_COMPROBANTES Cost=1 Cardinality=58 Bytes=406
INDEX UNIQUE SCAN Object Object name=TCM_PK Cardinality=58
TABLE ACCESS BY INDEX ROWID Object Object name=AREAS_GEOGRAFICAS Cost=1 Cardinality=953 Bytes=19060
INDEX UNIQUE SCAN Object Object name=AGF_PK Cardinality=953
TABLE ACCESS BY INDEX ROWID Object Object name=DEPARTAMENTOS Cost=1 Cardinality=25 Bytes=175
INDEX UNIQUE SCAN Object Object name=DEP_PK Cardinality=25
TABLE ACCESS BY INDEX ROWID Object Object name=PROVINCIAS Cost=1 Cardinality=25 Bytes=325
INDEX UNIQUE SCAN Object Object name=PRV_PK Cardinality=25
TABLE ACCESS BY INDEX ROWID Object Object name=COMPROBANTES_HOJAS_RUTA Cost=2 Cardinality=1 Bytes=7
INDEX RANGE SCAN Object Object name=CMP_NUM_INT_I Cost=1 Cardinality=1

plan steps

abz, April 12, 2007 - 8:00 am UTC

Suppose there is a large query, with UNION ALL etc,
a table t1 is use two or three times in this query,
the explain plan shows the T1 table 3 times in 3 different
steps, two of them FULL SCAN it and one of them INDEX SCAN it.

The query is running and we know that it will complete
in 2 hours. How can we see that at which step of the
explain plan is oracle right now?

Tom Kyte
April 13, 2007 - 12:01 pm UTC

you cannot really, it doesn't work that way.

sql tuning

A reader, April 12, 2007 - 8:11 pm UTC

I have this query which shows cost of 2081 in explain plan
but takes more than 3 hours to run
I have to yune it so that it max takes 15 mins.

SELECT ca.customer_id
FROM customer_address ca, address cad
WHERE ca.address_id = cad.address_id
AND ca.effective_date = (SELECT max(a2.effective_date)
FROM customer_address a2
WHERE a2.customer_id = ca.customer_id)

I have tried everything from reorganizing the indexes to rewriting the query to sql_hints
couldn't find any solution

here is the xml explain plan

- <ExplainPlan>
- <PlanElement object_ID="0" id="0" operation="SELECT STATEMENT" optimizer="CHOOSE" cost="2,081" cardinality="1" bytes="28" io_cost="2,081">
- <PlanElements>
- <PlanElement object_ID="0" id="1" operation="FILTER">
- <PlanElements>
- <PlanElement object_ID="0" id="2" operation="NESTED LOOPS" cost="2,071" cardinality="1" bytes="28" io_cost="2,071">
- <PlanElements>
<PlanElement object_ID="1" id="3" operation="TABLE ACCESS" option="FULL" optimizer="ANALYZED" object_owner="COLL" object_name="CUSTOMER_ADDRESS" object_instance="1" cost="2,070" cardinality="1" bytes="22" io_cost="2,070" />
<PlanElement object_ID="2" id="4" operation="INDEX" option="UNIQUE SCAN" optimizer="ANALYZED" object_owner="COLL" object_name="PK_ADDRESS_01" object_type="UNIQUE" search_columns="1" cost="1" cardinality="1" bytes="6" io_cost="1" />
</PlanElements>
</PlanElement>
- <PlanElement object_ID="0" id="5" operation="SORT" option="AGGREGATE" cardinality="1" bytes="15">
- <PlanElements>
- <PlanElement object_ID="1" id="6" operation="TABLE ACCESS" option="BY INDEX ROWID" optimizer="ANALYZED" object_owner="COLL" object_name="CUSTOMER_ADDRESS" object_instance="3" cost="5" cardinality="2" bytes="30" io_cost="5">
- <PlanElements>
<PlanElement object_ID="3" id="7" operation="INDEX" option="RANGE SCAN" optimizer="ANALYZED" object_owner="COLL" object_name="CSTMR_CSTMR_ADDRSS_FK" object_type="NON-UNIQUE" search_columns="1" cost="3" cardinality="2" io_cost="3" />
</PlanElements>
</PlanElement>
</PlanElements>
</PlanElement>
</PlanElements>
</PlanElement>
</PlanElements>
</PlanElement>
</ExplainPlan>
Tom Kyte
April 13, 2007 - 12:57 pm UTC

man, if that is using an index - there is your problem!!!!!

is this the real query? why not just

select distinct customer_id from customer_address;

or at most:

select distinct customer_id from customer_address where address_id in (select address_id from address);


tuning required

Debasish Ghosh, April 19, 2007 - 1:35 pm UTC

The following statement insert huge data it works but take huge time approx 1 hour .

insert into global.gtemp_pdc_storage_retrieval
( proposal_no,agreement_no,
location_code,division_code,
agree_date,party_code,
cash_bank_code, cmp_code,
pdc_type_code,pdc_status_code,
bin_no, packet_no,
storage_user_id ,storage_date,
retrieval_type_code,retrieval_user_id,
retrieval_date ,cheque_no,
cheque_date,cheque_amount,
bank_name_code ,bank_branch_code )
select a.proposal_no ,a.agreement_no ,
a.location_code ,a.division_code,
a.agree_date,a.party_code,
b.cash_bank_code,b.cmp_code,
b.pdc_type_code ,b.pdc_status_code,
b.bin_no,b.packet_no,
b.storage_user_id,b.storage_date,
b.retrieval_type_code,b.retrieval_user_id,
b.retrieval_date,b.chq_no,
b.chq_date,b.chq_amount,
b.bank_name_code,b.bank_branch_code
from trans.tb_proposal_main a, trans.tb_proposal_pdc_detail b
where a.comp_code = b.comp_code
and a.proposal_no= b.proposal_no
and trunc(b.storage_date) between '01-apr-04' and '31-mar-07'
and b.bin_no is not null;

The costing nearly 16266 in trans.tb_proposal_pdc_detail table has 5 milion data and
trans.tb_proposal_main has 2 milion data

in execution plan

table tb_proposal_pdc_detail full scan
and index range scan on tb_proposal_main

a indexd is already is there on tb_proposal_pdc_detail (comp_code,proposal_no,storage_date,bin_no)

please suggest me how can i reduce the execution time.
Tom Kyte
April 19, 2007 - 1:55 pm UTC

add

and 1=0

to the predicate, it'll go much faster.

It is physically impossible to say another with more meaning.

Not sure that I'd want any indexes to be used. In fact, I can say if it is driving off of the detail table back to the main table by an index 5,000,000 times - that is likely 'not good'

sorry - there just isn't sufficient detail here to say anything.

Sql Tuning

Debasish, April 20, 2007 - 1:15 pm UTC

below I given the execution plan of the above statement. The TB_PROPOSAL_PDC_DETAIL TABLE USE ALMOST 200 CON-CURRENT USER( 5 million record is there), SO I THINK ROW LOCKING IS ONE OF THE CAUSE FOR TAKING INSERTION TIME. THERE IS A INDEX ON TB_PROPOSAL_PDC_DETAIL TABLE ON THOSE COLUMN, BUT INDEX NOT CONSIDER IN THE EXECUTION PLAN. PLEASE SUGGEST ME IN ADVANCE

INSERT STATEMENT (Cost = 16342 CARD 695 Bytes 111200)
FILTER CARD Bytes
NESTED LOOPS (CARD 695 Bytes 111200)
TABLE ACCESS FULL TB_PROPOSAL_PDC_DETAIL (CARD 695 Bytes 57685)
TABLE ACCESS BY INDEX ROWID TB_PROPOSAL_MAIN (CARD 1 Bytes 77)
INDEX UNIQUE SCAN PK_PROPOSAL_MAIN (CARD 1 Bytes)

Tom Kyte
April 20, 2007 - 1:53 pm UTC

WHY DO YOU THINK THAT.

WHY DO YOU NOT hit the capslock key and turn it off.


Tuning Required

A reader, April 20, 2007 - 10:01 pm UTC

The following statement insert huge data it works but take huge time approx 1 hour .

insert into global.gtemp_pdc_storage_retrieval
( proposal_no,agreement_no,
location_code,division_code,
agree_date,party_code,
cash_bank_code, cmp_code,
pdc_type_code,pdc_status_code,
bin_no, packet_no,
storage_user_id ,storage_date,
retrieval_type_code,retrieval_user_id,
retrieval_date ,cheque_no,
cheque_date,cheque_amount,
bank_name_code ,bank_branch_code )
select a.proposal_no ,a.agreement_no ,
a.location_code ,a.division_code,
a.agree_date,a.party_code,
b.cash_bank_code,b.cmp_code,
b.pdc_type_code ,b.pdc_status_code,
b.bin_no,b.packet_no,
b.storage_user_id,b.storage_date,
b.retrieval_type_code,b.retrieval_user_id,
b.retrieval_date,b.chq_no,
b.chq_date,b.chq_amount,
b.bank_name_code,b.bank_branch_code
from trans.tb_proposal_main a, trans.tb_proposal_pdc_detail b
where a.comp_code = b.comp_code
and a.proposal_no= b.proposal_no
and trunc(b.storage_date) between '01-apr-04' and '31-mar-07'
and b.bin_no is not null;

execution Plan

INSERT STATEMENT (Cost = 16342 CARD 695 Bytes 111200)
FILTER CARD Bytes
NESTED LOOPS (CARD 695 Bytes 111200)
TABLE ACCESS FULL TB_PROPOSAL_PDC_DETAIL (CARD 695 Bytes 57685)
TABLE ACCESS BY INDEX ROWID TB_PROPOSAL_MAIN (CARD 1 Bytes 77)
INDEX UNIQUE SCAN PK_PROPOSAL_MAIN (CARD 1 Bytes)

------------------
1. trans.tb_proposal_pdc_detail (approx 5 milion record)
2. trans.tb_proposal_main (approx 2 milion record)
3. almost 200 concurrent user access detail table (row locking may cause)
4. the query insert almosgt 1/2 milion record to temporary able
a indexd is already is there on tb_proposal_pdc_detail (comp_code,proposal_no,storage_date,bin_no)

please suggest me how can I reduce the execution time. can delay occur due to table row locking.

Tom Kyte
April 21, 2007 - 9:00 am UTC

add "and 1=0" to the where clause.

we've already discussed this above.

I'm pretty sure it should use NO INDEXES

but we here don't know what indexes you have, what the selectivity of your where clause might be, what columns are in the index being used, basically - nothing.


full table scan on union all view

ned, April 26, 2007 - 10:15 pm UTC

"Union All" view is not using the Index in 10.2.0.3 when limited with inline view, is this a bug? you can simulate the problem with this script.

create table t1 as select rownum col1, object_name col2 from dba_objects;
create table t2 as select rownum col1, object_name col2 from dba_objects where rownum <10000;
create table t3 as select rownum col1, rownum col3 from dba_objects where rownum <10000;

CREATE VIEW t_view
AS
SELECT *
FROM t1
UNION ALL
SELECT *
FROM t2;

create index t1_n1 on t1 (col1,col2);
create index t2_n1 on t2 (col1,col2);
create index t3_n1 on t3 (col1,col3);
create index t3_n2 on t3 (col3);

exec dbms_stats.gather_TABLE_STATS(OWNNAME=>'NED',TABNAME=>'T1');
exec dbms_stats.gather_TABLE_STATS(OWNNAME=>'NED',TABNAME=>'T3');
exec dbms_stats.gather_TABLE_STATS(OWNNAME=>'NED',TABNAME=>'T3');

SQL> explain plan for
2 SELECT v.*
3 FROM t_view v
4 WHERE (v.col1, v.col2) IN (
5 SELECT t1.col1, t1.col2
6 FROM t3,
7 t1
8 WHERE t3.col1 = t1.col1 AND t3.col3 = :b1);

SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
Plan hash value: 967674388

-------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 79 | 81 (3)| 00:00:01 |
|* 1 | FILTER | | | | | |
| 2 | VIEW | T_VIEW | 81179 | 6262K| 79 (3)| 00:00:01 |
| 3 | UNION-ALL | | | | | |
| 4 | TABLE ACCESS FULL| T1 | 71180 | 1876K| 69 (3)| 00:00:01 |
| 5 | TABLE ACCESS FULL| T2 | 9999 | 224K| 10 (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
| 6 | NESTED LOOPS | | 1 | 34 | 2 (0)| 00:00:01 |
|* 7 | INDEX RANGE SCAN | T1_N1 | 1 | 27 | 1 (0)| 00:00:01 |
|* 8 | INDEX RANGE SCAN | T3_N1 | 1 | 7 | 1 (0)| 00:00:01 |
-------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter( EXISTS (SELECT /*+ */ 0 FROM "T1" "T1","T3" "T3" WHERE
"T3"."COL3"=TO_NUMBER(:B1) AND "T3"."COL1"=:B1 AND
"T3"."COL1"="T1"."COL1" AND "T1"."COL2"=:B2 AND "T1"."COL1"=:B3))

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
7 - access("T1"."COL1"=:B1 AND "T1"."COL2"=:B2)
8 - access("T3"."COL1"=:B1 AND "T3"."COL3"=TO_NUMBER(:B1))
filter("T3"."COL1"="T1"."COL1")

Tom Kyte
April 27, 2007 - 10:41 am UTC

it did not want to do the subquery twice, using WITH subquery factoring - it was happy to push it:

ops$tkyte%ORA10GR2> with data as
  2  (
  3         SELECT t1.col1, t1.col2
  4           FROM t3,
  5             t1
  6         WHERE t3.col1 = t1.col1 AND t3.col3 = to_number(:b1)
  7  )
  8  SELECT v.*
  9   FROM t_view v
 10   WHERE (v.col1, v.col2) IN (select * from data)
 11  /

Execution Plan
----------------------------------------------------------
Plan hash value: 1231972518

------------------------------------------------------------------------
| Id  | Operation                       | Name     | Rows  | Bytes | Cos
------------------------------------------------------------------------
|   0 | SELECT STATEMENT                |          |     1 |   168 |
|   1 |  NESTED LOOPS                   |          |     1 |   168 |
|   2 |   VIEW                          | VW_NSO_1 |     1 |    79 |
|   3 |    HASH UNIQUE                  |          |     1 |    37 |
|   4 |     NESTED LOOPS                |          |     1 |    37 |
|   5 |      TABLE ACCESS BY INDEX ROWID| T3       |     1 |     7 |
|*  6 |       INDEX RANGE SCAN          | T3_N2    |     1 |       |
|*  7 |      INDEX RANGE SCAN           | T1_N1    |     1 |    30 |
|   8 |   VIEW                          | T_VIEW   |     1 |    89 |
|   9 |    UNION-ALL PARTITION          |          |       |       |
|  10 |     TABLE ACCESS BY INDEX ROWID | T1       |     1 |   110 |
|* 11 |      INDEX RANGE SCAN           | T1_N1    |     1 |       |
|  12 |     TABLE ACCESS BY INDEX ROWID | T2       |     1 |   121 |
|* 13 |      INDEX RANGE SCAN           | T2_N1    |     1 |       |
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   6 - access("T3"."COL3"=TO_NUMBER(:B1))
   7 - access("T3"."COL1"="T1"."COL1")
  11 - access("COL1"="COL1" AND "COL2"="COL2")
  13 - access("COL1"="COL1" AND "COL2"="COL2")

Note
-----
   - dynamic sampling used for this statement

eliminate union

Sanji, May 02, 2007 - 4:11 pm UTC

Tom

I am trying to rewrite the following query.

select v.vendor, v.vendor_vname,v.remit_to_code,v.bank_entity,v.vbank_acct_no, m.r_public "Public" , a.addr1, a.addr2, a.city_addr5,a.state_prov, a.postal_code
from apvenmast v, apvenmast3 m, apvenaddr a
where v.vendor_group = m.vendor_group (+)
and v.vendor = m.vendor (+)
and v.vendor_group = a.vendor_group
and v.vendor = a.vendor
and a.location_code = ' '
and a.cur_addr = 'Y'
UNION
select v.vendor,v.vendor_vname,l.location_code,l.bank_entity,l.vbank_acct_no, m.r_public "Public" , a.addr1, a.addr2,a.city_addr5,a.state_prov, a.postal_code
from apvenmast v, apvenloc l, apvenmast3 m,apvenaddr a
where v.vendor_group = l.vendor_group
and v.vendor = l.vendor
and v.vendor_group = m.vendor_group (+)
and v.vendor = m.vendor (+)
and l.vendor_group = a.vendor_group
and l.vendor = a.vendor
and l.location_code = a.location_code
and a.cur_addr = 'Y'
and l.active_status = 'A'
/

Following is the execution plan
Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=28331 Card=96382 Bytes=22721876)
1 0 SORT (UNIQUE) (Cost=28331 Card=96382 Bytes=22721876)
2 1 UNION-ALL
3 2 HASH JOIN (OUTER) (Cost=6223 Card=1428 Bytes=312732)
4 3 NESTED LOOPS (Cost=5495 Card=1428 Bytes=288456)
5 4 TABLE ACCESS (FULL) OF 'APVENADDR' (Cost=2639 Card=1428 Bytes=167076)
6 4 TABLE ACCESS (BY INDEX ROWID) OF 'APVENMAST' (Cost=2 Card=1 Bytes=85)
7 6 INDEX (UNIQUE SCAN) OF 'VENSET1' (UNIQUE) (Cost=1 Card=1)
8 3 TABLE ACCESS (FULL) OF 'APVENMAST3' (Cost=715 Card=59344 Bytes=1008848)
9 2 HASH JOIN (Cost=15391 Card=94954 Bytes=22409144)
10 9 HASH JOIN (OUTER) (Cost=12190 Card=37921 Bytes=4512599)
11 10 HASH JOIN (Cost=11359 Card=37921 Bytes=3867942)
12 11 TABLE ACCESS (FULL) OF 'APVENLOC' (Cost=1220 Card=37921 Bytes=2123576)
13 11 TABLE ACCESS (FULL) OF 'APVENMAST' (Cost=9753 Card=303958 Bytes=13982068)
14 10 TABLE ACCESS (FULL) OF 'APVENMAST3' (Cost=715 Card=59344 Bytes=1008848)
15 9 TABLE ACCESS (FULL) OF 'APVENADDR' (Cost=2639 Card=189908 Bytes=22219236)

The latter part of the query has an extra join with "apvenloc".

This is ideally executing 2 queries and selecting distinct rows from each result set.

Could you suggest a more efficient methodology to write this query ?

Thanks
Sanji
Tom Kyte
May 02, 2007 - 6:20 pm UTC

not off hand - think about it

you join

t1, t2, t3
union
t1, t2, t3, t4

in the first query, t2 is used to provide some column values that t4 is used to provide in the second query - so two rows are returned.

If you squished that down into a single query - well, you'd get only one (or the other) row

further, what if by joining to t4 you turned 1 row from t1, t2, t3 (joined) into 5 - now you have a mess.

makes sense

Sanji, May 02, 2007 - 10:10 pm UTC

Makes a lot of sense.
Thanks a lot

SYS_OP_C2C( )

V, May 08, 2007 - 4:35 pm UTC

Hi Tom,
One of our applications is issuing sql statment as below.

insert into t_app_XXX1 ( id, sequence, label, action,----)
select
id, sequence, label, action,----
from
t_app_XXX2
WHERE id = :id AND version = :version And equence=:sequence

Primary key is (ID,VERSION,SEQUENCE) and rowcount ~50,000

From SQL trace I noticed that query is not using primary key index. After looking into V$SQLPLAN, I figured out that
filter_predicate is as below
("SEQUENCE"=:SEQUENCE AND SYS_OP_C2C("ID")=:ID AND "VERSION"=:VERSION)

Application is not issuing function SYS_OP_C2C(ID), but I did not understand why Oracle including the function.
For testing I executed as below.
SQL> select sys_op_c2c('What is this ?') from dual;

SYS_OP_C2C('WH
--------------
What is this ?

I created function based index as below and optimizer using index.
CREATE INDEX MY_IND ON ADV94.T_APP_XXX2
(SYS_OP_C2C("ID"), VERSION, SEQUENCE)

Could you please advise what is this function ? I am sure that is not our application function but Oracle's built in. I could not find any inforatmion on metalink.
Thank you,
V


Tom Kyte
May 11, 2007 - 8:49 am UTC

how about you give us a TEST CASE starting with your CREATE TABLE that demonstrates this please.

Thanks for your time

V, May 11, 2007 - 1:05 pm UTC

Tom,
My question earlier regarding sys_op_c2c function. I think i figured out the issue because, applicaiton is binding (.net) column to NVARCHAR2 where table column is VARCHAR2. It seems Oracle uses function to convert (implicit) Nvarchar2 to varchar2. I think that is the reason why my primary indexes also not used.
Thanks for your time
V

Query Plan or Bind Variables

RAM, May 16, 2007 - 4:35 am UTC

Hi Tom ,
I am currently monitoring a database where there is a specific module which causes a problem, the sql's are generated via a procedure call.
I have identified that none of the SQL's are Using Bind Variables and reported this as the major cause.I generated the report of SQL's that aren't using the function that you have provided (remove_constants) and the count for the sql in question is much above 350 or so.I strongly recommended to use Bind Variables so as to over come the issue as this is executed frequently.
But the Dev Lead says that we need to Fix up the Query Plan first and find other alternatives first and then will only we emphasize on usage of Bind Variables.He was making a point like "The IN Clauses should not be there. I want to focus on the developer to understand why they believe that they are required and redefine the query."

Please can i have your views on the same.

SELECT *
FROM (SELECT x.*, ROWNUM r
FROM (SELECT DISTINCT (u.user_id), u.first_name, u.last_name,
ua.login_name, sc.NAME sc_name,
a.display_name,
ua.authentication_type AS auth_type
FROM gbc_core.users u,
gbc_auth.user_authentications ua,
gbc_auth.user_status_codes sc,
gbc_core.accounts a
WHERE u.user_id = ua.user_id
AND ua.status_code = sc.status_code_id
AND u.user_id IN (
SELECT user_id
FROM users
WHERE account_id = a.account_id
UNION ALL
SELECT user_id
FROM user_accounts
WHERE account_id = a.account_id)
AND a.account_id IN (
SELECT u3.account_id
FROM users u3
WHERE user_id = :p_user_id
UNION ALL
SELECT ua3.account_id
FROM user_accounts ua3
WHERE user_id = :p_user_id)
AND UPPER (ua.login_name) LIKE UPPER (:v_pattern)) x
WHERE ROWNUM <= :p_end_row)
WHERE r >= :p_start_row


The explain plan is :

------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 220 | 50380 | 757 |
|* 1 | VIEW | | 220 | 50380 | 757 |
|* 2 | COUNT STOPKEY | | | | |
| 3 | VIEW | | 220 | 47520 | 757 |
|* 4 | SORT UNIQUE STOPKEY | | 220 | 17820 | 97 |
|* 5 | FILTER | | | | |
|* 6 | HASH JOIN | | 220 | 17820 | 84 |
| 7 | TABLE ACCESS FULL | USERS | 6281 | 104K| 15 |
|* 8 | HASH JOIN | | 4393 | 274K| 66 |
| 9 | MERGE JOIN CARTESIAN | | 112 | 5376 | 46 |
| 10 | NESTED LOOPS | | 14 | 518 | 18 |
| 11 | VIEW | VW_NSO_1 | 14 | 182 | 4 |
| 12 | UNION-ALL | | | | |
| 13 | TABLE ACCESS BY INDEX ROWID| USERS | 1 | 8 | 2 |
|* 14 | INDEX UNIQUE SCAN | USERS_PK | 1 | | 1 |
|* 15 | INDEX RANGE SCAN | USERS_ACCOUNTS_PK | 13 | 104 | 2 |
| 16 | TABLE ACCESS BY INDEX ROWID | ACCOUNTS | 1 | 24 | 1 |
|* 17 | INDEX UNIQUE SCAN | ACCOUNTS_PK | 1 | | |
| 18 | BUFFER SORT | | 8 | 88 | 45 |
| 19 | TABLE ACCESS FULL | USER_STATUS_CODES | 8 | 88 | 2 |
| 20 | TABLE ACCESS BY INDEX ROWID | USER_AUTHENTICATIONS | 314 | 5024 | 19 |
|* 21 | INDEX RANGE SCAN | IND_USER_AUTH_LOGIN | 56 | | 2 |
| 22 | UNION-ALL | | | | |
|* 23 | TABLE ACCESS BY INDEX ROWID | USERS | 1 | 8 | 2 |
|* 24 | INDEX UNIQUE SCAN | USERS_PK | 1 | | 1 |
|* 25 | INDEX UNIQUE SCAN | USERS_ACCOUNTS_PK | 1 | 8 | 1 |
------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("from$_subquery$_001"."R">=TO_NUMBER(:Z))
2 - filter(ROWNUM<=TO_NUMBER(:Z))
4 - filter(ROWNUM<=TO_NUMBER(:Z))
5 - filter( EXISTS ( (SELECT /*+ */ "USERS"."USER_ID" FROM "GBC_CORE"."USERS" "USERS" WHERE
"USERS"."USER_ID"=:B1 AND "USERS"."ACCOUNT_ID"=:B2) UNION ALL (SELECT /*+ */
"USER_ACCOUNTS"."USER_ID" FROM "GBC_CORE"."USER_ACCOUNTS" "USER_ACCOUNTS" WHERE
"USER_ACCOUNTS"."ACCOUNT_ID"=:B3 AND "USER_ACCOUNTS"."USER_ID"=:B4)))
6 - access("SYS_ALIAS_1"."USER_ID"="UA"."USER_ID")
8 - access("UA"."STATUS_CODE"="SC"."STATUS_CODE_ID")
14 - access("U3"."USER_ID"=TO_NUMBER(:Z))
15 - access("UA3"."USER_ID"=TO_NUMBER(:Z))
17 - access("SYS_ALIAS_2"."ACCOUNT_ID"="VW_NSO_1"."$nso_col_1")
21 - access(UPPER("UA"."LOGIN_NAME") LIKE UPPER(:Z))
filter(UPPER("UA"."LOGIN_NAME") LIKE UPPER(:Z))
23 - filter("USERS"."ACCOUNT_ID"=:B1)
24 - access("USERS"."USER_ID"=:B1)
25 - access("USER_ACCOUNTS"."USER_ID"=:B1 AND "USER_ACCOUNTS"."ACCOUNT_ID"=:B2)

Note: cpu costing is off
Thanks in advance


Tom Kyte
May 16, 2007 - 10:30 am UTC

that query uses bind variables - not sure what you mean.

Explain Plan or Bind Variables

RAM, May 16, 2007 - 4:38 am UTC

Hi tom ,

Forgot to mention that the query pasted above is not currently running on the production system ie the code on the production is still not using Bind Variables.I gave a suggestion to use Bind Varaibles but that is not take as the priority issue.

Thanks again

Binds or EXplain Plan

RAM, May 17, 2007 - 3:53 am UTC

Hi Tom,
I appologise for not conveying the message properly.

The query pasted above is what i suggested and this is not currently running on the production system ie the code on the production is still not using Bind Variables.I gave a suggestion to use Bind Varaibles but that is not take as the priority issue.

I reuested your openion on whether this could ie not using binds seriously hamper the performance or only the scalability.

Tom Kyte
May 17, 2007 - 11:21 am UTC

it is not my opinion

it is a fact that a query executed many times with different literals is

a) a huge security problem (google: sql injection)
b) a massive performance issue
c) a huge, perhaps the single largest, cause of "inability to scale in oracle"

Binds and Explain Plan

RAM, May 17, 2007 - 11:57 am UTC

Hi tom ,
Please can you suggest improvements if any for the above posted query.

Is there any other alternative to IN clause for this query.

Thanks again


Tell them to read the manual

Jim, May 17, 2007 - 12:03 pm UTC

Ram,
If they actually read the manuals. (Application Developer's Guide - Fundamentals) they can actually read all about bind variables and how VITAL they are to scale. Cure that problem and you will see HUGE gains in the performance of the system. using statspack etc. you can actually PROVE and QUANTIFY that this is a major drain on the system. I understand that is is difficult for those you are dealing with to understand the magnitude of their folly. (not using bind variables) Be brave and show them how it impacts the system.

instead of statspack/tkprof

Karteek, May 21, 2007 - 8:25 am UTC

Tom,

Is there any way that I can find the performance of DMLs of a procedure. While I do my application performance testing...I would like to check performance of SQL being used as well.

statspack and tkprof can help here, but is there any other way where I can get the information (each sql cost, plan, lio, pio etc...) by directly fetching the information from dictionary views (v$...).

Thanks Tom...
- Karteek

Tom Kyte
May 21, 2007 - 11:12 am UTC

sql_trace=true is the way to get it for your session.
statspack for the system

if you grab it from v$ views, you would be basically REIMPLEMENTING statspack and would have a system view (so obviously you would not do that, you would just use statspack)

if you have 10g and have licensed the AWR/ASH facility, you can use those views as well - ASH will give you a session view, AWR a system (statspack like) view.

Unable to understand the explain plan Oracle is using

Shreyas, June 05, 2007 - 5:05 pm UTC

Am debugging one poorly performing query. I was able to simulate the problem as well.

SQL> create table t_obj as
  2  select * from all_objects;

Table created.

SQL> create table t_tab as
  2  select o.object_id, t.*
  3  from   all_objects o, all_tables t
  4  where  o.owner = t.owner
  5  and    o.object_name = t.table_name;

Table created.

SQL> create index ik_t_obj_1 on t_obj(object_id);

Index created.

SQL> create index ik_t_obj_2 on t_obj(created);

Index created.

SQL> create index ik_t_tab_1 on t_tab(object_id);

Index created.

SQL> select count(*) from t_obj;

  COUNT(*)
----------
     29247

SQL> select count(*) from t_tab;

  COUNT(*)
----------
      1849

SQL> analyze table t_obj compute statistics for table for all indexes for all indexed columns;

Table analyzed.

SQL> analyze table t_tab compute statistics for table for all indexes for all indexed columns;

Table analyzed.

A simple query on t_obj on the indexed column

SQL> select o.object_id
  2  from   t_obj o
  3  where o.created between '01-Jan-2006'
  4       and '01-Nov-2006';

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=38 Card=71 Bytes=781)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'T_OBJ' (Cost=38 Card=71 Bytes=781)
   2    1     INDEX (RANGE SCAN) OF 'IK_T_OBJ_2' (NON-UNIQUE) (Cost=2 Card=71)

Query uses the index that is expected to use

Now, join t_tab; the join is on the indexed column

SQL> select o.object_id, t.table_name
  2  from   t_obj o, t_tab t
  3  where o.created between '01-Jan-2006' and '01-Nov-2006'
  4  and   o.object_id = t.object_id;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=46 Card=71 Bytes=2272)
   1    0   HASH JOIN (Cost=46 Card=71 Bytes=2272)
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'T_OBJ' (Cost=38 Card=71 Bytes=781)
   3    2       INDEX (RANGE SCAN) OF 'IK_T_OBJ_2' (NON-UNIQUE) (Cost=2 Card=71)
   4    1     <b>TABLE ACCESS (FULL) OF 'T_TAB'</b> (Cost=7 Card=1849 Bytes=38829)

This does an FTS on t_tab and does not use the index



An FTS on t_tab is proving costly in our actual case, and the query takes a long time to return data. Using a hint increases the cost but speeds up the query. Can you please help me undestand this behaviour?

We use Oracle 9i (9.2.0.8.0)

Shreyas.

Lot of OR's on different columns of the same table

tarun singh, July 10, 2007 - 3:28 pm UTC

Im trying to tune the following query.


select object_name, r_content_size from eccrpprd.dm_sysobject_s
where ((lower(object_name) like '%tarun%' or lower(title) like '%tarun%' or lower(subject) like '%tarun%' or lower(owner_name) like '%tarun%') and (r_object_type in ('dm_cabinet', 'dm_document', 'dm_folder') or r_object_type like 'qc_%') );


the explain plan right now is --

--------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
--------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 28744 | 1515K| 15051 |
|* 1 | TABLE ACCESS FULL| DM_SYSOBJECT_S | 28744 | 1515K| 15051 |
--------------------------------------------------------------------

its a fat table with 30-40 columns
and number of rows are 2702911.


I just dont know what should be my approach --- creating function based indexes on each of these columns,or creating a composite index on all of them or creating an index on r_object_type.

the query is takiing 30 secs right now.anytime less between 1-9 secs would be great as per customer demand.

Please advise.


Tom Kyte
July 10, 2007 - 8:11 pm UTC

read about ctxcat indexes in the oracle text documentation...

re:Lot of OR's on different columns of the same table.

tarun singh, July 10, 2007 - 3:30 pm UTC


and the version is 10.2.0.1.

thanks

Query Performance

Hitesh, July 13, 2007 - 2:23 pm UTC

Hi Tom,

I am facing an issue related to performance of the query which involves 4 tables

1. TEMP : 2.4 million
2. Impression_data : 65 million
3. AD_MATCH : 900 rows
4. Click_data : 0.28 million
5. Invalid_click_report_data : 4% of 0.28 million

When I run the query:

Select /*+ USE_HASH(req_imp_ad_match_view Z) Parallel(req_imp_ad_match_view 16) Parallel(Z 16) */ Category, req_imp_ad_match_view.ad_match_id AdMatchId, Ads_Ranked, Z.Click_tag C_tag, Case When Z.click_tag is NOT NULL then req_imp_ad_match_view.Ad_Cost Else 0 END AdCost from ( Select /*+ Parallel(req_imp_view 16) Parallel(ZA 16) USE_HASH(req_imp_view ZA) */ Rtag,Category,Ads_Ranked,req_imp_view.Ad_Match_Id,Ad_Cost,Impression_tag,Match_Terms
from
(
Select /*+ Parallel(temp 16) Parallel(Impression_data 16) USE_HASH(temp Impression_data) */ Rtag,Category,Ads_Ranked,Ad_Match_Id,Ad_Cost,Impression_tag
from
temp, impression_data
Where
Invalid is NULL AND
Impression_data.Insert_date >= to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') AND Impression_data.Insert_date < to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') + 1 + 1/24 AND
temp.RTag = Impression_data.Request_tag
) req_imp_view,
(
Select /*+ Parallel(AdMatch 16) */ Ad_Match_Id, Match_Terms from Ad_Match_V AdMatch Where Match_terms like 'category_%' AND UNSYNC_DATE <= to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss')
) ZA
Where req_imp_view.Ad_Match_Id = ZA.Ad_Match_Id AND
req_imp_view.Category = ZA.Match_Terms
) req_imp_ad_match_view,
(
Select /*+ Parallel(a 16) Use_Hash(b a) */ * from click_data a Where Insert_date >= to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') AND NOT EXISTS
(Select /*+ Parallel(b 16) USE_HASH(b a) */ Null from Invalid_Click_report_data b Where
Insert_date >= to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') AND a.click_tag = b.Click_tag)
) Z
Where req_imp_ad_match_view.Impression_tag = Z.Impression_tag(+) /

I get a plan listed below using dbms_xplan.display_cursor and the results gets fetched in 7 mins of time, which is pretty good given the joins and the complexity of the query.


| 0 | SELECT STATEMENT | | | | 21153 (100)| | |
|* 3 | HASH JOIN OUTER BUFFERED | | 1 | 96 | 21152 (4)| 00:04:14 | | | 6 | VIEW | | 1 | 76 | 20678 (4)| 00:04:09 | |
| 7 | NESTED LOOPS | | 1 | 143 | 20678 (4)| 00:04:09 | |
|* 8 | HASH JOIN | | 1 | 107 | 20678 (4)| 00:04:09 | |
|* 12 | TABLE ACCESS FULL | TEMP | 1 | 53 | 0 (0)| | |
|* 14 | TABLE ACCESS FULL | IMPRESSION_DATA | 65M| 3384M| 20612 (4)| 00:04:08 | 15 |
|* 15 | TABLE ACCESS BY INDEX ROWID| AD_MATCH | 1 | 36 | 0 (0)| | |
|* 16 | INDEX UNIQUE SCAN | PK_AD_MATCH | 1 | | 0 (0)| | |
| 19 | VIEW | | 288K| 5641K| 473 (1)| 00:00:06 | |
|* 20 | HASH JOIN RIGHT ANTI | | 288K| 18M| 473 (1)| 00:00:06 | |
|* 24 | TABLE ACCESS FULL | INVALID_CLICK_REPORT_DATA | 1 | 25 | 7 (0)| 00:00:01 | 1 |
|* 26 | TABLE ACCESS FULL | CLICK_DATA | 288K| 11M| 464 (1)| 00:00:06 | 15 |


However, if I put a SELECT doing a GROUP BY as the OUTER CLUASE to the above mentioned query then:

Select /*+ Parallel(Step1 16) */ Category, count(AdMatchId) cnt_impr_admatch, Sum(Ads_Ranked) cnt_Ranks_AdMatch,
count(C_tag) cnt_clicks_admatch, sum(AdCost) cost_admatch
from
(
Query listed above
) Step1
Group by Category
/

It takes 1 hr and 20 mins to complete, where in it just need to group the results based on "category". The plan should show "SORT GROUP BY" operation at the top most of the plan without changing anything else, but I see CBO differentiating the plan by using NESTED LOOPS OUTER than choosing HASH JOIN OUTER.

| 0 | SELECT STATEMENT | | | | 20694 (100)| |
| 1 | SORT GROUP BY | | 1 | 92 | 20694 (4)| 00:04:09 |
| 2 | NESTED LOOPS OUTER | | 1 | 92 | 20693 (4)| 00:04:09 |
| 5 | VIEW | | 1 | 78 | 20678 (4)| 00:04:09 |
| 6 | NESTED LOOPS | | 1 | 143 | 20678 (4)| 00:04:09 |
|* 7 | HASH JOIN | | 1 | 107 | 20678 (4)| 00:04:09 |
|* 11 | TABLE ACCESS FULL | TEMP | 1 | 53 | 0 (0)| |
|* 13 | TABLE ACCESS FULL | IMPRESSION_DATA | 65M| 3384M| 20612 (4)| 00:04:08 |
|* 14 | TABLE ACCESS BY INDEX ROWID | AD_MATCH | 1 | 36 | 0 (0)| |
|* 15 | INDEX UNIQUE SCAN | PK_AD_MATCH | 1 | | 0 (0)| |
| 18 | BUFFER SORT | | 1 | 92 | 20694 (4)| 00:04:09 |
| 19 | VIEW PUSHED PREDICATE | | 1 | 14 | | |
|* 20 | HASH JOIN ANTI | | 1 | 84 | 473 (1)| 00:00:06 |
|* 24 | TABLE ACCESS FULL | CLICK_DATA | 1 | 59 | 464 (1)| 00:00:06 |
|* 28 | TABLE ACCESS FULL | INVALID_CLICK_REPORT_DATA | 1 | 25 | 7 (0)| 00:00:01 |

Even specifying the hints is not solving the problem. Can you put in some possible suggestions.

Thanks


Tom Kyte
July 13, 2007 - 7:46 pm UTC

when I see so many hints - I just say "lose em"

what then

Jonathan Lewis, July 14, 2007 - 2:25 am UTC

Hitesh,

There is a CODE button on the input pages to make SQL and execution plans a little more readable. But you've made things harder anyway by cutting out all the paralle bits of the plan.

It's clear that you don't really know what you're doing with hints. You haven't used them correctly, so the performance of your basic query is more luck than judgement. Despite that, you might get lucky if you wrap the basic query into an inline view and add a /*+ no_merge */ hint to it, before selecting and grouping. Something like:

select ....
from 
    (
     select /*+ no_merge (V) */
            *
     from   (
             {your base query goes here}
            ) V
    )
where
group by 
having 
order by
;


No guarantees - because I don't have the time to untangle the original query - but it might work.

Regards
Jonathan Lewis
http://jonathanlewis.wordpres.com
http://www.jlcomp.demon.co.uk

Plans with NO HINTS

Hitesh bajaj, July 14, 2007 - 2:51 am UTC

Hi Tom,

Here are the plans without using any HINTS,





dwuser@ADMW>select * from table(dbms_xplan.display_cursor('b2a6v9843y3wt'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID b2a6v9843y3wt, child number 0
-------------------------------------
Select Category, req_imp_ad_match_view.ad_match_id AdMatchId, Ads_Ranked, Z.Click_tag C_tag, Case When Z.click_tag is NOT NULL then req_imp_ad_match_view.Ad_Cost Else 0 END AdCost from ( Select Rtag, Category, Ads_Ranked, req_imp_view.Ad_Match_Id, Ad_Cost, Impression_tag, Match_Terms from ( Select Rtag, Category, Ads_Ranked,
Ad_Match_Id, Ad_Cost, Impression_tag from temp t , impression_data imp Where Invalid is NULL AND
Imp.Insert_date >= to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') AND Imp.Insert_date < to_date('08/07/2007
07:59:59','DD/MM/YYYY hh24:mi:ss') + 1 + 1/24 AND t.RTag = Imp.Request_tag ) req_imp_view, ( Select
Ad_Match_Id, Match_Terms from Ad_Match_V AdMatch Where Match_terms like 'category_%' AND UNSYNC_DATE <=
to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') ) ZA Where req_imp_view.Ad_Match_Id = ZA.Ad_Match_Id AND
req_imp_view.Category = ZA.Match_Terms ) req_imp_ad_match_view, ( Select * from click_data a Where Insert_date
>= to_da

Plan hash value: 245199584

----------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
----------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 306K(100)| | | |
| 1 | NESTED LOOPS OUTER | | 1 | 92 | 306K (5)| 01:01:20 | | |
| 2 | VIEW | | 1 | 78 | 299K (5)| 00:59:58 | | |
| 3 | NESTED LOOPS | | 1 | 143 | 299K (5)| 00:59:58 | | |
|* 4 | HASH JOIN | | 1 | 107 | 299K (5)| 00:59:57 | | |
|* 5 | TABLE ACCESS FULL | TEMP | 1 | 53 | 2 (0)| 00:00:01 | | |
| 6 | PARTITION RANGE ITERATOR | | 65M| 3384M| 298K (4)| 00:59:45 | 14 | 15 |
|* 7 | TABLE ACCESS FULL | IMPRESSION_DATA | 65M| 3384M| 298K (4)| 00:59:45 | 14 | 15 |
|* 8 | TABLE ACCESS BY INDEX ROWID| AD_MATCH | 1 | 36 | 1 (0)| 00:00:01 | | |
|* 9 | INDEX UNIQUE SCAN | PK_AD_MATCH | 1 | | 0 (0)| | | |
| 10 | VIEW PUSHED PREDICATE | | 1 | 14 | 6852 (2)| 00:01:23 | | |
|* 11 | HASH JOIN ANTI | | 1 | 84 | 6852 (2)| 00:01:23 | | |
| 12 | PARTITION RANGE ITERATOR | | 1 | 59 | 6739 (2)| 00:01:21 | 14 | 27 |
|* 13 | TABLE ACCESS FULL | CLICK_DATA | 1 | 59 | 6739 (2)| 00:01:21 | 14 | 27 |
| 14 | PARTITION RANGE ALL | | 1 | 25 | 112 (3)| 00:00:02 | 1 | 27 |
|* 15 | TABLE ACCESS FULL | INVALID_CLICK_REPORT_DATA | 1 | 25 | 112 (3)| 00:00:02 | 1 | 27 |
----------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

4 - access("T"."RTAG"="IMP"."REQUEST_TAG")
5 - filter(("INVALID" IS NULL AND "CATEGORY" LIKE 'category_%'))
7 - filter(("IMP"."INSERT_DATE">=TO_DATE('2007-07-08 07:59:59', 'yyyy-mm-dd hh24:mi:ss') AND
"IMP"."INSERT_DATE"<TO_DATE('2007-07-09 08:59:59', 'yyyy-mm-dd hh24:mi:ss')))
8 - filter(("MATCH_TERMS" LIKE 'category_%' AND "UNSYNC_DATE"<=TO_DATE('2007-07-08 07:59:59', 'yyyy-mm-dd
hh24:mi:ss') AND "CATEGORY"="MATCH_TERMS"))
9 - access("AD_MATCH_ID"="AD_MATCH_ID")
11 - access("A"."CLICK_TAG"="B"."CLICK_TAG")
13 - filter(("A"."IMPRESSION_TAG"="REQ_IMP_AD_MATCH_VIEW"."IMPRESSION_TAG" AND "INSERT_DATE">=TO_DATE('2007-07-08
07:59:59', 'yyyy-mm-dd hh24:mi:ss')))
15 - filter("INSERT_DATE">=TO_DATE('2007-07-08 07:59:59', 'yyyy-mm-dd hh24:mi:ss'))

51 rows selected.

"With Outer Group BY"
=====================
dwuser@ADMW>select * from table(dbms_xplan.display_cursor('fxxcpsbfn0s86'));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID fxxcpsbfn0s86, child number 0
-------------------------------------
Select Category, count(AdMatchId) cnt_impr_admatch, Sum(Ads_Ranked) cnt_Ranks_AdMatch, count(C_tag)
cnt_clicks_admatch, sum(AdCost) cost_admatch from ( Select Category, req_imp_ad_match_view.ad_match_id
AdMatchId, Ads_Ranked, Z.Click_tag C_tag, Case When Z.click_tag is NOT NULL then req_imp_ad_match_view.Ad_Cost Else 0 END AdCost from ( Select Rtag, Category, Ads_Ranked, req_imp_view.Ad_Match_Id, Ad_Cost, Impression_tag, Match_Terms from ( Select Rtag, Category, Ads_Ranked, Ad_Match_Id, Ad_Cost, Impression_tag from temp t ,
impression_data imp Where Invalid is NULL AND Imp.Insert_date >= to_date('08/07/2007 07:59:59','DD/MM/YYYY
hh24:mi:ss') AND Imp.Insert_date < to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') + 1 + 1/24 AND t.RTag
= Imp.Request_tag ) req_imp_view, ( Select Ad_Match_Id, Match_Terms from Ad_Match_V AdMatch Where Match_terms like 'category_%' AND UNSYNC_DATE <= to_date('08/07/2007 07:59:59','DD/MM/YYYY hh24:mi:ss') ) ZA Where req_imp_view

Plan hash value: 430429098

-----------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 306K(100)| | | |
| 1 | SORT GROUP BY | | 1 | 92 | 306K (5)| 01:01:20 | | |
| 2 | NESTED LOOPS OUTER | | 1 | 92 | 306K (5)| 01:01:20 | | |
| 3 | VIEW | | 1 | 78 | 299K (5)| 00:59:58 | | |
| 4 | NESTED LOOPS | | 1 | 143 | 299K (5)| 00:59:58 | | |
|* 5 | HASH JOIN | | 1 | 107 | 299K (5)| 00:59:57 | | |
|* 6 | TABLE ACCESS FULL | TEMP | 1 | 53 | 2 (0)| 00:00:01 | | |
| 7 | PARTITION RANGE ITERATOR | | 65M| 3384M| 298K (4)| 00:59:45 | 14 | 15 |
|* 8 | TABLE ACCESS FULL | IMPRESSION_DATA | 65M| 3384M| 298K (4)| 00:59:45 | 14 | 15 |
|* 9 | TABLE ACCESS BY INDEX ROWID| AD_MATCH | 1 | 36 | 1 (0)| 00:00:01 | | |
|* 10 | INDEX UNIQUE SCAN | PK_AD_MATCH | 1 | | 0 (0)| | | |
| 11 | VIEW PUSHED PREDICATE | | 1 | 14 | 6852 (2)| 00:01:23 | | |
|* 12 | HASH JOIN ANTI | | 1 | 84 | 6852 (2)| 00:01:23 | | |
| 13 | PARTITION RANGE ITERATOR | | 1 | 59 | 6739 (2)| 00:01:21 | 14 | 27 |
|* 14 | TABLE ACCESS FULL | CLICK_DATA | 1 | 59 | 6739 (2)| 00:01:21 | 14 | 27 |
| 15 | PARTITION RANGE ALL | | 1 | 25 | 112 (3)| 00:00:02 | 1 | 27 |
|* 16 | TABLE ACCESS FULL | INVALID_CLICK_REPORT_DATA | 1 | 25 | 112 (3)| 00:00:02 | 1 | 27 |
-----------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

5 - access("T"."RTAG"="IMP"."REQUEST_TAG")
6 - filter(("INVALID" IS NULL AND "CATEGORY" LIKE 'category_%'))
8 - filter(("IMP"."INSERT_DATE">=TO_DATE('2007-07-08 07:59:59', 'yyyy-mm-dd hh24:mi:ss') AND
"IMP"."INSERT_DATE"<TO_DATE('2007-07-09 08:59:59', 'yyyy-mm-dd hh24:mi:ss')))
9 - filter(("MATCH_TERMS" LIKE 'category_%' AND "UNSYNC_DATE"<=TO_DATE('2007-07-08 07:59:59', 'yyyy-mm-dd
hh24:mi:ss') AND "CATEGORY"="MATCH_TERMS"))
10 - access("AD_MATCH_ID"="AD_MATCH_ID")
12 - access("A"."CLICK_TAG"="B"."CLICK_TAG")
14 - filter(("A"."IMPRESSION_TAG"="REQ_IMP_AD_MATCH_VIEW"."IMPRESSION_TAG" AND "INSERT_DATE">=TO_DATE('2007-07-08
07:59:59', 'yyyy-mm-dd hh24:mi:ss')))
16 - filter("INSERT_DATE">=TO_DATE('2007-07-08 07:59:59', 'yyyy-mm-dd hh24:mi:ss'))

51 rows selected

But when I use hints specifically USE_HASH the output results come in 7 mins as opposed to 1 hr 20 mins, using NESTED LOOPS OUTER.

When the query is getting grouped by Category then
NESTED LOOPS OUTER comes into picture even when Hints are supplied.

Please help!

Tom Kyte
July 17, 2007 - 10:26 am UTC

as someone else pointed out - there is this "code button" concept that would make this a tad bit more readable to the rest of us.


do the estimated rows close to reality (they look like they are single digit row numbers - obviously in real life they must not be)

are your statistics CORRECT and UP TO DATE.

Query not running

Kumar B, July 19, 2007 - 1:59 am UTC

Hi Tom,
Greetings. I am looking for your help again.
We have a querry which was running fine till last week. It used to complete within few minutes. But now this query is not running in production database. However it runs on development database returning no rows.
Here is the query,

SELECT /*+ INDEX(itinerary ix6_itinerary) */TEMP_EXT_DATA_LOAD_STAGE.COP_ID, TEMP_EXT_DATA_LOAD_STAGE.BRA_ID,
TEMP_EXT_DATA_LOAD_STAGE.CFA_TYPE, TEMP_EXT_DATA_LOAD_STAGE.CFA_CODE, TEMP_EXT_DATA_LOAD_STAGE.CFA_ID,
TEMP_EXT_DATA_LOAD_STAGE.LINE_NUMBER, TEMP_EXT_DATA_LOAD_STAGE.DOCUMENT_TYPE, TEMP_EXT_DATA_LOAD_STAGE.ITIN_TYPE,
TEMP_EXT_DATA_LOAD_STAGE.ITIN_LINE_NO, TEMP_EXT_DATA_LOAD_STAGE.PAX_ID, TEMP_EXT_DATA_LOAD_STAGE.PAX_LINE_NO,
TEMP_EXT_DATA_LOAD_STAGE.PRODUCT_TYPE, TEMP_EXT_DATA_LOAD_STAGE.RECORD_TYPE, TEMP_EXT_DATA_LOAD_STAGE.TKT_DOC_STATUS
FROM
TEMP_EXT_DATA_LOAD_STAGE, ITINERARY
WHERE
TEMP_EXT_DATA_LOAD_STAGE.RECORD_TYPE ='FILE12' and ITINERARY.ITIN_TYPE ='H'
AND ITINERARY.ACTIVE in ('Y','N')
AND
ITINERARY.COP_ID = TEMP_EXT_DATA_LOAD_STAGE.COP_ID and ITINERARY.BRA_ID = TEMP_EXT_DATA_LOAD_STAGE.BRA_ID and
ITINERARY.CFA_TYPE = TEMP_EXT_DATA_LOAD_STAGE.CFA_TYPE and ITINERARY.CFA_CODE = TEMP_EXT_DATA_LOAD_STAGE.CFA_CODE
and ITINERARY.ITIN_TYPE = TEMP_EXT_DATA_LOAD_STAGE.ITIN_TYPE and ITINERARY.START_DATE=TEMP_EXT_DATA_LOAD_STAGE.HTC_START_DATE
and ITINERARY.LAST_NAME = rtrim(TEMP_EXT_DATA_LOAD_STAGE.HTC_LAST_NAME) and ITINERARY.FIRST_NAME= rtrim(TEMP_EXT_DATA_LOAD_STAGE.HTC_FIRST_NAME)
and ITINERARY.REFERENCE= TEMP_EXT_DATA_LOAD_STAGE.HTC_REFERENCE and ITINERARY.PHONE_ACODE= rtrim(substr(TEMP_EXT_DATA_LOAD_STAGE.HTC_PHONE,1,3))
and ITINERARY.PHONE_NO=rtrim(substr(TEMP_EXT_DATA_LOAD_STAGE.HTC_PHONE,4)) and
to_number(ITINERARY.END_DT - ITINERARY.START_DATE) = to_number(TEMP_EXT_DATA_LOAD_STAGE.HTC_NO_DAYS) and
ITINERARY.CONFIRMATION = rtrim(TEMP_EXT_DATA_LOAD_STAGE.HTC_CONFIRM_NO)
/
I used plan_table to find out execution plan.
Here is the plan.
----------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost | Pstart| Pstop |
----------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 161 | 126K| | |
|* 1 | TABLE ACCESS BY GLOBAL INDEX ROWID| ITINERARY | 1 | 61 | 170 | ROWID | ROW L |
| 2 | NESTED LOOPS | | 1 | 161 | 126K| | |
|* 3 | TABLE ACCESS FULL | TEMP_EXT_DATA_LOAD_STAGE | 709 | 70900 | 6053 | | |
| 4 | INLIST ITERATOR | | | | | | |
|* 5 | INDEX RANGE SCAN | IX6_ITINERARY | 829 | | 32 | | |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("ITINERARY"."COP_ID"="TEMP_EXT_DATA_LOAD_STAGE"."COP_ID" AND
"ITINERARY"."BRA_ID"="TEMP_EXT_DATA_LOAD_STAGE"."BRA_ID" AND
"ITINERARY"."CFA_TYPE"="TEMP_EXT_DATA_LOAD_STAGE"."CFA_TYPE" AND
"ITINERARY"."START_DATE"="TEMP_EXT_DATA_LOAD_STAGE"."HTC_START_DATE" AND
"ITINERARY"."LAST_NAME"=RTRIM("TEMP_EXT_DATA_LOAD_STAGE"."HTC_LAST_NAME") AND
"ITINERARY"."FIRST_NAME"=RTRIM("TEMP_EXT_DATA_LOAD_STAGE"."HTC_FIRST_NAME") AND
"ITINERARY"."REFERENCE"="TEMP_EXT_DATA_LOAD_STAGE"."HTC_REFERENCE" AND
"ITINERARY"."PHONE_ACODE"=RTRIM(SUBSTR("TEMP_EXT_DATA_LOAD_STAGE"."HTC_PHONE",1,3)) AND
"ITINERARY"."PHONE_NO"=RTRIM(SUBSTR("TEMP_EXT_DATA_LOAD_STAGE"."HTC_PHONE",4)) AND
TO_NUMBER("ITINERARY"."END_DT"-"ITINERARY"."START_DATE")=TO_NUMBER("TEMP_EXT_DATA_LOAD_STAGE"."HTC_NO_DAYS
")

AND "ITINERARY"."CONFIRMATION"=RTRIM("TEMP_EXT_DATA_LOAD_STAGE"."HTC_CONFIRM_NO"))
3 - filter("TEMP_EXT_DATA_LOAD_STAGE"."RECORD_TYPE"='FILE12' AND "TEMP_EXT_DATA_LOAD_STAGE"."HTC_START_DATE"
IS NOT NULL AND "TEMP_EXT_DATA_LOAD_STAGE"."HTC_REFERENCE" IS NOT NULL AND
"TEMP_EXT_DATA_LOAD_STAGE"."ITIN_TYPE"='H')
5 - access("ITINERARY"."CFA_CODE"="TEMP_EXT_DATA_LOAD_STAGE"."CFA_CODE" AND
"ITINERARY"."ITIN_TYPE"="TEMP_EXT_DATA_LOAD_STAGE"."ITIN_TYPE" AND ("ITINERARY"."ACTIVE"='N' OR
"ITINERARY"."ACTIVE"='Y'))
filter("ITINERARY"."ITIN_TYPE"='H')

There is full table scan for TEMP_EXT_DATA_LOAD_STAGE though there is index on this table.(IX1_TEMP_EXT_DATA_LOAD_STAGE is the index on columns CFA_CODE and RECORD_TYPE). I analysed this index , it is fine. Where is the hot spot?. No changes are made to the environment.
Will you please help me.

Tuning

jj, July 20, 2007 - 11:33 am UTC

Tom,
Can you please help me on this one? How can I tune this query?

SELECT COUNT (*) AS x0_0_
FROM cp_n action0_
WHERE (action0_.failed = 0)
AND (action0_.id_site = 1)
AND (action0_.id_action_type = 6)
AND (action0_.created >= TO_DATE ('19.7.2007 00:00', 'dd.mm.yyyy HH24:MI'))
AND (action0_.id_referrer = 9);

********************************************************************************

SELECT COUNT (*) AS x0_0_
FROM cpown.cp_action action0_
WHERE (action0_.failed = 0)
AND (action0_.id_site = 1)
AND (action0_.id_action_type = 6)
AND (action0_.created >= TO_DATE ('19.7.2007 00:00', 'dd.mm.yyyy HH24:MI'))
AND (action0_.id_referrer = 9)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.65 11.71 2323 6409 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.66 11.72 2323 6409 0 1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 5

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE (cr=6409 pr=2323 pw=0 time=11716912 us)
4317 TABLE ACCESS BY INDEX ROWID CP_n(cr=6409 pr=2323 pw=0 time=10187444 us)
4450 INDEX RANGE SCAN IDX_CP_n_CREATED_AT (cr=2928 pr=2088 pw=0 time=3047903 us)(object id 122943)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
library cache lock 1 0.00 0.00
SQL*Net message to client 2 0.00 0.00
db file sequential read 2323 0.06 10.67
gc cr grant 2-way 1048 0.00 0.34
gc current grant 2-way 93 0.00 0.02
latch free 1 0.00 0.00
latch: cache buffers chains 2 0.00 0.00
gc current block 2-way 3 0.00 0.00
gc cr block 2-way 7 0.00 0.00
SQL*Net message from client 2 0.00 0.00
********************************************************************************


Tom Kyte
July 20, 2007 - 5:11 pm UTC

wow, I cannot say how much that naming convention bothers me :)

The best way to make that query go faster would probably be not to run it. 99.999999999999999999% of the time, a count query like that is not useful. People do them to see if data exists to process - I just say 'try to process data until there isn't anymore'. You don't need to count.

short of that, indexing all of the columns in the predicate in a single concatenated index would do it. Put the things you use "=" on first in the index.

ROWNUM use

Asim, July 25, 2007 - 6:11 pm UTC

Hi Tom,
Could you please look at the scenario below for us and suggest us something?

We have a table with 80 million rows with a range index on the last name. The query requires a "LIKE" on the last name but has to return a set of 300 rows which is then joined to additional tables. The like can return millions of rows. We are using a hint to force the query to use the range index. Based on the explain the following is occurring:
1) Index Range Scan - Cost 30
2) Table Access - Cost 10,640
3) Count SortKey - Limits the rows to 300

The query appears to be joining the index back to the data prior to selecting only 300 rows. Is there a way to force the query to prune the rows prior to joining with the table.

The original query was performing the 3 table join prior to pruning the result set. We added the "with" to prune the result set prior to the 3 table join and saw significant improvement.

with tmp as (select /*+ INDEX(PERSONNAME X1PERSONNAME) */
c1, c2, etc,
FROM PERSONNAME
WHERE
UPPER (LAST_NAME) LIKE 'SMITH' || '%'
AND ROWNUM <= 301)
SELECT /*+ INDEX(XA X1XADDRESS) INDEX(XM X2XCONTACTMETHOD) INDEX(C P_CONTACT) INDEX(CT P_CONTRACT) INDEX(I I2_IDENTIFIER)*/ c3, c4, etc.
FROM
(SELECT /*+ INDEX(PN X1PERSONNAME) INDEX(CR I2_CONTRACTROLE) INDEX(CC P_CONTRACTCOMPONEN)*/ c5, c6, etc.
FROM
CONTRACTROLE CR,
CONTRACTCOMPONENT CC,
TMP
WHERE
TMP.PN_CONT_ID = CR.CONT_ID
AND CR.CONTR_COMPONENT_ID = CC.CONTR_COMPONENT_ID
AND ROWNUM <= 201) T,
CONTACT C,
PERSON P,
IDENTIFIER I,
CONTRACT CT,
XADDRESS XA,
XCONTACTMETHOD XM
WHERE T.CR_CONT_ID = C.CONT_ID
AND T.CR_CONT_ID = P.CONT_ID
AND T.CR_CONT_ID = I.CONT_ID

Thanks,
Asim
Tom Kyte
July 27, 2007 - 8:17 am UTC

... The query appears to be joining the index back to the data prior to selecting
only 300 rows. ...

I don't know what you mean by that.


Help on ROWNUM

Asim, July 26, 2007 - 10:44 am UTC

Hi Tom,
Some more information on this -

When we execute the "with tmp select * from personname where upper(last_name) like ''||'%' ....and rownum < 301 select * from tmp" query separately the cost is around 300 but when we use as it is in my previous question to pull the data from other tables after joining with "tmp" table data, the same overall cost goes back to 6500.

Unable to understand why? It is the same part in the explain plan for both the cases before "STOP COUNT KEY to restrict to 300".

Do you have any idea why?

Thanks,
Asim
Tom Kyte
July 27, 2007 - 8:55 am UTC

ignore the cost for now, the cost is a number we use to find the lowest cost execution path for a given query. not much use to you and me - unless you are debugging the optimizer.

SQL Tuning help

Asim, July 27, 2007 - 12:52 pm UTC

Hi Tom,
Please see the original query as below along with the table informations.

Let me know if you need anything else.

All the table have 100 to 150 million records.

Like search takes more than a minute and equal search takes 37 seconds for returning 1600 records.





Table Name Partition Partition Column(s) Indexes
-------------- ----------- --------------------------------------- -----------------------
PERSONNAME COMPOSITE partition of 216 partitions last_name, cont_id "UPPER("LAST_NAME"), NAME_USAGE_TP_CD, UPPER("GIVEN_NAME_ONE")" - B-Tree index - X1PERSONNAME
(Hash on cont_id and Range on first PERSON_NAME_ID - Primary key - Unique B-Tree index - P_PERSONNAME
character of last_name) "CONT_ID, END_DT" - B-Tree index - I4_PERSONNAME

CONTRACTROLE HASH parition of 128 partitions xcontract_id "CONTR_COMPONENT_ID, CONTR_ROLE_TP_CD" - B-Tree index - I1_CONTRACTROLE
"CONTR_COMPONENT_ID, CONT_ID, END_DT" - B-Tree index - X1CONTRACTROLE
"CONT_ID, CONTR_COMPONENT_ID, END_DT" - B-Tree index - I2_CONTRACTROLE
CONTRACT_ROLE_ID - PRIMARY KEY - Unique index - P_CONTRACTROLE
XCONTRACT_ID - B-Tree Index - X2CONTRACTROLE

CONTRACTCOMPONENT HASH parition of 128 partitions contract_id,cont_id,contr_componnent_id "CONTR_COMPONENT_ID, CONTRACT_ID" - B-Tree index - I1_CONTRACTCOMPONE
CONTR_COMPONENT_ID - PRIMARY KEY - Unique index - P_CONTRACTCOMPONEN
"CONTR_COMPONENT_ID, XLOB_TP_CD, XARCHIVED_IND" - B-Tree index - X1CONTRACTCOMPONENT
"CONTRACT_ID, CONTR_COMPONENT_ID, PROD_TP_CD" - B-Tree index - X2CONTRACTCOMPONENT

CONTACT HASH partition of 128 partitions x_ccid "CONT_ID, INACTIVATED_DT" - B-Tree index - I1_CONTACT
CONT_ID - PRIMARY KEY - Unique index - P_CONTACT
"X_CCID" - B-Tree index - X1CONTACT


PERSON HASH partition of 128 partitions x_ccid CONT_ID - Primary Key - Unique B-Tree index - P_PERSON
X_CCID - B-Tree index - X2PERSON


IDENTIFIER HASH partition of 256 partitions cont_id "CONT_ID, END_DT, ID_TP_CD" - B-Tree index - I2_IDENTIFIER
IDENTIFIER_ID - PRIMARY KEY - Unique index - P_IDENTIFIER
"REF_NUM, ID_TP_CD, END_DT" - B-Tree index - X1IDENTIFIER

CONTRACT HASH partition of 64 partitions contract_id "CONT_ID, INACTIVATED_DT" - B-Tree index - I1_CONTACT
CONT_ID - PRIMARY KEY - Unique index - P_CONTACT
"X_CCID" - B-Tree index - X1CONTACT

XADDRESS HASH partition of 192 partitions entity_name, instance_pk "UPPER("CITY_NAME"), INSTANCE_PK, ENTITY_NAME, END_DT" - B-Tree index - X5XADDRESS
ADDR_TP_CD - BITMAP index - X4XADDRESS
UPPER("ADDR_LINE_ONE") - B-Tree index - X3XADDRESS
UPPER("PROVINCE_STATE_NAME") - BITMAP index - X6XADDRESS
ADDRESS_ID - PRIMARY KEY - Unique index - XPKXADDRESS
"INSTANCE_PK, ENTITY_NAME, END_DT" - B-Tree index - X1XADDRESS
"POSTAL_CODE, INSTANCE_PK, ENTITY_NAME, END_DT" - B-Tree index - X2XADDRESS

XCONTACTMETHOD HASH partition of 256 partitions entity_name "UPPER("REF_NUM"), CONT_METH_CAT_CD, INSTANCE_PK, ENTITY_NAME, END_DT)" - B-Tree index - X1XCONTACTMETHOD
REF_NUM - B-Tree index - XP1XCONTACTMETHOD
CONTACT_METHOD_ID - PRIMARY KEY - Unique index - XPKXCONTACTMETHOD
"INSTANCE_PK, ENTITY_NAME, END_DT" - B-Tree index - X2XCONTACTMETHOD



We are executing this query below as last_name search:
-------------------------------------------------------------
SELECT /*+ INDEX(XA X1XADDRESS) INDEX(XM X2XCONTACTMETHOD) INDEX(C P_CONTACT) INDEX(CT P_CONTRACT)*/
C.CONT_ID C_CONT_ID,
C.ACCE_COMP_TP_CD C_ACCE_COMP_TP_CD,
C.PREF_LANG_TP_CD C_PREF_LANG_TP_CD,
C.CREATED_DT C_CREATED_DT,
C.INACTIVATED_DT C_INACTIVATED_DT,
C.CONTACT_NAME C_CONTACT_NAME,
C.PERSON_ORG_CODE C_PERSON_ORG_CODE,
C.SOLICIT_IND C_SOLICIT_IND,
C.CONFIDENTIAL_IND C_CONFIDENTIAL_IND,
C.CLIENT_IMP_TP_CD C_CLIENT_IMP_TP_CD,
C.CLIENT_ST_TP_CD C_CLIENT_ST_TP_CD,
C.CLIENT_POTEN_TP_CD C_CLIENT_POTEN_TP_CD,
C.RPTING_FREQ_TP_CD C_RPTING_FREQ_TP_CD,
C.LAST_STATEMENT_DT C_LAST_STATEMENT_DT,
C.PROVIDED_BY_CONT C_PROVIDED_BY_CONT,
C.ALERT_IND C_ALERT_IND,
C.LAST_UPDATE_DT C_LAST_UPDATE_DT,
C.LAST_UPDATE_USER C_LAST_UPDATE_USER,
C.LAST_UPDATE_TX_ID C_LAST_UPDATE_TX_ID,
C.DO_NOT_DELETE_IND C_DO_NOT_DELETE_IND,
C.LAST_USED_DT C_LAST_USED_DT,
C.LAST_VERIFIED_DT C_LAST_VERIFIED_DT,
C.SOURCE_IDENT_TP_CD C_SOURCE_IDENT_TP_CD,
C.X_CCID C_X_CCID,
P.CONT_ID P_CONT_ID,
P.MARITAL_ST_TP_CD P_MARITAL_ST_TP_CD,
P.BIRTHPLACE_TP_CD P_BIRTHPLACE_TP_CD,
P.CITIZENSHIP_TP_CD P_CITIZENSHIP_TP_CD,
P.HIGHEST_EDU_TP_CD P_HIGHEST_EDU_TP_CD,
P.AGE_VER_DOC_TP_CD P_AGE_VER_DOC_TP_CD,
P.GENDER_TP_CODE P_GENDER_TP_CODE,
P.BIRTH_DT P_BIRTH_DT,
P.DECEASED_DT P_DECEASED_DT,
P.CHILDREN_CT P_CHILDREN_CT,
P.DISAB_START_DT P_DISAB_START_DT,
P.DISAB_END_DT P_DISAB_END_DT,
P.USER_IND P_USER_IND,
P.LAST_UPDATE_DT P_LAST_UPDATE_DT,
P.LAST_UPDATE_USER P_LAST_UPDATE_USER,
P.LAST_UPDATE_TX_ID P_LAST_UPDATE_TX_ID,
P.XPREFERRED_NAME P_XPREFERRED_NAME,
P.XNAME_LOB_TP_CD P_XNAME_LOB_TP_CD,
P.XNAME_LAST_UPDATE_DT P_XNAME_LAST_UPDATE_DT,
P.XBIRTH_DT_LOB_TP_CD P_XBIRTH_DT_LOB_TP_CD,
P.XBIRTH_LAST_UPDATE_DT P_XBIRTH_LAST_UPDATE_DT,
P.XPRIM_STATE_CODE P_XPRIM_STATE_CODE,
P.XPRIM_POSTAL_CODE P_XPRIM_POSTAL_CODE,
P.XPRIM_ADDR_LOB_TP_CD P_XPRIM_ADDR_LOB_TP_CD,
P.XPRIM_ADDR_LAST_UPDATE_DT P_XPRIM_ADDR_LAST_UPDATE_DT,
P.XCALLBACK_QUEUE_IND P_XCALLBACK_QUEUE_IND,
P.XINTERACTION_STYLE P_XINTERACTION_STYLE,
P.XDISPOSITION_TP_CD P_XDISPOSITION_TP_CD,
P.XLAST_DISPOSITION_TP_CD P_XLAST_DISPOSITION_TP_CD,
P.XOVERALL_DISPOSITION_TP_CD P_XOVERALL_DISPOSITION_TP_CD,
P.XPREF_CONT_METHOD P_XPREF_CONT_METHOD,
P.XALERT_CONT_METHOD P_XALERT_CONT_METHOD,
P.XDIRECT_TO_AGENT P_XDIRECT_TO_AGENT,
P.XCITIZENSHIP_LOB_TP_CD P_XCITIZENSHIP_LOB_TP_CD,
P.XCITIZENSHIP_LAST_UPDATE_DT P_XCITIZENSHIP_LAST_UPDATE_DT,
P.XPREF_LANG_LOB_TP_CD P_XPREF_LANG_LOB_TP_CD,
P.XPREF_LANG_LAST_UPDATE_DT P_XPREF_LANG_LAST_UPDATE_DT,
P.XSOURCE_LAST_UPDATE_DT P_XSOURCE_LAST_UPDATE_DT,
P.XORG_TP_CD P_XORG_TP_CD,
P.XPARTY_TP_CODE P_XPARTY_TP_CODE,
P.X_CCID P_X_CCID,
P.XMEMBER_SINCE_DT P_XMEMBER_SINCE_DT,
P.XPATRIOT_ACT_DOB P_XPATRIOT_ACT_DOB,
P.XANNUAL_INCOME P_XANNUAL_INCOME,
P.XANNUAL_INCOME_LOB_TP_CD P_XANNUAL_INCOME_LOB_TP_CD,
P.XEMPLOYER_NAME P_XEMPLOYER_NAME,
P.XANNUAL_INCOME_LAST_UPD_DT P_XANNUAL_INCOME_LAST_UPD_DT,
P.XEMPLOYER_LAST_UPDATE_DT P_XEMPLOYER_LAST_UPDATE_DT,
P.OCCUPATION P_OCCUPATION,
P.XOCCUPATION_LAST_UPDATE_DT P_XOCCUPATION_LAST_UPDATE_DT,
P.XSRC_LANG P_XSRC_LANG,
T.CR_CONTRACT_ROLE_ID,
T.CR_CONT_ID,
T.CR_CONTR_COMPONENT_ID,
T.CR_CONTR_ROLE_TP_CD,
T.CR_REGISTERED_NAME,
T.CR_DISTRIB_PCT,
T.CR_IRREVOC_IND,
T.CR_START_DT,
T.CR_END_DT,
T.CR_RECORDED_START_DT,
T.CR_RECORDED_END_DT,
T.CR_LAST_UPDATE_DT,
T.CR_LAST_UPDATE_USER,
T.CR_SHARE_DIST_TP_CD,
T.CR_ARRANGEMENT_TP_CD,
T.CR_ARRANGEMENT_DESC,
T.CR_LAST_UPDATE_TX_ID,
T.CR_END_REASON_TP_CD,
T.CR_XCONTRACT_ID,
T.CR_XGCG_AID,
T.CR_XROLE_CONFIRM_TP_CD,
T.CR_XHOUSEHOLD_KEY,
T.CR_XJOINT_STATUS_IND,
T.CC_CONTR_COMPONENT_ID,
T.CC_CONTRACT_ST_TP_CD,
T.CC_PROD_TP_CD,
T.CC_CONTRACT_ID,
T.CC_CURR_CASH_VAL_AMT,
T.CC_PREMIUM_AMT,
T.CC_ISSUE_DT,
T.CC_VIATICAL_IND,
T.CC_BASE_IND,
T.CC_LAST_UPDATE_DT,
T.CC_LAST_UPDATE_USER,
T.CC_CONTR_COMP_TP_CD,
T.CC_LAST_UPDATE_TX_ID,
T.CC_SERV_ARRANGE_TP_CD,
T.CC_HOLDING_ID,
T.CC_EXPIRY_DT,
T.CC_PREMAMT_CUR_TP,
T.CC_CASHVAL_CUR_TP,
T.CC_XLOB_TP_CD,
T.CC_XBANKING_PACKAGE_TP_CD,
T.CC_XPROD_FEATURE_TP_CD,
T.CC_XPROD_FEATURE_BALANCE,
T.CC_XSEPARATOR_TP_CD,
T.CC_XEXPENSE_CODE,
T.CC_XPRIVATE_BANK_IND,
T.CC_XSOURCE_LAST_UPDATE_DT,
T.CC_XCONTRACT_ST_REASON_TP_CD,
T.CC_XARCHIVED_IND,
T.CC_XARCHIVED_IND_UPDATE_DT,
T.CC_XSRC_PROD_TYPE,
T.CC_XSRC_CONTRACT_STATUS,
T.PN_PERSON_NAME_ID,
T.PN_PREFIX_NAME_TP_CD,
T.PN_PREFIX_DESC,
T.PN_NAME_USAGE_TP_CD,
T.PN_GIVEN_NAME_ONE,
T.PN_GIVEN_NAME_TWO,
T.PN_GIVEN_NAME_THREE,
T.PN_GIVEN_NAME_FOUR,
T.PN_LAST_NAME,
T.PN_GENERATION_TP_CD,
T.PN_SUFFIX_DESC,
T.PN_START_DT,
T.PN_END_DT,
T.PN_CONT_ID,
T.PN_USE_STANDARD_IND,
T.PN_LAST_UPDATE_DT,
T.PN_LAST_UPDATE_USER,
T.PN_LAST_UPDATE_TX_ID,
T.PN_LAST_USED_DT,
T.PN_LAST_VERIFIED_DT,
T.PN_SOURCE_IDENT_TP_CD,
I.IDENTIFIER_ID I_IDENTIFIER_ID,
I.ID_STATUS_TP_CD I_ID_STATUS_TP_CD,
I.CONT_ID I_CONT_ID,
I.ID_TP_CD I_ID_TP_CD,
I.REF_NUM I_REF_NUM,
I.START_DT I_START_DT,
I.END_DT I_END_DT,
I.EXPIRY_DT I_EXPIRY_DT,
I.LAST_UPDATE_DT I_LAST_UPDATE_DT,
I.LAST_UPDATE_USER I_LAST_UPDATE_USER,
I.LAST_UPDATE_TX_ID I_LAST_UPDATE_TX_ID,
I.ASSIGNED_BY I_ASSIGNED_BY,
I.IDENTIFIER_DESC I_IDENTIFIER_DESC,
I.ISSUE_LOCATION I_ISSUE_LOCATION,
I.LAST_USED_DT I_LAST_USED_DT,
I.LAST_VERIFIED_DT I_LAST_VERIFIED_DT,
I.SOURCE_IDENT_TP_CD I_SOURCE_IDENT_TP_CD,
CT.CONTRACT_ID CT_CONTRACT_ID,
CT.CONTR_LANG_TP_CD CT_CONTR_LANG_TP_CD,
CT.CURRENCY_TP_CD CT_CURRENCY_TP_CD,
CT.FREQ_MODE_TP_CD CT_FREQ_MODE_TP_CD,
CT.BILL_TP_CD CT_BILL_TP_CD,
CT.REPL_BY_CONTRACT CT_REPL_BY_CONTRACT,
CT.PREMIUM_AMT CT_PREMIUM_AMT,
CT.NEXT_BILL_DT CT_NEXT_BILL_DT,
CT.CURR_CASH_VAL_AMT CT_CURR_CASH_VAL_AMT,
CT.LINE_OF_BUSINESS CT_LINE_OF_BUSINESS,
CT.BRAND_NAME CT_BRAND_NAME,
CT.SERVICE_ORG_NAME CT_SERVICE_ORG_NAME,
CT.BUS_ORGUNIT_ID CT_BUS_ORGUNIT_ID,
CT.SERVICE_PROV_ID CT_SERVICE_PROV_ID,
CT.LAST_UPDATE_DT CT_LAST_UPDATE_DT,
CT.LAST_UPDATE_USER CT_LAST_UPDATE_USER,
CT.LAST_UPDATE_TX_ID CT_LAST_UPDATE_TX_ID,
CT.ISSUE_LOCATION CT_ISSUE_LOCATION,
CT.ADMIN_CONTRACT_ID CT_ADMIN_CONTRACT_ID,
CT.ADMIN_SYS_TP_CD CT_ADMIN_SYS_TP_CD,
CT.PREMAMT_CUR_TP CT_PREMAMT_CUR_TP,
CT.CASHVAL_CUR_TP CT_CASHVAL_CUR_TP,
CT.XLEGAL_ENTITY_TP_CD CT_XLEGAL_ENTITY_TP_CD,
CT.XSOURCE_LAST_UPDATE_DT CT_XSOURCE_LAST_UPDATE_DT,
CT.XCOLLECTION_IND CT_XCOLLECTION_IND,
CT.XPORTFOLIO_ID CT_XPORTFOLIO_ID,
CT.XSTREAM_IND CT_XSTREAM_IND,
CT.XSOURCE_SYSTEM CT_XSOURCE_SYSTEM,
CT.XRELIEF_IND CT_XRELIEF_IND,
XA.ADDRESS_ID XA_ADDRESS_ID,
XA.ENTITY_NAME XA_ENTITY_NAME,
XA.INSTANCE_PK XA_INSTANCE_PK,
XA.XCAID XA_XCAID,
XA.ADDR_TP_CD XA_ADDR_TP_CD,
XA.ADDR_USAGE_TP_CD XA_ADDR_USAGE_TP_CD,
XA.RESIDENCE_TP_CD XA_RESIDENCE_TP_CD,
XA.PREFERRED_IND XA_PREFERRED_IND,
XA.ADDR_STATUS_TP_CD XA_ADDR_STATUS_TP_CD,
XA.START_DT XA_START_DT,
XA.END_DT XA_END_DT,
XA.LAST_UPDATE_DT_SRC XA_LAST_UPDATE_DT_SRC,
XA.LAST_UPDATE_DT XA_LAST_UPDATE_DT,
XA.LAST_UPDATE_TX_ID XA_LAST_UPDATE_TX_ID,
XA.LAST_UPDATE_USER XA_LAST_UPDATE_USER,
XA.ADDR_LINE_ONE XA_ADDR_LINE_ONE,
XA.ADDR_LINE_TWO XA_ADDR_LINE_TWO,
XA.CITY_NAME XA_CITY_NAME,
XA.PROVINCE_STATE_NAME XA_PROVINCE_STATE_NAME,
XA.POSTAL_CODE XA_POSTAL_CODE,
XA.COUNTRY_CODE XA_COUNTRY_CODE,
XA.ADDR_LINE_THREE XA_ADDR_LINE_THREE,
XA.ADDR_LINE_FOUR XA_ADDR_LINE_FOUR,
XA.ADDR_LINE_FIVE XA_ADDR_LINE_FIVE,
XA.ADDR_LINE_SIX XA_ADDR_LINE_SIX,
XA.ADDR_UNSTRUCTURED XA_ADDR_UNSTRUCTURED,
XA.PATRIOT_ACT_IND XA_PATRIOT_ACT_IND,
XA.EFFECT_START_MMDD XA_EFFECT_START_MMDD,
XA.EFFECT_END_MMDD XA_EFFECT_END_MMDD,
XA.SRC_COUNTRY XA_SRC_COUNTRY,
XA.RECURRING_IND XA_RECURRING_IND,
XM.CONTACT_METHOD_ID XM_CONTACT_METHOD_ID,
XM.ENTITY_NAME XM_ENTITY_NAME,
XM.INSTANCE_PK XM_INSTANCE_PK,
XM.CONT_METH_TP_CD XM_CONT_METH_TP_CD,
XM.CONT_METH_CAT_CD XM_CONT_METH_CAT_CD,
XM.REF_NUM XM_REF_NUM,
XM.CONT_METH_ST_TP_CD XM_CONT_METH_ST_TP_CD,
XM.ATTACH_ALLOW_IND XM_ATTACH_ALLOW_IND,
XM.TEXT_ONLY_IND XM_TEXT_ONLY_IND,
XM.START_DT XM_START_DT,
XM.END_DT XM_END_DT,
XM.LAST_UPDATE_DT_SRC XM_LAST_UPDATE_DT_SRC,
XM.LAST_UPDATE_DT XM_LAST_UPDATE_DT,
XM.LAST_UPDATE_USER XM_LAST_UPDATE_USER,
XM.LAST_UPDATE_TX_ID XM_LAST_UPDATE_TX_ID,
XM.PHONE_EXT_NBR XM_PHONE_EXT_NBR,
XM.SRC_METH_STATUS XM_SRC_METH_STATUS,
XM.RECURRING_IND XM_RECURRING_IND,
XM.EFFECT_END_MMDD XM_EFFECT_END_MMDD,
XM.EFFECT_START_MMDD XM_EFFECT_START_MMDD
FROM
(SELECT /*+ INDEX(PN X1PERSONNAME) INDEX(CR I2_CONTRACTROLE) INDEX(CC P_CONTRACTCOMPONEN)*/
CR.CONTRACT_ROLE_ID CR_CONTRACT_ROLE_ID,
CR.CONT_ID CR_CONT_ID,
CR.CONTR_COMPONENT_ID CR_CONTR_COMPONENT_ID,
CR.CONTR_ROLE_TP_CD CR_CONTR_ROLE_TP_CD,
CR.REGISTERED_NAME CR_REGISTERED_NAME,
CR.DISTRIB_PCT CR_DISTRIB_PCT,
CR.IRREVOC_IND CR_IRREVOC_IND,
CR.START_DT CR_START_DT,
CR.END_DT CR_END_DT,
CR.RECORDED_START_DT CR_RECORDED_START_DT,
CR.RECORDED_END_DT CR_RECORDED_END_DT,
CR.LAST_UPDATE_DT CR_LAST_UPDATE_DT,
CR.LAST_UPDATE_USER CR_LAST_UPDATE_USER,
CR.SHARE_DIST_TP_CD CR_SHARE_DIST_TP_CD,
CR.ARRANGEMENT_TP_CD CR_ARRANGEMENT_TP_CD,
CR.ARRANGEMENT_DESC CR_ARRANGEMENT_DESC,
CR.LAST_UPDATE_TX_ID CR_LAST_UPDATE_TX_ID,
CR.END_REASON_TP_CD CR_END_REASON_TP_CD,
CR.XCONTRACT_ID CR_XCONTRACT_ID,
CR.XGCG_AID CR_XGCG_AID,
CR.XROLE_CONFIRM_TP_CD CR_XROLE_CONFIRM_TP_CD,
CR.XHOUSEHOLD_KEY CR_XHOUSEHOLD_KEY,
CR.XJOINT_STATUS_IND CR_XJOINT_STATUS_IND,
CC.CONTR_COMPONENT_ID CC_CONTR_COMPONENT_ID,
CC.CONTRACT_ST_TP_CD CC_CONTRACT_ST_TP_CD,
CC.PROD_TP_CD CC_PROD_TP_CD,
CC.CONTRACT_ID CC_CONTRACT_ID,
CC.CURR_CASH_VAL_AMT CC_CURR_CASH_VAL_AMT,
CC.PREMIUM_AMT CC_PREMIUM_AMT,
CC.ISSUE_DT CC_ISSUE_DT,
CC.VIATICAL_IND CC_VIATICAL_IND,
CC.BASE_IND CC_BASE_IND,
CC.LAST_UPDATE_DT CC_LAST_UPDATE_DT,
CC.LAST_UPDATE_USER CC_LAST_UPDATE_USER,
CC.CONTR_COMP_TP_CD CC_CONTR_COMP_TP_CD,
CC.LAST_UPDATE_TX_ID CC_LAST_UPDATE_TX_ID,
CC.SERV_ARRANGE_TP_CD CC_SERV_ARRANGE_TP_CD,
CC.HOLDING_ID CC_HOLDING_ID,
CC.EXPIRY_DT CC_EXPIRY_DT,
CC.PREMAMT_CUR_TP CC_PREMAMT_CUR_TP,
CC.CASHVAL_CUR_TP CC_CASHVAL_CUR_TP,
CC.XLOB_TP_CD CC_XLOB_TP_CD,
CC.XBANKING_PACKAGE_TP_CD CC_XBANKING_PACKAGE_TP_CD,
CC.XPROD_FEATURE_TP_CD CC_XPROD_FEATURE_TP_CD,
CC.XPROD_FEATURE_BALANCE CC_XPROD_FEATURE_BALANCE,
CC.XSEPARATOR_TP_CD CC_XSEPARATOR_TP_CD,
CC.XEXPENSE_CODE CC_XEXPENSE_CODE,
CC.XPRIVATE_BANK_IND CC_XPRIVATE_BANK_IND,
CC.XSOURCE_LAST_UPDATE_DT CC_XSOURCE_LAST_UPDATE_DT,
CC.XCONTRACT_ST_REASON_TP_CD CC_XCONTRACT_ST_REASON_TP_CD,
CC.XARCHIVED_IND CC_XARCHIVED_IND,
CC.XARCHIVED_IND_UPDATE_DT CC_XARCHIVED_IND_UPDATE_DT,
CC.XSRC_PROD_TYPE CC_XSRC_PROD_TYPE,
CC.XSRC_CONTRACT_STATUS CC_XSRC_CONTRACT_STATUS,
PN.PERSON_NAME_ID PN_PERSON_NAME_ID,
PN.PREFIX_NAME_TP_CD PN_PREFIX_NAME_TP_CD,
PN.PREFIX_DESC PN_PREFIX_DESC,
PN.NAME_USAGE_TP_CD PN_NAME_USAGE_TP_CD,
PN.GIVEN_NAME_ONE PN_GIVEN_NAME_ONE,
PN.GIVEN_NAME_TWO PN_GIVEN_NAME_TWO,
PN.GIVEN_NAME_THREE PN_GIVEN_NAME_THREE,
PN.GIVEN_NAME_FOUR PN_GIVEN_NAME_FOUR,
PN.LAST_NAME PN_LAST_NAME,
PN.GENERATION_TP_CD PN_GENERATION_TP_CD,
PN.SUFFIX_DESC PN_SUFFIX_DESC,
PN.START_DT PN_START_DT,
PN.END_DT PN_END_DT,
PN.CONT_ID PN_CONT_ID,
PN.USE_STANDARD_IND PN_USE_STANDARD_IND,
PN.LAST_UPDATE_DT PN_LAST_UPDATE_DT,
PN.LAST_UPDATE_USER PN_LAST_UPDATE_USER,
PN.LAST_UPDATE_TX_ID PN_LAST_UPDATE_TX_ID,
PN.LAST_USED_DT PN_LAST_USED_DT,
PN.LAST_VERIFIED_DT PN_LAST_VERIFIED_DT,
PN.SOURCE_IDENT_TP_CD PN_SOURCE_IDENT_TP_CD
FROM PERSONNAME PN,
CONTRACTROLE CR,
CONTRACTCOMPONENT CC
WHERE
UPPER (PN.LAST_NAME) LIKE 'WILLIAM' || '%'
AND PN.NAME_USAGE_TP_CD = 1
AND PN.CONT_ID = CR.CONT_ID
AND CR.CONTR_COMPONENT_ID = CC.CONTR_COMPONENT_ID
AND NVL (PN.END_DT, LOCALTIMESTAMP) >= LOCALTIMESTAMP
AND NVL (CR.END_DT, LOCALTIMESTAMP) >= LOCALTIMESTAMP
AND CC.XLOB_TP_CD BETWEEN 1 AND 7
AND CC.XARCHIVED_IND = 'N'
AND ROWNUM <= 201) T,
CONTACT C,
PERSON P,
IDENTIFIER I,
CONTRACT CT,
XADDRESS XA,
XCONTACTMETHOD XM
WHERE T.CR_CONT_ID = C.CONT_ID
AND T.CR_CONT_ID = P.CONT_ID
AND T.CR_CONT_ID = I.CONT_ID
AND NVL (I.END_DT, LOCALTIMESTAMP) >= LOCALTIMESTAMP
AND T.CR_XCONTRACT_ID = CT.CONTRACT_ID(+)
AND T.CR_CONTR_COMPONENT_ID = XA.INSTANCE_PK(+)
AND XA.ENTITY_NAME(+) = 'CONTRACTCOMPONENT'
AND NVL (XA.END_DT(+), LOCALTIMESTAMP) >= LOCALTIMESTAMP
AND T.CR_CONTR_COMPONENT_ID = XM.INSTANCE_PK(+)
AND XM.ENTITY_NAME(+) = 'CONTRACTCOMPONENT'
AND NVL (XM.END_DT(+), LOCALTIMESTAMP) >= LOCALTIMESTAMP;

Help on SQL Tuning

Asim, July 29, 2007 - 5:42 pm UTC

Hi Tom,
I know you are busy, just wanted to check with you if you could find sometime to look at the problem above?

Thanks,
Asim
Tom Kyte
July 30, 2007 - 5:22 pm UTC

I don't see any problems above.

I see a big query, I see a query so big, I cannot even see it all.

Help on SQL Tuning

Asim, July 31, 2007 - 10:05 am UTC

Hi Tom,
Problem is the query is just hanging while doing wild card search for above big big query.

Here is the explain plan for a wild card search in the same query - last_name as 'V%' - 

Execution Plan
----------------------------------------------------------
Plan hash value: 2257075102

--------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                     | Name               | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     | Pstart| Pstop |
--------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                              |                    |   219 |   445K|       |  9124K  (1)| 30:24:52 |       |       |
|   1 |  NESTED LOOPS OUTER                           |                    |   219 |   445K|       |  9124K  (1)| 30:24:52 |       |       |
|   2 |   NESTED LOOPS                                |                    |   211 |   404K|       |  9123K  (1)| 30:24:47 |       |       |
|   3 |    NESTED LOOPS OUTER                         |                    |   204 |   374K|       |  9123K  (1)| 30:24:42 |       |       |
|   4 |     NESTED LOOPS                              |                    |   204 |   357K|       |  9123K  (1)| 30:24:40 |       |       |
|   5 |      NESTED LOOPS OUTER                       |                    |   202 |   335K|       |  9122K  (1)| 30:24:35 |       |       |
|   6 |       NESTED LOOPS                            |                    |   201 |   299K|       |  9122K  (1)| 30:24:30 |       |       |
|   7 |        VIEW                                   |                    |   201 |   268K|       |  9122K  (1)| 30:24:25 |       |       |
|*  8 |         COUNT STOPKEY                         |                    |       |       |       |            |          |       |       |
|   9 |          NESTED LOOPS                         |                    |   193K|    54M|       |  9122K  (1)| 30:24:25 |       |       |
|* 10 |           HASH JOIN                           |                    |   193K|    34M|    21M|  8761K  (1)| 29:12:19 |       |       |
|  11 |            PARTITION RANGE ALL                |                    |   193K|    19M|       |  3739K  (1)| 12:27:49 |     1 |    27 |
|  12 |             PARTITION HASH ALL                |                    |   193K|    19M|       |  3739K  (1)| 12:27:49 |     1 |     8 |
|* 13 |              TABLE ACCESS BY LOCAL INDEX ROWID| PERSONNAME         |   193K|    19M|       |  3739K  (1)| 12:27:49 |     1 |   216 |
|* 14 |               INDEX RANGE SCAN                | X1PERSONNAME       |  3866K|       |       |  3767   (4)| 00:00:46 |     1 |   216 |
|  15 |            PARTITION HASH ALL                 |                    |  4851K|   388M|       |  4999K  (1)| 16:39:52 |     1 |   128 |
|  16 |             TABLE ACCESS BY LOCAL INDEX ROWID | CONTRACTROLE       |  4851K|   388M|       |  4999K  (1)| 16:39:52 |     1 |   128 |
|* 17 |              INDEX FULL SCAN                  | I2_CONTRACTROLE    |  4851K|       |       |   167K (14)| 00:33:30 |     1 |   128 |
|* 18 |           TABLE ACCESS BY GLOBAL INDEX ROWID  | CONTRACTCOMPONENT  |     1 |   104 |       |     2   (0)| 00:00:01 | ROWID | ROWID |
|* 19 |            INDEX UNIQUE SCAN                  | P_CONTRACTCOMPONEN |     1 |       |       |     1   (0)| 00:00:01 |       |       |
|  20 |        TABLE ACCESS BY GLOBAL INDEX ROWID     | PERSON             |     1 |   157 |       |     2   (0)| 00:00:01 | ROWID | ROWID |
|* 21 |         INDEX UNIQUE SCAN                     | P_PERSON           |     1 |       |       |     1   (0)| 00:00:01 |       |       |
|  22 |       PARTITION HASH ITERATOR                 |                    |     1 |   176 |       |     2   (0)| 00:00:01 |   KEY |   KEY |
|  23 |        TABLE ACCESS BY LOCAL INDEX ROWID      | XADDRESS           |     1 |   176 |       |     2   (0)| 00:00:01 |   KEY |   KEY |
|* 24 |         INDEX RANGE SCAN                      | X1XADDRESS         |     1 |       |       |     1   (0)| 00:00:01 |   KEY |   KEY |
|  25 |      TABLE ACCESS BY GLOBAL INDEX ROWID       | CONTACT            |     1 |    89 |       |     2   (0)| 00:00:01 | ROWID | ROWID |
|* 26 |       INDEX UNIQUE SCAN                       | P_CONTACT          |     1 |       |       |     1   (0)| 00:00:01 |       |       |
|  27 |     PARTITION HASH ITERATOR                   |                    |     1 |    86 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
|  28 |      TABLE ACCESS BY LOCAL INDEX ROWID        | CONTRACT           |     1 |    86 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
|* 29 |       INDEX UNIQUE SCAN                       | P_CONTRACT         |     1 |       |       |     0   (0)| 00:00:01 |   KEY |   KEY |
|  30 |    PARTITION HASH ITERATOR                    |                    |     1 |    87 |       |     2   (0)| 00:00:01 |   KEY |   KEY |
|  31 |     TABLE ACCESS BY LOCAL INDEX ROWID         | IDENTIFIER         |     1 |    87 |       |     2   (0)| 00:00:01 |   KEY |   KEY |
|* 32 |      INDEX RANGE SCAN                         | I2_IDENTIFIER      |     1 |       |       |     1   (0)| 00:00:01 |   KEY |   KEY |
|  33 |   PARTITION HASH ITERATOR                     |                    |     1 |   120 |       |     2   (0)| 00:00:01 |   KEY |   KEY |
|  34 |    TABLE ACCESS BY LOCAL INDEX ROWID          | XCONTACTMETHOD     |     1 |   120 |       |     2   (0)| 00:00:01 |   KEY |   KEY |
|* 35 |     INDEX RANGE SCAN                          | X2XCONTACTMETHOD   |     1 |       |       |     1   (0)| 00:00:01 |   KEY |   KEY |
--------------------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   8 - filter(ROWNUM<=201)
  10 - access("PN"."CONT_ID"="CR"."CONT_ID")
  13 - filter(NVL("PN"."END_DT",LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  14 - access(UPPER("LAST_NAME") LIKE 'V%' AND "PN"."NAME_USAGE_TP_CD"=1)
       filter(UPPER("LAST_NAME") LIKE 'V%' AND "PN"."NAME_USAGE_TP_CD"=1)
  17 - filter(NVL("CR"."END_DT",LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  18 - filter("CC"."XARCHIVED_IND"='N' AND "CC"."XLOB_TP_CD">=1 AND "CC"."XLOB_TP_CD"<=7)
  19 - access("CR"."CONTR_COMPONENT_ID"="CC"."CONTR_COMPONENT_ID")
  21 - access("T"."CR_CONT_ID"="P"."CONT_ID")
  24 - access("T"."CR_CONTR_COMPONENT_ID"="XA"."INSTANCE_PK"(+) AND "XA"."ENTITY_NAME"(+)='CONTRACTCOMPONENT')
       filter(NVL("XA"."END_DT"(+),LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  26 - access("T"."CR_CONT_ID"="C"."CONT_ID")
  29 - access("T"."CR_XCONTRACT_ID"="CT"."CONTRACT_ID"(+))
  32 - access("T"."CR_CONT_ID"="I"."CONT_ID")
       filter(NVL("I"."END_DT",LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  35 - access("T"."CR_CONTR_COMPONENT_ID"="XM"."INSTANCE_PK"(+) AND "XM"."ENTITY_NAME"(+)='CONTRACTCOMPONENT')
       filter(NVL("XM"."END_DT"(+),LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))

SQL> 


We tried to separate the personname table query above in "WITH TMP AS" as below, and now the query takes more time when it needs to return more number of records such as 1440 records or 1660 records.


with tmp as (select /*+ INDEX(PERSONNAME X1PERSONNAME) */      
 c1, c2, etc,
     FROM PERSONNAME 
     WHERE 
     UPPER (LAST_NAME) LIKE 'SMITH' || '%' 
     AND ROWNUM <= 301)
SELECT /*+ INDEX(XA X1XADDRESS) INDEX(XM X2XCONTACTMETHOD) INDEX(C P_CONTACT) INDEX(CT P_CONTRACT) 
INDEX(I I2_IDENTIFIER)*/  c3, c4, etc.
     FROM 
     (SELECT /*+ INDEX(PN X1PERSONNAME) INDEX(CR I2_CONTRACTROLE) INDEX(CC P_CONTRACTCOMPONEN)*/  
c5, c6, etc.
     FROM 
     CONTRACTROLE CR,
     CONTRACTCOMPONENT CC,
     TMP 
     WHERE 
         TMP.PN_CONT_ID = CR.CONT_ID 
     AND CR.CONTR_COMPONENT_ID = CC.CONTR_COMPONENT_ID 
     AND ROWNUM <= 201) T,
     CONTACT C,
     PERSON P,
     IDENTIFIER I,
     CONTRACT CT,
     XADDRESS XA,
     XCONTACTMETHOD XM 
     WHERE T.CR_CONT_ID = C.CONT_ID 
     AND T.CR_CONT_ID = P.CONT_ID 
     AND T.CR_CONT_ID = I.CONT_ID;


Is it the number of records returned from the sql is taking most of the time? 

Explain plan for "WITH TMP AS..."
-------------------------------------------
Execution Plan
----------------------------------------------------------
Plan hash value: 3495887530

-----------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                    | Name               | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                             |                    |   219 |   445K|   225K  (4)| 00:45:10 |       |       |
|   1 |  NESTED LOOPS OUTER                          |                    |   219 |   445K|   225K  (4)| 00:45:10 |       |       |
|   2 |   NESTED LOOPS                               |                    |   211 |   404K|   225K  (4)| 00:45:05 |       |       |
|   3 |    NESTED LOOPS OUTER                        |                    |   204 |   374K|   224K  (4)| 00:45:00 |       |       |
|   4 |     NESTED LOOPS                             |                    |   204 |   357K|   224K  (4)| 00:44:58 |       |       |
|   5 |      NESTED LOOPS OUTER                      |                    |   202 |   335K|   224K  (4)| 00:44:53 |       |       |
|   6 |       NESTED LOOPS                           |                    |   201 |   299K|   223K  (4)| 00:44:48 |       |       |
|   7 |        VIEW                                  |                    |   201 |   268K|   223K  (4)| 00:44:43 |       |       |
|*  8 |         COUNT STOPKEY                        |                    |       |       |            |          |       |       |
|   9 |          NESTED LOOPS                        |                    |   301 |   134K|   223K  (4)| 00:44:43 |       |       |
|  10 |           NESTED LOOPS                       |                    |   301 |   103K|   222K  (4)| 00:44:36 |       |       |
|* 11 |            VIEW                              |                    |   301 | 80668 |   184K  (5)| 00:36:49 |       |       |
|* 12 |             COUNT STOPKEY                    |                    |       |       |            |          |       |       |
|  13 |              PARTITION RANGE ALL             |                    |  3866K|   387M|   184K  (5)| 00:36:49 |     1 |    27 |
|  14 |               PARTITION HASH ALL             |                    |  3866K|   387M|   184K  (5)| 00:36:49 |     1 |     8 |
|* 15 |                TABLE ACCESS FULL             | PERSONNAME         |  3866K|   387M|   184K  (5)| 00:36:49 |     1 |   216 |
|  16 |            PARTITION HASH ALL                |                    |     1 |    84 |   129   (0)| 00:00:02 |     1 |   128 |
|  17 |             TABLE ACCESS BY LOCAL INDEX ROWID| CONTRACTROLE       |     1 |    84 |   129   (0)| 00:00:02 |     1 |   128 |
|* 18 |              INDEX RANGE SCAN                | I2_CONTRACTROLE    |     1 |       |   128   (0)| 00:00:02 |     1 |   128 |
|* 19 |           TABLE ACCESS BY GLOBAL INDEX ROWID | CONTRACTCOMPONENT  |     1 |   104 |     2   (0)| 00:00:01 | ROWID | ROWID |
|* 20 |            INDEX UNIQUE SCAN                 | P_CONTRACTCOMPONEN |     1 |       |     1   (0)| 00:00:01 |       |       |
|  21 |        TABLE ACCESS BY GLOBAL INDEX ROWID    | PERSON             |     1 |   157 |     2   (0)| 00:00:01 | ROWID | ROWID |
|* 22 |         INDEX UNIQUE SCAN                    | P_PERSON           |     1 |       |     1   (0)| 00:00:01 |       |       |
|  23 |       PARTITION HASH ITERATOR                |                    |     1 |   176 |     2   (0)| 00:00:01 |   KEY |   KEY |
|  24 |        TABLE ACCESS BY LOCAL INDEX ROWID     | XADDRESS           |     1 |   176 |     2   (0)| 00:00:01 |   KEY |   KEY |
|* 25 |         INDEX RANGE SCAN                     | X1XADDRESS         |     1 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
|  26 |      TABLE ACCESS BY GLOBAL INDEX ROWID      | CONTACT            |     1 |    89 |     2   (0)| 00:00:01 | ROWID | ROWID |
|* 27 |       INDEX UNIQUE SCAN                      | P_CONTACT          |     1 |       |     1   (0)| 00:00:01 |       |       |
|  28 |     PARTITION HASH ITERATOR                  |                    |     1 |    86 |     1   (0)| 00:00:01 |   KEY |   KEY |
|  29 |      TABLE ACCESS BY LOCAL INDEX ROWID       | CONTRACT           |     1 |    86 |     1   (0)| 00:00:01 |   KEY |   KEY |
|* 30 |       INDEX UNIQUE SCAN                      | P_CONTRACT         |     1 |       |     0   (0)| 00:00:01 |   KEY |   KEY |
|  31 |    PARTITION HASH ITERATOR                   |                    |     1 |    87 |     2   (0)| 00:00:01 |   KEY |   KEY |
|  32 |     TABLE ACCESS BY LOCAL INDEX ROWID        | IDENTIFIER         |     1 |    87 |     2   (0)| 00:00:01 |   KEY |   KEY |
|* 33 |      INDEX RANGE SCAN                        | I2_IDENTIFIER      |     1 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
|  34 |   PARTITION HASH ITERATOR                    |                    |     1 |   120 |     2   (0)| 00:00:01 |   KEY |   KEY |
|  35 |    TABLE ACCESS BY LOCAL INDEX ROWID         | XCONTACTMETHOD     |     1 |   120 |     2   (0)| 00:00:01 |   KEY |   KEY |
|* 36 |     INDEX RANGE SCAN                         | X2XCONTACTMETHOD   |     1 |       |     1   (0)| 00:00:01 |   KEY |   KEY |
-----------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   8 - filter(ROWNUM<=201)
  11 - filter(NVL("TMP"."PN_END_DT",LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  12 - filter(ROWNUM<=301)
  15 - filter(UPPER("LAST_NAME") LIKE 'V%' AND "NAME_USAGE_TP_CD"=1)
  18 - access("TMP"."PN_CONT_ID"="CR"."CONT_ID")
       filter(NVL("CR"."END_DT",LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  19 - filter("CC"."XARCHIVED_IND"='N' AND "CC"."XLOB_TP_CD">=1 AND "CC"."XLOB_TP_CD"<=7)
  20 - access("CR"."CONTR_COMPONENT_ID"="CC"."CONTR_COMPONENT_ID")
  22 - access("T"."CR_CONT_ID"="P"."CONT_ID")
  25 - access("T"."CR_CONTR_COMPONENT_ID"="XA"."INSTANCE_PK"(+) AND "XA"."ENTITY_NAME"(+)='CONTRACTCOMPONENT')
       filter(NVL("XA"."END_DT"(+),LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  27 - access("T"."CR_CONT_ID"="C"."CONT_ID")
  30 - access("T"."CR_XCONTRACT_ID"="CT"."CONTRACT_ID"(+))
  33 - access("T"."CR_CONT_ID"="I"."CONT_ID")
       filter(NVL("I"."END_DT",LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))
  36 - access("T"."CR_CONTR_COMPONENT_ID"="XM"."INSTANCE_PK"(+) AND "XM"."ENTITY_NAME"(+)='CONTRACTCOMPONENT')
       filter(NVL("XM"."END_DT"(+),LOCALTIMESTAMP(6))>=LOCALTIMESTAMP(6))

SQL>

==========================================================

Any comments????

Thanks,
Asim


Tom Kyte
August 02, 2007 - 9:59 am UTC

no comments other than it is NOT hanging, it is definitely not hanging.

It is taking longer than you anticipated perhaps, but it it not hanging.


this is too much stuff to look at here, yet it is insufficient to diagnose any further as well - you have hints, you have tables, you have indexes - all of which I'm not aware of. Not really able to deal with this in a review/followup.

Asim ...

Gabe, August 02, 2007 - 11:31 am UTC

The query you've included is incomplete (missing join conditions) and doesn't match the plan shown after. You have to be precise with these things.

This hint ... /*+ INDEX(PERSONNAME X1PERSONNAME) */ it is likely wrong for this predicate ... UPPER (LAST_NAME) LIKE 'SMITH' || '%' ... in fact, losing those hints should be the first thing to do.

Joining 3 tables and keeping the first 200 rows is not the same as keeping 300 rows from one of them, joining to the other 2 and then keeping 200 from the result.

You have partitioned objects all over the place. Maybe try to go back to the original query and see if you can take advantage of partition elimination somehow ...

Your opinon sought on cbo/stats/partitioned table issue.

Manny, August 03, 2007 - 11:00 am UTC

Tom, if you have minute...
Not seeking a solution, just your thoughts.

I am gathering stats/executing query on a partiton of a "reporting" table nicely indexed with bitmaps etc.

The table does not have global stats.

I gather partition level stats...

begin
DBMS_STATS.GATHER_TABLE_STATS (
ownname => user,
tabname => 'otr_order_insts_rpt',
estimate_percent => 50,
partname => 'P200707',
granularity => 'PARTITION',
method_opt => 'FOR ALL INDEXED COLUMNS SIZE AUTO',
DEGREE => 2,
CASCADE => TRUE,
no_invalidate => FALSE);
end;
/

I get the best response time for a query on this table with the following hint: /*+ index_combine( oi otr_order_insts_rpt_0pk idx_otr_order_insts_rpt_8ak ) */

Hint results in: Range scan on primary key + bitmap conversion from rowid of PK is being bitmap minused with the other bitmap index: 8ak.

With estimate_percent at 50, the cbo will *not* do what my index_combine hint does for me.

Infact, raising estimate percent from 10 to 50 did not change the plan at all?

Shared pool was flushed so as to reduce chance of cached plan being used after stats gathering.

Also played around with optimizer_index_cost_adj and mbrc - with no success.

I don't want to use the hint because the query is dynamically generated through an app.

What should be my next steps: Take global stats? Keep increasing estimate percent?

Just in case it would be easier for you to understand i am listing the query + good and bad plans:

select /* + index_combine( oi otr_order_insts_rpt_0pk idx_otr_order_insts_rpt_8ak ) */
oi.* from otradmin.otr_order_insts_rpt oi
where oi.trade_date = '20-JUN-2007'
and oi.controller_party_label = 'GEB'
and oi.originator_party_label <> oi.controller_party_label

Bad Plan exported from sql developer:

Note: the third to last line of the 'good plan' listed last is the key - the index combine hint entails use of the primary key on the table.

"Optimizer" "Cost" "Cardinality" "Bytes" "Partition Start" "Partition Stop" "Partition Id" "ACCESS PREDICATES" "FILTER PREDICATES"
"SELECT STATEMENT" "ALL_ROWS" "3" "5137" "2337335" "" "" "" "" ""
"PARTITION RANGE(SINGLE)" "" "3" "5137" "2337335" "3" "3" "1" "" ""
"TABLE ACCESS(BY LOCAL INDEX ROWID) OTRADMIN.OTR_ORDER_INSTS_RPT" "ANALYZED" "3" "5137" "2337335" "3" "3" "2" "" ""OI"."TRADE_DATE"=TO_DATE('2007-06-20 00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND "OI"."ORIGINATOR_PARTY_LABEL"<>"OI"."CONTROLLER_PARTY_LABEL""
"BITMAP CONVERSION(TO ROWIDS)" "" "" "" "" "" "" "" "" ""
"BITMAP MINUS" "" "" "" "" "" "" "" "" ""
"BITMAP MINUS" "" "" "" "" "" "" "" "" ""
"BITMAP INDEX(SINGLE VALUE) OTRADMIN.IDX_OTR_ORDER_INSTS_RPT_4AK" "" "" "" "" "3" "3" "6" ""OI"."CONTROLLER_PARTY_LABEL"='GEB'" ""
"BITMAP INDEX(SINGLE VALUE) OTRADMIN.IDX_OTR_ORDER_INSTS_RPT_8AK" "" "" "" "" "3" "3" "7" ""OI"."ORIGINATOR_PARTY_LABEL"='GEB'" ""
"BITMAP INDEX(SINGLE VALUE) OTRADMIN.IDX_OTR_ORDER_INSTS_RPT_8AK" "" "" "" "" "3" "3" "8" ""OI"."ORIGINATOR_PARTY_LABEL" IS NULL" ""


And the good plan:

"Optimizer" "Cost" "Cardinality" "Bytes" "Partition Start" "Partition Stop" "Partition Id" "ACCESS PREDICATES" "FILTER PREDICATES"
"SELECT STATEMENT" "ALL_ROWS" "2776" "5137" "2337335" "" "" "" "" ""
"PARTITION RANGE(SINGLE)" "" "2776" "5137" "2337335" "3" "3" "1" "" ""
"TABLE ACCESS(BY LOCAL INDEX ROWID) OTRADMIN.OTR_ORDER_INSTS_RPT" "ANALYZED" "2776" "5137" "2337335" "3" "3" "2" "" ""OI"."ORIGINATOR_PARTY_LABEL"<>"OI"."CONTROLLER_PARTY_LABEL""
"BITMAP CONVERSION(TO ROWIDS)" "" "" "" "" "" "" "" "" ""
"BITMAP AND" "" "" "" "" "" "" "" "" ""
"BITMAP MINUS" "" "" "" "" "" "" "" "" ""
"BITMAP MINUS" "" "" "" "" "" "" "" "" ""
"BITMAP INDEX(SINGLE VALUE) OTRADMIN.IDX_OTR_ORDER_INSTS_RPT_4AK" "" "" "" "" "3" "3" "7" ""OI"."CONTROLLER_PARTY_LABEL"='GEB'" ""
"BITMAP INDEX(SINGLE VALUE) OTRADMIN.IDX_OTR_ORDER_INSTS_RPT_8AK" "" "" "" "" "3" "3" "8" ""OI"."ORIGINATOR_PARTY_LABEL"='GEB'" ""
"BITMAP INDEX(SINGLE VALUE) OTRADMIN.IDX_OTR_ORDER_INSTS_RPT_8AK" "" "" "" "" "3" "3" "9" ""OI"."ORIGINATOR_PARTY_LABEL" IS NULL" ""
"BITMAP CONVERSION(FROM ROWIDS)" "" "" "" "" "" "" "" "" ""
"SORT(ORDER BY)" "" "" "" "" "" "" "" "" ""
"INDEX(RANGE SCAN) OTRADMIN.OTR_ORDER_INSTS_RPT_0PK" "ANALYZED" "88" "" "" "3" "3" "12" ""OI"."TRADE_DATE"=TO_DATE('2007-06-20 00:00:00', 'yyyy-mm-dd hh24:mi:ss')" ""OI"."TRADE_DATE"=TO_DATE('2007-06-20 00:00:00', 'yyyy-mm-dd hh24:mi:ss')"




Performance tuning options

NewUser, August 10, 2007 - 2:55 pm UTC

Tom, I am in a process of learning how to optimize queries/scripts.

I have a pl/sql :

declare
cursor c1 is select * from table;
cursor c2(tableA_id in integer) is select * from table b where id=tablea_id;
begin
for i in c1
loop
for j in c2(i.id)
loop
..Some processing..
end loop;
end loop;
end;


and an SQL Query:

select a.* ,b.*
from table A,
table B
where a.id=b.id;

{It's not that simple query though}

I want to run some statistics between these two and see which one is performing better. Can you suggest an approach as to how I can measure performance between these two[Please consider me a novice in this field and respond]?

I am not asking you to tune it , but suggest an apporach whether TKProf / Explain Plan etc.. and how??

Thanks,
Tom Kyte
August 14, 2007 - 3:07 pm UTC

never write code when you don't have to.

you never want to write your own nested loops join.

just code SQL.

If you can do it in a single sql statment - DO IT.

basic SQL

A reader, August 17, 2007 - 7:02 am UTC

Hi Tom,

I have been trying to improve the performance of the query below,
I have tried using inner joins on the 10 tables and it does improve slightly.
My problem is I am relatively new to DB's and Oracle ( a greenhorn you might say over yonder) and I can only keep things simple due to a lack of knowledge.

Am I missing something glaringly obvious or am I 'barking up the wrong tree'?
Any help/tips would be greatly appreciated.

Many thanks,
Jenny.

SELECT
PROCESS,
FAMILY,
Status,
Count(Status) AS PointCount
FROM
(
SELECT Process,
PRTF.FAMILY,
PRTF.FAMILY_ID,
CASE
WHEN (Deviation > DSGN_LSL) AND (Deviation < DSGN_USL) THEN 'P'
ELSE 'F'
END Status
FROM PROCESS PRS,
PART PRT, FAMILY PRTF,
INSP_STAGE ISPS,
TAPE TPE,
RES_FILE RESF,
DSGN_GAUGE DSGNG,
Characteristic CTC,
GaugeType GT,
DSGN_GAUGE_RES DSGNGR,
POINT PNT
WHERE PRT.PROCESS_ID = PRS.PROCESS_ID
AND PRTF.FAMILY_ID = PRT.FAMILY_ID
AND ISPS.PART_ID = PRT.PART_ID
AND TPE.INSP_STAGE_ID = ISPS.INSP_STAGE_ID
AND RESF.TAPE_ID = TPE.TAPE_ID
AND DSGNG.TAPE_ID = TPE.TAPE_ID
AND CTC.CharacteristicID = DSGNG.CharacteristicID
AND GT.GaugeTypeID = CTC.GaugeTypeID
AND DSGNGR.RES_FILE_ID = RESF.RES_FILE_ID
AND PNT.DSGN_GAUGE_RES_ID = DSGNGR.DSGN_GAUGE_RES_ID
AND PRTF.FAMILY_ID > 218
)
GROUP BY PROCESS, FAMILY, Status
ORDER BY PROCESS;

151 rows selected

Plan hash value: 2649833928
-------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
-------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1817K | 194M | | 47616 (2 | 00:09:32 |
| 1 | SORT GROUP BY | | 1817K | 194M | 417M | 47616 (2 | 00:09:32 |
|* 2 | HASH JOIN | | 1817K | 194M | | 1241 (8 | 00:00:15 |
|* 3 | TABLE ACCESS FULL | CHARACTERISTIC | 2338 | | 3 (0) | 00:00:01 |
|* 4 | HASH JOIN | | 1817K | 181M | | 1207 (6 | 00:00:15 |
| 5 | TABLE ACCESS FULL | DSGN_GAUGE | 26383 | 412K | | 104 (2) | 00:00:02 |
|* 6 | HASH JOIN | | 83421 | 7250K | 1072 (4 | 00:00:13 |
|* 7 | HASH JOIN | | 8306 | 616K | | 209 (4) | 00:00:03 |
|* 8 | HASH JOIN | | 379 | 25393 | | 35 (9) 00:00:01 |
|* 9 | HASH JOIN | | 215 | 12685 | | 19 (11) | 00:00:01 |
|* 10 | HASH JOIN | | 165 | 8415 | 13 (8) | 00:00:01 |
| 11 | TABLE ACCESS BY INDEX ROWID | PROCESS | 1 | 19 | | 1 (0) | 00:00:01 |
| 12 | NESTED LOOPS | | 140 | 6020 | | 10 (10) 00:00:01 |
| 13 | NESTED LOOPS | | 140 | 3360 | | 9 (12) | 00:00:01 |
|* 14 | TABLE ACCESS FULL | PART | 436 | 4796 | | 7 (0) | 00:00:01 |
| 15 | TABLE ACCESS BY INDEX ROWID| FAMILY | 1 | 13 | | 1 (0) 00:01 |
|* 16 | INDEX RANGE SCAN | FAMILY_ID | 1 | | | 0 (0) | 00:00:01 |
|* 17 | INDEX RANGE SCAN | PROCESS_ID_1 | 1 | | | 0 (0) | 00:00:01 |
| 18 | TABLE ACCESS FULL | INSP_STAGE | 932 | 7456 | | 3 (0) | 00:00:01 |
| 19 | TABLE ACCESS FULL | TAPE | 1211 | 9688 | | 5 (0) | 00:00:01 |
| 20 | VIEW | index$_join$_007 | 2139 | 17112 | | 16 (7) | 00: 00:01 |
|* 21 | HASH JOIN | | | | | | |
| 22 | INDEX FAST FULL SCAN | ID_2 | 2139 | 17112 | | 8 (0) | 00:00:01 |
| 23 | INDEX FAST FULL SCAN | TAPE_ID_2 | 2139 | 17112 | | 8 (0) | 00:00:01 |
| 24 | TABLE ACCESS FULL | DSGN_GAUGE_RES | 46829 | 411 K | | 172 (| 00:00:03 |
| 25 | TABLE ACCESS FULL | POINT | 470K | 5970K | | 855 ( | 00:00:11 |
-------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("DSGNG"."CHARACTERISTICID"="CTC"."CHARACTERISTICID")
3 - filter("CTC"."GAUGETYPEID" IS NOT NULL)
4 - access("DSGNG"."TAPE_ID"="TPE"."TAPE_ID")
6 - access("PNT"."DSGN_GAUGE_RES_ID"="DSGNGR"."DSGN_GAUGE_RES_ID")
7 - access("DSGNGR"."RES_FILE_ID"="RESF"."RES_FILE_ID")
8 - access("RESF"."TAPE_ID"="TPE"."TAPE_ID")
9 - access("TPE"."INSP_STAGE_ID"="ISPS"."INSP_STAGE_ID")
10 - access("ISPS"."PART_ID"="PRT"."PART_ID")
14 - filter("PRT"."FAMILY_ID">218)
16 - access("PRTF"."FAMILY_ID"="PRT"."FAMILY_ID")
filter("PRTF"."FAMILY_ID">218)
17 - access("PRT"."PROCESS_ID"="PRS"."PROCESS_ID")
21 - access(ROWID=ROWID)

Statistics
-----------------------------------------------------------
96,733ms elapsed

Tom Kyte
August 22, 2007 - 9:07 am UTC

it depends - what are your EXPECTATIONS of response time here.

Looks like almost every row in all tables will be processed (only predicate is family_id > 218) so full scans and hash joins is a good thing.

two sessions, two differents execution plans

juancarlosreyesp, August 17, 2007 - 3:31 pm UTC

Hi Tom, executing the same query on sqlplus and in another tool, I get different executions plans, one takes 10 seconds the other 4 minutes.

I checked v$sql_optimizer_env and everything is equal in both sessions.

The questions is what should I have to compare to know why
there are different executions plans?

I was think in v$sesstat, but I'm not sure if that's enough to get the whole picture.

Thank you :)
Tom Kyte
August 22, 2007 - 9:35 am UTC

tkprof them and show us the tkprofs.

they will turn out to be different queries, that I'm pretty sure of.

9i VS 10G

ali, August 27, 2007 - 2:02 pm UTC


Hi Tom,

The sql below runs in about 2 mins in 9.2.0.6.0, the same sql in 10g (10.2.0.2.0) with similar data volumes/environment/stats... takes more than 2 hrs to complete.

Please see below comparison from tkprof.
Any help is greatly appreciated.
thanks.

----9i....

SELECT SYSDATE AS DATENOW,
portf.shortname AS SHORTNAME,
secur.securityassetid AS CUSIP,
'Latest Yield more than 7 days old. Yield='||prcyl.yield||', Date = '||TO_CHAR(prcyl.priceyielddate,'MM/DD/YYYY')||'. Inv Typ
e = '||secur.securitytype AS DESCRIPTION
FROM pot portf,
pos postn,
smf secur,
price prcyl
WHERE portf.portfolioid = postn.portfolioid
AND postn.securityid = secur.securityid
AND postn.securityid = prcyl.securityid
AND (prcyl.yield IS NOT NULL OR prcyl.yield <> 0)
AND prcyl.priceyielddate = (SELECT MAX(priceyielddate)
FROM price
WHERE securityid = postn.securityid
AND TRUNC(priceyielddate) <= '16-jul-2007')
AND secur.securitytype IN ('DVR', 'WVR')
AND ROUND(to_date('16-jul-2007') - TRUNC(prcyl.priceyielddate)) > 7
AND postn.totalquantity > 0
AND portf.FUNDGROUPCODE = 'MUNI'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 3 58.80 133.64 50017 50166 0 18
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 5 58.80 133.64 50017 50166 0 18

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 365

Rows Row Source Operation
------- ---------------------------------------------------
18 NESTED LOOPS
78 HASH JOIN
8980 HASH JOIN
9129 HASH JOIN
35 TABLE ACCESS FULL pot
9146 INDEX FAST FULL SCAN XIDPSTN5 (object id 45837)
62168 VIEW
62168 SORT GROUP BY
5143974 INDEX FAST FULL SCAN SYS_C007654 (object id 45847)
2791787 TABLE ACCESS FULL price
18 TABLE ACCESS BY INDEX ROWID smf
78 INDEX UNIQUE SCAN SYS_C0011686 (object id 45899)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 3 0.00 0.00
db file sequential read 53 0.00 0.00
db file scattered read 1594 0.32 3.84
SQL*Net message from client 3 0.02 0.02
********************************************************************************



----10g....

SELECT SYSDATE AS DATENOW,
portf.shortname AS SHORTNAME,
secur.securityassetid AS CUSIP,
'Latest Yield more than 7 days old. Yield='||prcyl.yield||', Date = '||TO_CHAR(prcyl.priceyielddate,'MM/DD/YYYY')||'. Inv Typ
e = '||secur.securitytype AS DESCRIPTION
FROM pot portf,
pos postn,
smf secur,
price prcyl
WHERE portf.portfolioid = postn.portfolioid
AND postn.securityid = secur.securityid
AND postn.securityid = prcyl.securityid
AND (prcyl.yield IS NOT NULL OR prcyl.yield <> 0)
AND prcyl.priceyielddate = (SELECT MAX(priceyielddate)
FROM price
WHERE securityid = postn.securityid
AND TRUNC(priceyielddate) <= '16-jul-2007')
AND secur.securitytype IN ('DVR', 'WVR')
AND ROUND(to_date('16-jul-2007') - TRUNC(prcyl.priceyielddate)) > 7
AND postn.totalquantity > 0
AND portf.FUNDGROUPCODE = 'MUNI'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.53 0.52 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 4333.10 7945.31 41165 42339 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 4333.63 7945.84 41165 42339 0 0

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 33

Rows Row Source Operation
------- ---------------------------------------------------
0 FILTER (cr=42339 pr=41165 pw=2790 time=3650349967 us)
454887 HASH GROUP BY (cr=42339 pr=41165 pw=2790 time=3652934647 us)
265260705 HASH JOIN (cr=42339 pr=38375 pw=0 time=2441891156 us)
5695 TABLE ACCESS FULL smf (cr=626 pr=602 pw=0 time=50291 us)
1349842280 HASH JOIN (cr=41713 pr=37773 pw=0 time=4102337171 us)
2315752 HASH JOIN (cr=25198 pr=24734 pw=0 time=30178281 us)
9023 HASH JOIN (cr=58 pr=0 pw=0 time=37681 us)
35 TABLE ACCESS FULL pot (cr=7 pr=0 pw=0 time=647 us)
9040 INDEX FAST FULL SCAN XIDPSTN5 (cr=51 pr=0 pw=0 time=9321 us)(object id 11144)
2791783 TABLE ACCESS FULL price (cr=25140 pr=24734 pw=0 time=64224780 us)
5137973 INDEX FAST FULL SCAN SYS_C007654 (cr=16515 pr=13039 pw=0 time=61656242 us)(object id 11154)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 1 0.00 0.00
db file scattered read 2610 0.23 6.10
db file sequential read 227 0.01 0.29
direct path write temp 90 0.05 0.50
direct path read temp 90 0.01 0.07
SQL*Net message from client 1 0.02 0.02
********************************************************************************

Forced View

Prabhu, August 29, 2007 - 11:55 am UTC

Hi..Tom,

I have a small doubt, Please explain me with an example.

We can create a view without a base table or without a base table attributes is called as "Forced View".

But

What is the use ? which circumstances we want to create a forced view? can you explain me with a small example.

Tom Kyte
September 04, 2007 - 4:08 pm UTC

export uses it so it doesn't have to create things in any special order.

it can create views that cannot be compiled - since not everything they need might be in the database yet.

Ful tabe scan inspite of unique index

A reader, August 30, 2007 - 11:50 am UTC

Hi Tom,
Below is my code.
SELECT DISTINCT a.project_id, a.top_task_id, a.billing_assignment_id,
GREATEST (0,
(a.amount - SUM (dr.project_revenue_amount))
) amount
FROM apps.pa_draft_revenue_items dr,
apps.pa_cust_event_rdl_all erdl,
apps.pa_events e,
apps.pa_billing_assignments_all a,
apps.pa_projects_all pa--,
WHERE e.revenue_amount = dr.amount
AND dr.project_id = erdl.project_id
AND dr.draft_revenue_num = erdl.draft_revenue_num
AND dr.line_num = erdl.draft_revenue_item_line_num
AND erdl.event_num = e.event_num
AND erdl.request_id = e.request_id
AND erdl.project_id = e.project_id
AND erdl.task_id = e.task_id
AND e.attribute1 = a.attribute2
AND e.attribute2 = a.attribute3
AND e.attribute4 = a.attribute10
AND e.project_id = a.project_id
AND e.task_id = a.top_task_id
AND a.attribute_category = 'Custom Milestone Invoicing'
AND NVL (e.attribute5, e.billing_assignment_id) =
a.billing_assignment_id
AND e.project_id = pa.project_id
AND a.project_id = pa.project_id
AND PA.PROJECT_STATUS_CODE not in (Select PAS.PROJECT_STATUS_CODE
FROM PA_PROJECT_STATUSES PAS
WHERE PAS.PROJECT_STATUS_NAME IN ('Completed',
'Completed - Archived', 'Non Delivery Completed', 'Rejected', 'Duplicate') )
GROUP BY a.project_id, a.top_task_id, a.billing_assignment_id,
a.amount

this code is causing lot of performance issue. on table pa_events a full table scan is there, even though there is a unique index. can u help me this for better performance.

How to get old explain plan?

V@to, August 31, 2007 - 7:39 pm UTC

Hello,

Here is the parallel SQL that takes more than 6 hours. It used to finish just in 35 minutes three weeks ago. I see that Explain plan changed but i can't catch the reason.

Please advice how to get the old plan. Only thing i found is that during execution, query performs big sorts in temp space that causes huge amount of "direct path read temp".

SELECT a.call_id, a.subscriber_id, a.db_service_id, a.tariff_id,
       a.subscriber_business_type_id, a.subscriber_marketing_type_id,
       a.db_distance_band_id, a.time_band_id, a.time_id, a.duration_band_id,
       a.cell_id, a.equipment_id, a.roaming_id, a.gsm_method_id,
       a.cboss_call_type_id, a.a_number, a.b_number, a.a_number_original,
       a.b_number_original, a.call_date, a.etl_date, a.DURATION, a.imei,
       a.call_charge, a.interoper_charge, a.uplink, a.downlink,
       a.rounded_duration, a.gsm_payment_type_id, a.direction_type_id,
       a.call_charge_with_vat, a.service_id_2, a.call_type_id_2,
       a.account_typ
  FROM (SELECT /*+ parallel(c 4) parallel (d 4) */
               NVL (d.call_type_id, -99) AS db_call_type_id,
               NVL (d.service_id, -99) AS db_service_id,
               NVL (d.distance_band_id, -99) AS db_distance_band_id,
               ROW_NUMBER () OVER (PARTITION BY c.call_id, d.call_type_id ORDER BY LENGTH
                                              (d.check_digits) DESC NULLS LAST)
                                                              AS record_order,
               c.record_no, c.call_id, c.subscriber_id, c.service_id,
               c.tariff_id, c.subscriber_business_type_id,
               c.subscriber_marketing_type_id, c.gsm_payment_type_id,
               c.distance_band_id, c.time_band_id, c.time_id,
               c.duration_band_id, c.cell_id, c.equipment_id, c.roaming_id,
               c.gsm_method_id, c.cboss_call_type_id, c.a_number, c.b_number,
               c.a_number_original, c.b_number_original, c.call_date,
               c.etl_date, c.DURATION, c.rounded_duration, c.imei,
               c.call_charge, c.interoper_charge, c.uplink, c.downlink,
               c.service_id_2, c.call_type_id_2, c.call_charge_with_vat,
               c.direction_type_id, c.account_typ
          FROM (SELECT   /*+ parallel (e 4)  parallel (k 4)  */
                         k.master_source_system_value1
                                                  AS orga_call_type_src_value,
                         k.detail_dwh_id AS cboss_call_type_id, e.record_no,
                         e.call_id, e.subscriber_id, e.service_id,
                         e.tariff_id, e.subscriber_business_type_id,
                         e.subscriber_marketing_type_id,
                         e.gsm_payment_type_id, e.distance_band_id,
                         e.time_band_id, e.time_id, e.duration_band_id,
                         e.cell_id, e.equipment_id, e.roaming_id,
                         e.gsm_method_id, e.call_type_id, e.a_number,
                         e.b_number, e.a_number_original, e.b_number_original,
                         e.call_date, e.etl_date, e.DURATION,
                         e.rounded_duration, e.imei, e.call_charge,
                         e.interoper_charge, e.uplink, e.downlink,
                         e.service_id_2, e.call_type_id_2,
                         e.call_charge_with_vat, e.direction_type_id,
                         e.local_flag, e.account_typ
                    FROM dwh_adm_key_transformation k,
                         (SELECT *
                            FROM dwh_tmp_pre_calldetails_6_1
                           WHERE local_flag = 'INT') e
                   WHERE k.master_trans_src_sys_value1 = 374
                     AND k.source_system_id = 2
                     AND e.call_type_id_2 = k.master_dwh_id(+)
                ORDER BY e.call_id, e.call_type_id, b_number) c,
               (SELECT *
                  FROM dwh_dim_distance_band
                 WHERE local_flag = 'INT' AND NVL (gsm_method_id, 2) = 2) d
         WHERE c.cboss_call_type_id = d.call_type_id(+)
           AND c.gsm_method_id = NVL (d.gsm_method_id(+), 2)
           AND c.direction_type_id = TO_NUMBER (d.service_direction(+))
           AND NVL (c.b_number, -1) LIKE NVL (d.check_digits(+), -1) || '%') a
 WHERE a.record_order = 1


explain plan:
PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------

------------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name                        | Rows  | Bytes | Cost  | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |                             |  2590K|  1586M|   106K|       |       |
|   1 |  PX COORDINATOR                    |                             |       |       |       |       |       |
|   2 |   PX SEND QC (RANDOM)              | :TQ10004                    |  2590K|  1586M|   106K|       |       |
|   3 |    VIEW                            |                             |  2590K|  1586M|   106K|       |       |
|   4 |     WINDOW SORT PUSHED RANK        |                             |  2590K|  1573M|   106K|       |       |
|   5 |      PX RECEIVE                    |                             |  2590K|  1573M|   106K|       |       |
|   6 |       PX SEND HASH                 | :TQ10003                    |  2590K|  1573M|   106K|       |       |

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------
|   7 |        VIEW                        |                             |       |       |       |       |       |
|   8 |         WINDOW CHILD PUSHED RANK   |                             |  2590K|  1573M|   106K|       |       |
|   9 |          HASH JOIN RIGHT OUTER     |                             |  2590K|  1573M|  9895 |       |       |
|  10 |           PX RECEIVE               |                             |  5823 |   181K|    12 |       |       |
|  11 |            PX SEND BROADCAST       | :TQ10001                    |  5823 |   181K|    12 |       |       |
|  12 |             PX BLOCK ITERATOR      |                             |  5823 |   181K|    12 |       |       |
|  13 |              TABLE ACCESS FULL     | DWH_DIM_DISTANCE_BAND       |  5823 |   181K|    12 |       |       |
|  14 |           VIEW                     |                             |  2590K|  1494M|  9874 |       |       |
|  15 |            SORT ORDER BY           |                             |  2590K|   390M|  9874 |       |       |
|  16 |             PX RECEIVE             |                             |  2590K|   390M|  9799 |       |       |
|  17 |              PX SEND RANGE         | :TQ10002                    |  2590K|   390M|  9799 |       |       |

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------------------------------------
|  18 |               HASH JOIN            |                             |  2590K|   390M|  9799 |       |       |
|  19 |                PX RECEIVE          |                             |     3 |    66 |    63 |       |       |
|  20 |                 PX SEND BROADCAST  | :TQ10000                    |     3 |    66 |    63 |       |       |
|  21 |                  PX BLOCK ITERATOR |                             |     3 |    66 |    63 |       |       |
|  22 |                   TABLE ACCESS FULL| DWH_ADM_KEY_TRANSFORMATION  |     3 |    66 |    63 |       |       |
|  23 |                PX BLOCK ITERATOR   |                             |  7928K|  1028M|  9712 |     1 |     4 |
|  24 |                 TABLE ACCESS FULL  | DWH_TMP_PRE_CALLDETAILS_6_1 |  7928K|  1028M|  9712 |     1 |     4 |
------------------------------------------------------------------------------------------------------------------


Thank you in advance.

How to get old explain plan?

V@to, August 31, 2007 - 7:57 pm UTC

Hello,

Here is the parallel SQL that takes more than 6 hours. It used to finish just in 35 minutes three weeks ago. I see that Explain plan changed but i can't catch the reason.

Please advice how to get the old plan. Only thing i found is that during execution, query performs big sorts in temp space that causes huge amount of "direct path read temp".

SELECT a.call_id, a.subscriber_id, a.db_service_id, a.tariff_id,
       a.subscriber_business_type_id, a.subscriber_marketing_type_id,
       a.db_distance_band_id, a.time_band_id, a.time_id, a.duration_band_id,
       a.cell_id, a.equipment_id, a.roaming_id, a.gsm_method_id,
       a.cboss_call_type_id, a.a_number, a.b_number, a.a_number_original,
       a.b_number_original, a.call_date, a.etl_date, a.DURATION, a.imei,
       a.call_charge, a.interoper_charge, a.uplink, a.downlink,
       a.rounded_duration, a.gsm_payment_type_id, a.direction_type_id,
       a.call_charge_with_vat, a.service_id_2, a.call_type_id_2,
       a.account_typ
  FROM (SELECT /*+ parallel(c 4) parallel (d 4) */
               NVL (d.call_type_id, -99) AS db_call_type_id,
               NVL (d.service_id, -99) AS db_service_id,
               NVL (d.distance_band_id, -99) AS db_distance_band_id,
               ROW_NUMBER () OVER (PARTITION BY c.call_id, d.call_type_id ORDER BY LENGTH
                                              (d.check_digits) DESC NULLS LAST)
                                                              AS record_order,
               c.record_no, c.call_id, c.subscriber_id, c.service_id,
               c.tariff_id, c.subscriber_business_type_id,
               c.subscriber_marketing_type_id, c.gsm_payment_type_id,
               c.distance_band_id, c.time_band_id, c.time_id,
               c.duration_band_id, c.cell_id, c.equipment_id, c.roaming_id,
               c.gsm_method_id, c.cboss_call_type_id, c.a_number, c.b_number,
               c.a_number_original, c.b_number_original, c.call_date,
               c.etl_date, c.DURATION, c.rounded_duration, c.imei,
               c.call_charge, c.interoper_charge, c.uplink, c.downlink,
               c.service_id_2, c.call_type_id_2, c.call_charge_with_vat,
               c.direction_type_id, c.account_typ
          FROM (SELECT   /*+ parallel (e 4)  parallel (k 4)  */
                         k.master_source_system_value1
                                                  AS orga_call_type_src_value,
                         k.detail_dwh_id AS cboss_call_type_id, e.record_no,
                         e.call_id, e.subscriber_id, e.service_id,
                         e.tariff_id, e.subscriber_business_type_id,
                         e.subscriber_marketing_type_id,
                         e.gsm_payment_type_id, e.distance_band_id,
                         e.time_band_id, e.time_id, e.duration_band_id,
                         e.cell_id, e.equipment_id, e.roaming_id,
                         e.gsm_method_id, e.call_type_id, e.a_number,
                         e.b_number, e.a_number_original, e.b_number_original,
                         e.call_date, e.etl_date, e.DURATION,
                         e.rounded_duration, e.imei, e.call_charge,
                         e.interoper_charge, e.uplink, e.downlink,
                         e.service_id_2, e.call_type_id_2,
                         e.call_charge_with_vat, e.direction_type_id,
                         e.local_flag, e.account_typ
                    FROM dwh_adm_key_transformation k,
                         (SELECT *
                            FROM dwh_tmp_pre_calldetails_6_1
                           WHERE local_flag = 'INT') e
                   WHERE k.master_trans_src_sys_value1 = 374
                     AND k.source_system_id = 2
                     AND e.call_type_id_2 = k.master_dwh_id(+)
                ORDER BY e.call_id, e.call_type_id, b_number) c,
               (SELECT *
                  FROM dwh_dim_distance_band
                 WHERE local_flag = 'INT' AND NVL (gsm_method_id, 2) = 2) d
         WHERE c.cboss_call_type_id = d.call_type_id(+)
           AND c.gsm_method_id = NVL (d.gsm_method_id(+), 2)
           AND c.direction_type_id = TO_NUMBER (d.service_direction(+))
           AND NVL (c.b_number, -1) LIKE NVL (d.check_digits(+), -1) || '%') a
 WHERE a.record_order = 1


explain plan:
PLAN_TABLE_OUTPUT
-----------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                          | Name                        | Rows  | Bytes | Cost  | Pstart| Pstop |    TQ  |IN-OUT| PQ Distrib |
-----------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                   |                             |  2590K|  1586M|   106K|  
|   1 |  PX COORDINATOR                    |                              
|   2 |   PX SEND QC (RANDOM)              | :TQ10004                    |  2590K|  1586M|   106K|        |       |  Q1,04 | P->S | QC (RAND)  |
|   3 |    VIEW                            |                             |  2590K|  1586M|   106K|       |       |  Q1,04 | PCWP |            
|   4 |     WINDOW SORT PUSHED RANK        |                             |  2590K|  1573M|   106K|       |       |  Q1,04 | PCWP |            
|   5 |      PX RECEIVE                    |                             |  2590K|  1573M|   106K|       |       |  Q1,04 | PCWP |            
|   6 |       PX SEND HASH                 | :TQ10003                    |  2590K|  1573M|   106K|       |       |  Q1,03 | P->P | HASH       |
|   7 |        VIEW                        |                             |       |       |       |       |       |  Q1,03 | PCWP |            
|   8 |         WINDOW CHILD PUSHED RANK   |                             |  2590K|  1573M|   106K|       |       |  Q1,03 | PCWP |            
|   9 |          HASH JOIN RIGHT OUTER     |                             |  2590K|  1573M|  9895 |       |       |  Q1,03 | PCWP |            
|  10 |           PX RECEIVE               |                             |  5823 |   181K|    12 |       |       |  Q1,03 | PCWP |            
|  11 |            PX SEND BROADCAST       | :TQ10001                    |  5823 |   181K|    12 |       |       |  Q1,01 | P->P | BROADCAST  |
|  12 |             PX BLOCK ITERATOR      |                             |  5823 |   181K|    12 |       |       |  Q1,01 | PCWC |            
|  13 |              TABLE ACCESS FULL     | DWH_DIM_DISTANCE_BAND       |  5823 |   181K|    12 |       |       |  Q1,01 | PCWP |            |
|  14 |           VIEW                     |                             |  2590K|  1494M|  9874 |       |       |  Q1,03 | PCWP |            
|  15 |            SORT ORDER BY           |                             |  2590K|   390M|  9874 |       |       |  Q1,03 | PCWP |            
|  16 |             PX RECEIVE             |                             |  2590K|   390M|  9799 |       |       |  Q1,03 | PCWP |            
|  17 |              PX SEND RANGE         | :TQ10002                    |  2590K|   390M|  9799 |       |       |  Q1,02 | P->P | RANGE      |
|  18 |               HASH JOIN            |                             |  2590K|   390M|  9799 |       |       |  Q1,02 | PCWP |            
|  19 |                PX RECEIVE          |                             |     3 |    66 |    63 |       |       |  Q1,02 | PCWP |            
|  20 |                 PX SEND BROADCAST  | :TQ10000                    |     3 |    66 |    63 |       |       |  Q1,00 | P->P | BROADCAST  |
|  21 |                  PX BLOCK ITERATOR |                             |     3 |    66 |    63 |       |       |  Q1,00 | PCWC |            
|  22 |                   TABLE ACCESS FULL| DWH_ADM_KEY_TRANSFORMATION  |     3 |    66 |    63 |       |       |  Q1,00 | PCWP |            |
|  23 |                PX BLOCK ITERATOR   |                             |  7928K|  1028M|  9712 |     1 |     4 |  Q1,02 | PCWC |            
|  24 |                 TABLE ACCESS FULL  | DWH_TMP_PRE_CALLDETAILS_6_1 |  7928K|  1028M|  9712 |     1 |     4 |  Q1,02 | PCWP |            |
-----------------------------------------------------------------------------------------------------------------------------------------------


Thank you in advance.

How to tune this query. please help me

Gouri, September 03, 2007 - 8:48 am UTC

SELECT /*+ ORDERED */
DECODE(iProductFlag, 'YES', ocprl.product_entry_id, NULL) as product_entry_id,
DECODE(iContentFlag,'YES', oc.entry_id,NULL) as online_content_entry_id,
DECODE(iOLCSDetailsFlag,'YES','N',NULL) AS Entitlement,
DECODE(iOLCSDetailsFlag,'YES',oc.content_by_product,NULL) AS content_by_product
FROM
aradmin.olcs_onlinecontent oc,
aradmin.olcs_onlinecontentprlinkage ocprl,
aradmin.olcs_product pr
WHERE
(
(iProductEntryID is NULL)
OR
(ocprl.product_entry_id = iProductEntryID)
)
AND
(
(iOnlineContentEntryID is NULL)
OR
(oc.entry_id = iOnlineContentEntryID)
)
AND
pr.entry_id = ocprl.product_entry_id
AND
ocprl.online_content_entry_id = oc.entry_id
AND
ocprl.state = 0
AND
oc.content_by_product != 'No'
AND
(
(
ocprl.entitlement = 'General Access'
OR oc.entitlement = 'General Access'
)
OR
(
ocprl.entitlement = 'Registered Users'
OR oc.entitlement = 'Registered Users'
)
OR
(
ocprl.entitlement = 'Entitled Users'
OR oc.entitlement = 'Entitled Users'
)
)
AND
oc.state = 2 -- 1 is internal only)
AND
( pr.state > 0 AND pr.state < 5 )
AND
(pr.help_desk_product = 'Standard Product'
OR
pr.help_desk_product = 'Pseudo Product')
AND
pr.catalog_product_name IS NOT NULL
AND
pr.catalog_business_unit IS NOT NULL
UNION
-- B ^ C Start
(
SELECT /*+ ORDERED */
DECODE(iProductFlag,'YES',product_entry_id,NULL) AS product_entry_id,
DECODE(iContentFlag, 'YES',online_content_entry_id,NULL) AS online_content_entry_id,
Entitlement AS Entitlement,
content_by_product AS content_by_product
FROM
(

(
(SELECT /*+ ORDERED */
--DECODE(iProductFlag,'YES',pr.entry_id,NULL) AS product_entry_id,
--DECODE(iContentFlag, 'YES',oc.entry_id,NULL) AS online_content_entry_id,
pr.entry_id AS product_entry_id,
oc.entry_id AS online_content_entry_id,
DECODE(iOLCSDetailsFlag,'YES','Y',NULL) AS Entitlement,
DECODE(iOLCSDetailsFlag,'YES',oc.content_by_product,NULL) AS content_by_product
FROM
aradmin.olcs_onlinecontent oc,
aradmin.olcs_onlinecontentprlinkage ocprl,
aradmin.olcs_product pr
WHERE
pr.entry_id = ocprl.product_entry_id
AND
ocprl.online_content_entry_id = oc.entry_id
AND
ocprl.state = 0
AND
oc.content_by_product != 'No'
AND
oc.state = 2 -- (1 is internal only)
AND
( pr.state > 0 AND pr.state < 5 )
AND
(pr.help_desk_product = 'Standard Product'
OR
pr.help_desk_product = 'Pseudo Product')
AND
pr.catalog_product_name IS NOT NULL
AND
pr.catalog_business_unit IS NOT NULL
)
)
INTERSECT
(SELECT /*+ ORDERED */
sd.xprentryid AS product_entry_id,
ocsol.online_content_entry_id AS online_content_entry_id,
DECODE(iOLCSDetailsFlag,'YES','Y',NULL) AS Entitlement,
DECODE(iOLCSDetailsFlag,'YES','Yes',NULL) AS content_by_product
FROM
aradmin.olcs_customer c,
aradmin.olcs_authorizedcontact ac,
aradmin.olcs_servicedetails sd,
aradmin.olcs_serviceagreement sa,
aradmin.olcs_coveredproductinstance cpi,
aradmin.olcs_coveredservice cs,
aradmin.olcs_serviceoffer so,
aradmin.olcs_onlinecontentsolinkage ocsol
WHERE
c.single_sign_on_principal_id = iSSOPID
AND
c.state = 1
AND
( ac.contact_id = c.contact_id
OR
(ac.xcompanyentryid = c.xcmmasterentryid
AND ac.all_employees_authorized='Yes')
)
AND
ac.state = 0
AND
ocsol.service_offer_entry_id =
cs.offer_id
AND
(
-- Option to limit to one specific product
(iProductEntryID is NULL)
OR
(sd.xprentryid = iProductEntryID)
)
AND
(
-- Option to limit to one specific online content
(iOnlineContentEntryID is NULL)
OR
(ocsol.online_content_entry_id = iOnlineContentEntryID)
)
AND
so.offer_id = cs.offer_id
AND
cs.service_details_entry_id =
sd.service_details_entry_id
AND
sa.service_agreement_number =
sd.service_agreement_number
AND
( sa.service_agreement_type != 'Umbrella Agreement' )
AND
sd.service_agreement_number =
ac.service_agreement_number
AND
sd.service_details_entry_id =
cpi.service_details_entry_id(+)
AND
(
(
( ac.line_item = 'ALL'
OR
( ac.service_details_entry_id =
sd.service_details_entry_id
AND ac.cpi_id = 'ALL')
)
AND
( sd.start_date <= (iRightNow + 1)
AND sd.end_date >= (iRightNow - 1)
)
)
OR
(
( ac.service_details_entry_id =
sd.service_details_entry_id
AND ac.cpi_id = cpi.entry_id )
AND
( cpi.start_date <= (iRightNow+ 1) AND
DECODE(so.synchronize_end_date, 'No',
( cpi.start_date + ocsol.warranty_support_interval ), cpi.end_date)
>= (iRightNow - 1)
)
)
)
AND
sd.state = 1
AND
cpi.state(+) = 1
AND
cs.state = 1
AND
ocsol.state = 0
)
)
-- B ^ C
)
-- END
UNION
(
SELECT
NULL as product_entry_id,
DECODE(iContentFlag,'YES', oc.entry_id,NULL) as online_content_entry_id,
DECODE(iOLCSDetailsFlag,'YES','N',NULL) AS Entitlement,
DECODE(iOLCSDetailsFlag,'YES','No',NULL) AS content_by_product
FROM
aradmin.olcs_onlinecontent oc
WHERE
(
-- Option to limit to one specific online content
(iOnlineContentEntryID is NULL)
OR
(oc.entry_id = iOnlineContentEntryID)
)
AND
oc.content_by_product = 'No'
AND
(
(
oc.entitlement = 'General Access'
)
OR
(
oc.entitlement = 'Registered Users'
)
OR
(
oc.entitlement = 'Entitled Users'
)
)
AND
oc.state = 2 -- 1 is internal only)
)
UNION
-- E ^ F Start
(
SELECT /*+ ORDERED */
DECODE(iProductFlag,'YES',product_entry_id,NULL) AS product_entry_id,
DECODE(iContentFlag, 'YES',online_content_entry_id, NULL) AS online_content_entry_id,
Entitlement AS Entitlement,
content_by_product AS content_by_product
FROM
--
(
(SELECT /*+ ORDERED */
--DECODE(iProductFlag,'YES',pr.entry_id,NULL) AS product_entry_id,
--DECODE(iContentFlag, 'YES',oc.entry_id, NULL) AS online_content_entry_id,
pr.entry_id AS product_entry_id,
oc.entry_id AS online_content_entry_id,
DECODE(iOLCSDetailsFlag,'YES','Y',NULL) AS Entitlement,
DECODE(iOLCSDetailsFlag,'YES',oc.content_by_product,NULL) AS content_by_product
FROM
aradmin.olcs_onlinecontent oc,
aradmin.olcs_product pr
WHERE
oc.content_by_product = 'No'
AND
oc.state = 2 -- (1 is internal only)
AND
( pr.state > 0 AND pr.state < 5 )
AND
(pr.help_desk_product = 'Standard Product'
OR
pr.help_desk_product = 'Pseudo Product')
AND
pr.catalog_product_name IS NOT NULL
AND
pr.catalog_business_unit IS NOT NULL
)
INTERSECT
(SELECT /*+ ORDERED */
--DECODE(iProductFlag,'YES',sd.xprentryid,NULL) AS product_entry_id,
--DECODE(iContentFlag, 'YES',ocsol.online_content_entry_id,NULL)
-- AS online_content_entry_id,
sd.xprentryid AS product_entry_id,
ocsol.online_content_entry_id AS online_content_entry_id,
DECODE(iOLCSDetailsFlag,'YES','Y',NULL) AS Entitlement,
DECODE(iOLCSDetailsFlag,'YES','No',NULL) AS content_by_product
FROM
aradmin.olcs_customer c,
aradmin.olcs_authorizedcontact ac,
aradmin.olcs_servicedetails sd,
aradmin.olcs_serviceagreement sa,
aradmin.olcs_coveredproductinstance cpi,
aradmin.olcs_coveredservice cs,
aradmin.olcs_serviceoffer so,
aradmin.olcs_onlinecontentsolinkage ocsol
WHERE
c.single_sign_on_principal_id = iSSOPID
AND
c.state = 1
AND
( ac.contact_id = c.contact_id
OR
(ac.xcompanyentryid = c.xcmmasterentryid
AND ac.all_employees_authorized='Yes')
)
AND
ac.state = 0
AND
ocsol.service_offer_entry_id =
cs.offer_id
AND
(
-- Option to limit to one specific online content
(iOnlineContentEntryID is NULL)
OR
(ocsol.online_content_entry_id = iOnlineContentEntryID)
)
AND
so.offer_id = cs.offer_id
AND
cs.service_details_entry_id =
sd.service_details_entry_id
AND
sa.service_agreement_number =
sd.service_agreement_number
AND
( sa.service_agreement_type != 'Umbrella Agreement' )
AND
sd.service_agreement_number =
ac.service_agreement_number
AND
sd.service_details_entry_id =
cpi.service_details_entry_id(+)
AND
(
(
( ac.line_item = 'ALL'
OR
( ac.service_details_entry_id =
sd.service_details_entry_id
AND ac.cpi_id = 'ALL')
)
AND
( sd.start_date <= (iRightNow + 1)
AND sd.end_date >= (iRightNow - 1)
)
)
OR
(
( ac.service_details_entry_id =
sd.service_details_entry_id
AND ac.cpi_id = cpi.entry_id )
AND
( cpi.start_date <= (iRightNow+ 1) AND
DECODE(so.synchronize_end_date, 'No',
( cpi.start_date + ocsol.warranty_support_interval ), cpi.end_date)
>= (iRightNow - 1)
)
)
)
AND
sd.state = 1
AND
cpi.state(+) = 1
AND
cs.state = 1
AND
ocsol.state = 0
)
)
-- E ^ F
)
-- End
;

A reader, September 05, 2007 - 9:28 pm UTC

Thanks Tom

merge statement efficiency

Jayanth, September 07, 2007 - 10:22 am UTC

Hi Tom,
   I am struggling with a merge statement with its huge turn around time. It is taking about 45-50 minutes to execute. The following is the merge 

statement, with its plan and statistics. I dont seem to find anything wrong with the plan except for the high cost, but then, the number of rows 

merged is about 1.3 million, so I am guessing the cost is "OK". 

This is the version info of the environment.

<code>

SQL*Plus: Release 9.2.0.1.0 - Production on Wed Sep 5 12:25:24 2007
Copyright (c) 1982, 2002, Oracle Corporation.  All rights reserved.

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, Real Application Clusters, OLAP and Data Mining options



The following is the merge statement
merge into email_sub ets
using (select ea.*, ems.master_source_id, es.web_store_campaign, ems.channel
    from email_address ea, email_source es, email_master_source ems
    where ea.add_by_source_id = es.source_id
    and es.master_source_id = ems.master_source_id
    and ea.valid_ind = 1
    and ea.opt_in = 1) e_address
 on (ets.email_address = e_address.email_address)
when matched then
 update set ets.men = case when e_address.gender = 'M' or e_address.title = 3 then 1 else 0 end,                                                

ets.card_holder = nvl(e_address.first_tier, 0),
            ets.first = decode(e_address.first_flag, '0', 'ENTRY PREMIER',                                                           

      '1', 'PREMIER',
         '2', 'ELITE',                       

        '3', 'PLATINUM',
         '4', 'DIAMOND',
         'C', 'ENTRY PREMIER',
         'V', 'PREMIER',
         'W', 'ELITE',
         'Z', 'PLATINUM',
         'D', 'DIAMOND',
          null),
   ets.sweepstake_entrant = case when e_address.web_Store_campaign is not null and e_address.web_store_campaign != '0' then 1 

else 0 end,
   ets.modify_Dt = e_address.modify_dt, ets.bdate = CASE WHEN (e_address.bday_day IS NOT NULL AND e_address.bday_day > 0 and 

e_address.bday_daY <=30 ) and (e_address.bday_month IS NOT NULL AND e_address.bday_month > 0  and e_address.bday_month <= 12) THEN TO_CHAR(  to_date(  

lpad( e_address.bday_day, 2, '0') || '-' || lpad(e_address.bday_month, 2, '0') || '-1900' , 'DD-MM-YYYY'), 'DD-MON-YYYY') ELSE NULL END,    

 ets.source_id = e_address.add_by_source_id,
   ets.master_source_id = e_address.master_source_id,
   ets.master_channel = e_address.channel,
   ets.welcome_promo = e_address.welcome_promo
when not matched then
 insert (ets.email_address, ets.sweepstake_entrant, ets.men, ets.first, ets.Card_holder, ets.modify_dt, ets.bdate, ets.source_id, 

ets.master_source_id, ets.master_channel, ets.welcome_promo, ets.non_trade_area, ets.affluent, ets.sfa_employee, ets.vip,                            

  ets.buyer_type, ets.vgc_sender, ets.phone_orderer, ets.gift_card_buyer, ets.vgc_recipient, ets.web_only_buyer,
   ets.holiday_only_shopper, ets.promo_code_user, ets.gift_giver, ets.channel, ets.partner, ets.vendor,
   ets.division)
 values (e_address.email_address, case when e_address.web_Store_campaign is not null and e_address.web_store_campaign != '0' then 1 else 0 end,       

  case when e_address.gender = 'M' or e_address.title = 3 then 1 else 0 end,
   decode(e_address.first_flag, '0', 'ENTRY PREMIER',
               '1', 'PREMIER',
             '2', 'ELITE',                                                       

              '3', 'PLATINUM',
             '4', 'DIAMOND',                                                   

              'C', 'ENTRY PREMIER',
             'V', 'PREMIER',
               'W', 'ELITE',
             'Z', 'PLATINUM',
               'D', 'DIAMOND',
             ' '),                                                            

  e_Address.first_tier,
    e_address.modify_dt,
   CASE WHEN (e_address.bday_day IS NOT NULL AND e_address.bday_day > 0 and e_address.bday_daY <=30 ) and (e_address.bday_month IS NOT 

NULL AND e_address.bday_month > 0  and e_address.bday_month <= 12) THEN TO_CHAR(  to_date(  lpad( e_address.bday_day, 2, '0') || '-' || 

lpad(e_address.bday_month, 2, '0') || '-1900' , 'DD-MM-YYYY'), 'DD-MON-YYYY') ELSE NULL END,
   e_address.add_by_source_id,
   e_address.master_source_id,
   e_address.channel,
   e_address.welcome_promo,
   0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0,0);  

And its plan and statistics

Execution Plan
----------------------------------------------------------
   0      MERGE STATEMENT Optimizer=FIRST_ROWS (Cost=1660480 Card=819884 Bytes=597695436)
   1    0   MERGE OF 'EMAIL_SUB'   2    1     VIEW
   3    2       NESTED LOOPS (OUTER) (Cost=1660480 Card=819884 Bytes=300077544)
   4    3         NESTED LOOPS (Cost=429851 Card=819884 Bytes=201691464)
   5    4           NESTED LOOPS (Cost=14 Card=135 Bytes=2565)
   6    5             TABLE ACCESS (FULL) OF 'EMAIL_MASTER_SOURCE' (TABLE) (Cost=3 Card=15 Bytes=150)
   7    5             TABLE ACCESS (BY INDEX ROWID) OF 'EMAIL_SOURCE' (TABLE) (Cost=1 Card=9 Bytes=81)
   8    7               INDEX (RANGE SCAN) OF 'ES_MASTER_SOURCE_ID_IDX' (INDEX) (Cost=1 Card=9)
   9    4           TABLE ACCESS (BY INDEX ROWID) OF 'EMAIL_ADDRESS' (TABLE) (Cost=3184 Card=6073 Bytes=1378571)
  10    9             INDEX (RANGE SCAN) OF 'EA_SOURCE_ID_IDX' (INDEX) (Cost=44 Card=52896)
  11    3         TABLE ACCESS (BY INDEX ROWID) OF 'EMAIL_SUB' (TABLE) (Cost=2 Card=1 Bytes=120)
  12   11           INDEX (UNIQUE SCAN) OF 'PK_EMAIL_1' (INDEX (UNIQUE)) (Cost=1 Card=1)


where
pk_email_1 is primary key index on email_sub (email_address)
ea_source_id_idx is an index on the email_address (add_by_source_id)
es_master_source_id_idx is an index on email_source (master_source_id)

The query that is used for the merge (select ea.*, ems.master_source_id, es.web_store_campaign, ems.channel.....) is fairly fast.

Statistics
----------------------------------------------------------
       1292  recursive calls
    2658192  db block gets
    4142551  consistent gets
     523976  physical reads
  752473676  redo size
        630  bytes sent via SQL*Net to client
       4118  bytes received via SQL*Net from client
          3  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
    1291714  rows processed


The hash_area_size and sort area size is


SQL> show parameter hash_area_size

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
hash_area_size                       integer     131072
SQL> show parameter sort_area_size;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
sort_area_size                       integer     65536
SQL>




Waht do you think of the statistics? Right now, I am thinking upping the hash_area_size and the sort_Area_size might help, but not sure. I wanted to

run it by you to see if I was missing anything more significant and fundamental.



Thanks a lot in advance!</code>
Tom Kyte
September 12, 2007 - 10:11 am UTC

well, 1.2 million rows...

are you modifying indexed columns, that would account for a huge bit of that.

and where is the tkprof that shows

a) the real work performed
b) the wait events you experience

why first rows? that is causing it to use lots of indexes there and you probably want no indexes, just nice juicy full scans and hash joins (of course, increase your hash area size if you are using manual memory management)

LARGE TABLE INSER

DEBASISH, September 14, 2007 - 9:19 am UTC

HI TOM
I HAVE THE FOLLOWING INERT STAMENT, IT TOOK PLENTY OF TIME. CAN YOU GIVE ME SUGGESTION IN ADVANCE

INSERT INTO magerror.m02_6
(voucher_no, voucher_date, cash_bank_code, debit, credit, gl_type)
select voucher_no, voucher_date, account_code, debit, credit, 'GL FIN'
from trans.tb_gledger_fin a
where comp_code = '000002'
and voucher_date between '01-apr-05' and '31-mar-06'
and not exists (select 1
from trans.tb_cv_voucher_mas b
where comp_code = '000002'
and b.voucher_no = a.voucher_no
and b.voucher_date = a.voucher_date
and b.cash_bank_code=a.account_code
and b.vr_debit=a.debit
and b.vr_credit=a.credit
and b.source_location_code=a.LOCATION_CODE)
and serial_no = 0;


THE EXPLAIN PLAN IS
===================
Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

INSERT STATEMENT Optimizer Mode=ALL_ROWS 43 K 273253
FILTER
HASH JOIN ANTI 43 K 5 M 273253
TABLE ACCESS BY GLOBAL INDEX ROWID TRANS.TB_GLEDGER_FIN 43 K 2 M 261645 ROWID ROW L
INDEX RANGE SCAN TRANS.PK_GLEDGER_FIN 285 K 205482
TABLE ACCESS FULL TRANS.TB_CV_VOUCHER_MAS 654 K 37 M 9544

BOTH THE TABLE HAS 4 TO 5 MILION RECORD
Tom Kyte
September 15, 2007 - 9:42 pm UTC

define "plenty of time" and define the indexes on m02_6 and define your expectations.

business functions performance

JDam, September 21, 2007 - 10:10 pm UTC

Hi Tom,

I have a view with several business functions, each business functions have one or more select statements, the questions is Should I have to avoid the use of functions with select statements inside it.

Thanks...
Tom Kyte
September 26, 2007 - 1:21 pm UTC

I don't know what you mean by a view with several business functions.

overhead involved in calling plsql from sql

Jdam, September 26, 2007 - 8:23 pm UTC

Hi Tom,

Sorry I found the answer in this link http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:1547006324238

Thanks..

Huge create table

martina, September 27, 2007 - 3:47 am UTC

Hello Tom,

I have the following create Tables. They are logically identical. the first is the simpler one (one table is not joined) but it fills up systemp within 20min. The 2nd finishes within 7+ hrs. I accept that it takes a long time as i expected more than 1,000,000,000 rows before the group by. (I tested with mod(fil,100) = 1 which had 15 mio before the group by). I do not understand why the 1st fills up systemp.
What can we change? increase pga_aggregate_target (now 1073741824)? increase systemp (now 16380MB)? Any other ideas?

Thank you in advance!

martina

following the queries:
create table gi_data_rast tablespace IGROSSU   nologging compress
  as
select aliq.filiale, aliq.firma , aliq.ezg_grp, aliq.ezg_id, aliq.geo_basis
      ,codes.code_typ ,codes.code1 ,codes.code2 ,codes.code3
      ,sum(aliq.anteil_ring * nvl ( rwa.wert, 0 ) ) wert
      ,sysdate aender_datzt
      ,sum(aliq.anteil * nvl ( rwa.wert, 0 ) ) wert_kreis
from   gi_filst_gis        fil
     , gi_codes         codes
     , gi_rwadata_zsp   rwa
     , gi_ring_rast  aliq
where codes.nur_rwadata_jn = 'N'
  and codes.code_typ       = rwa.code_typ
  and codes.code1          = rwa.code1
  and codes.code2          = rwa.code2
  and codes.code3          = rwa.code3
  and to_char(rwa.zsp_nr)  = mod(aliq.basis_id,100000000)
  and aliq.geo_basis       = 'ZSP'
group by   aliq.firma, aliq.filiale, aliq.ezg_grp, aliq.ezg_id
         , codes.code_typ, codes.code1, codes.code2, codes.code3, aliq.geo_basis

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          2          0           0
Execute      1    651.91     698.92      22242      29838         16           0
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    651.92     698.93      22242      29840         16           0

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 18  
********************************************************************************

SELECT /*+ ALL_ROWS IGNORE_WHERE_CLAUSE */ NVL(SUM(C1),0), NVL(SUM(C2),0), 
  COUNT(DISTINCT C3) 
FROM
 (SELECT /*+ IGNORE_WHERE_CLAUSE NOPARALLEL("ALIQ") */ 1 AS C1, CASE WHEN 
  "ALIQ"."GEO_BASIS"='ZSP' AND "ALIQ"."FIRMA"='00' THEN 1 ELSE 0 END AS C2, 
  "ALIQ"."FIRMA" AS C3 FROM "GI_RING_RAST" SAMPLE BLOCK (0.104836) "ALIQ") 
  SAMPLESUB


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        1      0.05       0.56        409         32          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3      0.05       0.56        409         32          0           1

Misses in library cache during parse: 1
Optimizer goal: ALL_ROWS
Parsing user id: 18     (recursive depth: 1)

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT GROUP BY 
   9924   TABLE ACCESS SAMPLE GI_RING_RAST 

********************************************************************************

create table gi_data_rast tablespace IGROSSU   nologging compress
  as
select fil.filiale, fil.firma , aliq.ezg_grp, aliq.ezg_id, aliq.geo_basis
      ,codes.code_typ ,codes.code1 ,codes.code2 ,codes.code3
      ,sum(aliq.anteil_ring * nvl ( rwa.wert, 0 ) ) wert
      ,sysdate aender_datzt
      ,sum(aliq.anteil * nvl ( rwa.wert, 0 ) ) wert_kreis
from   gi_filst_gis        fil
     , gi_codes         codes
     , gi_rwadata_zsp   rwa
     , gi_ring_rast   aliq
where fil.firma            = aliq.firma
  and fil.filiale          = aliq.filiale
  and fil.firma = '00'
  and codes.nur_rwadata_jn = 'N'
  and codes.code_typ       = rwa.code_typ
  and codes.code1          = rwa.code1
  and codes.code2          = rwa.code2
  and codes.code3          = rwa.code3
  and to_char(rwa.zsp_nr)  = mod(aliq.basis_id,100000000)
  and aliq.geo_basis       = 'ZSP'
group by   fil.firma, fil.filiale, aliq.ezg_grp, aliq.ezg_id
         , codes.code_typ, codes.code1, codes.code2, codes.code3, aliq.geo_basis

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.01          0          2          0           0
Execute      1  23852.76   25365.17     482931 2440866944        333     8114874
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2  23852.76   25365.18     482931 2440866946        333     8114874

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 18  


PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------
| Id  | Operation              |  Name           | Rows  | Bytes |TempSpc| Cost  |
----------------------------------------------------------------------------------
|   0 | CREATE TABLE STATEMENT |                 |    17G|  1100G|       |  3674M|
|   1 |  LOAD AS SELECT        |                 |       |       |       |       |
|   2 |   SORT GROUP BY        |                 |    17G|  1100G|    18T|  3674M|
|*  3 |    HASH JOIN           |                 |   206G|    12T|    91M| 11734 |
|*  4 |     HASH JOIN          |                 |  2182K|    66M|       |   382 |
|*  5 |      TABLE ACCESS FULL | GI_CODES        |   422 |  5486 |       |     3 |
|   6 |      TABLE ACCESS FULL | GI_RWADATA_ZSP  |  2182K|    39M|       |   370 |
|*  7 |     TABLE ACCESS FULL  | GI_RING_RAST    |  9466K|   334M|       |  2845 |
----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access(TO_NUMBER(TO_CHAR("RWA"."ZSP_NR"))=MOD(TO_NUMBER("ALIQ"."BASIS_ID"),
              100000000))
   4 - access("CODES"."CODE_TYP"="RWA"."CODE_TYP" AND
              "CODES"."CODE1"="RWA"."CODE1" AND "CODES"."CODE2"="RWA"."CODE2" AND
              "CODES"."CODE3"="RWA"."CODE3")
   5 - filter("CODES"."NUR_RWADATA_JN"='N')
   7 - filter("ALIQ"."GEO_BASIS"='ZSP')

Note: cpu costing is off


PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------

---------------------------------------------------------------------------------------------------
| Id  | Operation              |  Name            | Rows  | Bytes |TempSpc| Cost  | Pstart| Pstop |
---------------------------------------------------------------------------------------------------
|   0 | CREATE TABLE STATEMENT |                  |    17G|  1179G|       |  1850M|       |       |
|   1 |  LOAD AS SELECT        |                  |       |       |       |       |       |       |
|   2 |   SORT GROUP BY        |                  |    17G|  1179G|  8777G|  1850M|       |       |
|   3 |    NESTED LOOPS        |                  |    94G|  6511G|       | 11734 |       |       |
|*  4 |     HASH JOIN          |                  |   206G|    12T|    91M| 11734 |       |       |
|*  5 |      HASH JOIN         |                  |  2182K|    66M|       |   382 |       |       |
|*  6 |       TABLE ACCESS FULL| GI_CODES         |   422 |  5486 |       |     3 |       |       |
|   7 |       TABLE ACCESS FULL| GI_RWADATA_ZSP   |  2182K|    39M|       |   370 |       |       |
|*  8 |      TABLE ACCESS FULL | GI_RING_RAST     |  9466K|   334M|       |  2845 |       |       |
|*  9 |     INDEX UNIQUE SCAN  | GI_FILST_GIS_PK  |     1 |     5 |       |       |     1 |     1 |
---------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - access(TO_NUMBER(TO_CHAR("RWA"."ZSP_NR"))=MOD(TO_NUMBER("ALIQ"."BASIS_ID"),100000000))
   5 - access("CODES"."CODE_TYP"="RWA"."CODE_TYP" AND "CODES"."CODE1"="RWA"."CODE1" AND
              "CODES"."CODE2"="RWA"."CODE2" AND "CODES"."CODE3"="RWA"."CODE3")
   6 - filter("CODES"."NUR_RWADATA_JN"='N')
   8 - filter("ALIQ"."GEO_BASIS"='ZSP' AND "ALIQ"."FIRMA"='00')
   9 - access("GI_FILST_GIS"."FILIALE"="ALIQ"."FILIALE" AND "GI_FILST_GIS"."FIRMA"='00')
       filter("GI_FILST_GIS"."FIRMA"="ALIQ"."FIRMA")

Note: cpu costing is off

Tom Kyte
September 27, 2007 - 7:08 am UTC

well, if you need to store one billion records - you'll need quite a bit of temp don't you think?

you do not say how big temp is, but it surely sounds like it is insufficient for what you are trying to do.

but, you might look at what you are doing - if that generates such a large intermediate result - do you see the estimated temp space for the one query is 18t - 18 TERABYTES

Martina in Vienna

SeánMacGC, September 28, 2007 - 9:28 am UTC

You say "I have the following create Tables. They are logically identical. the first is the simpler one (one table is not joined) but it fills up systemp within 20min..."

This is effectively a Cartesian Product, yes (if the table gi_filst_gis has more than 1 record)? These two SQL statements cannot be logically equivalent, since the first one will produce (many) more results than the second (hence your filling up problem), because of the Cartesian Product (Cross Join)

Re: merge statement efficiency

Jayanth, September 28, 2007 - 5:26 pm UTC

Tom,
    I ran the merge statement in both optimizer modes (all_rows and first_rows). The following are the TKPROF's from both the runs. When run with the optimizer mode as all_rows, the statement completes in about 9 mins less (from 44~45 to 33~34) as compared with first_rows.

Also, there are no indexes on the target table to hinder the merge operation.

TKPROF for optimizer_mode FIRST_ROWS:
<code>
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.06       0.04          0          0          0           0
Execute      1    130.42     432.13     481649    4168215    2656757     1291714
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    130.48     432.18     481649    4168215    2656757     1291714

Misses in library cache during parse: 1
Optimizer goal: FIRST_ROWS
Parsing user id: 179  


TKPROF for optimizer mode ALL_ROWS
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.04       0.04          0          0          6           0
Execute      1     84.76    1992.95     329751     136171    2634326     1291714
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2     84.81    1992.99     329751     136171    2634332     1291714

Misses in library cache during parse: 1
Optimizer goal: ALL_ROWS
Parsing user id: 179  


Thanks a bunch in advance!</code>
Tom Kyte
October 03, 2007 - 1:13 pm UTC

well, that is not useful.

you left out - well - the useful bits for whatever reason.

you know, the bits that show THE WORK PERFORMED by each step (the row source operation)

and the wait events.

I'm going to guess that most of the wait is disk IO - the cpu times are small, the elapsed times large - you are waiting on something and you do lots of physical IO. Might be "unavoidable" - you have to read it into the cache sometime.

But, we are just guessing - since you didn't provide that bit.

Re: merge statement efficiency

Jayanth, October 03, 2007 - 2:36 pm UTC

Tom,
I looked through the trace files for row source operation, but could not find any info for the merge statement. Do I need to set any session level parameters for it to generate the row source operation details and such?

Here is what I did.

SQL>ALTER SESSION SET SQL_TRACE=true;
SQL>ALTER SESSION SET TIMED_STATISTICS=true;


and used the following to generate the output from the trace files
$ tkprof tracefile.trc outfile


Am I missing something here?

Regarding "Followup June 2, 2004 - 7am US/Eastern:"

kulbhushan, October 04, 2007 - 10:06 am UTC

Regarding "Followup June 2, 2004 - 7am US/Eastern:"

Actual question is to retrieve all person records where only one active incident.

Query seuggested by you :

SELECT i1.pid_number, max(i1.inc_number)...
FROM alias.cch_person c, alias.incident i1
WHERE i1.pid_number = c.pid_number ..
GROUP BY i1.pid_number
having count(*) = 1


My questions:

1. I wonder how group by is gonna work ?.
Its gonna group rows by same pid number then select only rowsets having row count=1 and return max values in rowset .
or
Group rows by pid number then run max function on each column selected in rowset.If this is true ,it conflicts with user requirement .

2. The Explain plan of select statement is
...
SORT (GROUP BY) (Cost=13062 Card=3841 Bytes=238142)
...
It says card=3841 but actually selects 681235 ,please explain why it shows different card?

Regards

date and index

John Wang, October 04, 2007 - 3:14 pm UTC

SQL> set autotrace traceonly explain
SQL> select * from workorder
  2  where reportdate BETWEEN TO_DATE('10-04-2007','MM-DD-YYYY') AND TO_DATE('10
-05-2007','MM-DD-YYYY') ;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=302 Card=429 Bytes=3
          01587)

   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'WORKORDER' (Cost=302 Car
          d=429 Bytes=301587)

   2    1     INDEX (RANGE SCAN) OF 'IDX_WORKORDER10' (NON-UNIQUE) (Co
          st=4 Card=429)




SQL> select * from workorder
  2  where reportdate between trunc(sysdate) and trunc(sysdate)+1 and reportdate
 <> trunc(sysdate)+1;

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=20577 Card=21 Bytes=
          14763)

   1    0   FILTER
   2    1     TABLE ACCESS (FULL) OF 'WORKORDER' (Cost=20577 Card=21 B
          ytes=14763)




SQL>

also, in https://asktom.oracle.com/Misc/oramag/on-html-db-bulking-up-and-speeding.html, you suggested that between would use index.  but how come when i use trunc(sysdate), it won't use the index?

any ideas?

thanks
jw


Columns with only two unique values

Rama Subramanian G, October 11, 2007 - 8:43 am UTC

Hi Tom,

On this topic of tuning, I came across this situation. A table has a column which takes only values 'N' or 'Y' and the count for 'N' is several times more than that for 'Y'.

DRAFT_FLAG COUNT(*)
---------- --------
N 1396577
Y 423

In a typical situation where the users query data using a java based web application and the search condition specified is very sparse, say only based on this column, the result set appears in a fairly immediately if the value is 'Y' and takes much more time if it is 'N'.

Well that was expected as it has to return more number of rows in the latter case. However, the user expectation is to have comparably faster as that for 'Y'.

What is in you opinion a fair goal to have while approaching tuning - to benchmark the response time or to have reasonably better response time depending on available resources? What should be a developer's aim while trying to satisfy user requirement ?

Warm Regards
Rama Subramanian G
Tom Kyte
October 14, 2007 - 9:54 pm UTC

I would need more information - like "why does the user have to wait for 1.3 million records to come back - what is the application DOING here"

i would say to display the first 25 records of either should be really fast.

if you need to process 1.3 million records, do not expect fast.


I don't understand the last paragraph in the context of the example. You have to benchmark response time and resources required in order to understand how something will respond and how it will scale. Tuning is the art of taking that information and finding a faster/better/cheaper way of doing it.

Ali, October 23, 2007 - 3:28 pm UTC

Can you say me why is the WITH clause faster than using GTT tables in this situation?

---- WITH clause
with with_sere as (select /*+ parallel (dein,8) full(dein) */
dein.inte_no
from intr_tbl_detail_intr dein
where sysdate between dein.dein_dt_vig and nvl ( dein.dein_dt_expir, sysdate )
and dein.dein_ind_actif = 'O'
and dein.vaat_id_val+0 = 2123380 -- sérénité oui
and dein.atgl_id+0 = 7193 -- atglid sérénité
),
with_civi as (select /*+ parallel (dein,8) full(dein) */
dein.inte_no
from intr_tbl_detail_intr dein
where sysdate between dein.dein_dt_vig and nvl ( dein.dein_dt_expir, sysdate )
and dein.dein_ind_actif = 'O'
and dein.dein_val||'' = 'A'
and dein.atgl_id+0 = 119 -- statut civil
),
with_vigu as (select /*+ ordered parallel(peco,8) full(peco)*/
distinct poas.inte_no
from sous_tbl_pol_ass poas ,
sous_tbl_perd_couvrt peco
where sysdate between peco.peco_dt_vig and peco.peco_dt_expir
and peco.vaat_id_type_statut_dnm_stso+0 in (9, 199)
and peco.poas_id = poas.poas_id
and poas.vaat_id_lig_aff+0 = 3
)
select /*+ ordered parallel(vigu,8) full(vigu)
*/
distinct inte.inte_no
bulk collect into inte_tab
from with_vigu vigu,
intr_tbl_intr inte
where vigu.inte_no = inte.inte_no
and not exists (select 1
from with_sere
where inte_no = inte.inte_no
)
and not exists(select 1
from with_civi
where inte_no = inte.inte_no
)
and instr( upper ( inte.inte_nom_dnm || inte.inte_prenm_dnm ), 'SUCC' ) = 0
and inte.inte_type = 'I';

-- GTT tables
insert into gtt_sere (select /*+ parallel (dein,8) full(dein) */
inte_no
from intr_tbl_detail_intr dein
where sysdate between dein.dein_dt_vig and nvl ( dein.dein_dt_expir, sysdate )
and dein.dein_ind_actif = 'O'
and dein.vaat_id_val+0 = 2123380 -- sérénité oui
and dein.atgl_id+0 = 7193 -- atglid sérénité
);

insert into gtt_civi (select /*+ parallel (dein,8) full(dein) */
inte_no
from intr_tbl_detail_intr dein
where sysdate between dein.dein_dt_vig and nvl ( dein.dein_dt_expir, sysdate )
and dein.dein_ind_actif = 'O'
and dein.dein_val||'' = 'A'
and dein.atgl_id+0 = 119 -- statut civil
);

insert into gtt_vigu (select /*+ ordered parallel(peco,8) full(peco)*/
distinct poas.inte_no
from sous_tbl_pol_ass poas ,
sous_tbl_perd_couvrt peco
where sysdate between peco.peco_dt_vig and peco.peco_dt_expir
and peco.vaat_id_type_statut_dnm_stso+0 in (9, 199)
and peco.poas_id = poas.poas_id
and poas.vaat_id_lig_aff+0 = 3
);
select /*+ dynamic_sampling(gtt_vigu 1)
ordered full(gtt_vigu) parallel (gtt_vigu, 8)
*/
distinct inte.inte_no
bulk collect into inte_tab
from gtt_vigu,
intr_tbl_intr inte
where gtt_vigu.inte_no = inte.inte_no
and not exists (select /*+ dynamic_sampling(gtt_sere 1)
*/
1
from gtt_sere
where inte_no = inte.inte_no
)
and not exists (select /*+ dynamic_sampling(gtt_civi 1)
*/
1
from gtt_civi
where inte_no = inte.inte_no
)
and instr( upper ( inte.inte_nom_dnm || inte.inte_prenm_dnm ), 'SUCC' ) = 0
and inte.inte_type = 'I';

Regards

Basic SQL Tuning

Robert, October 27, 2007 - 3:10 am UTC

Hi,

I'm just a little puzzled about the behaviour of Oracle with regard to Consistent Gets when returning a COUNT of a table. One would expect that a count(1) query of a table of 2,500 rows  to complete instantly, in sub millisecond time. When I run this query on the all_objects table using rownum < 2500, the query takes about 0.84 seconds to complete on my machine. In contrast if I insert 2,500 rows from all_objects into a new table and then run the same query against this new table, the query complete in sub millisecond time. The number of consistent gets used when querying the all_objects table directly using rownum is about 4,500 higher.

See:

SQL> set autotrace on statistics
SQL> select count(1) from all_objects where rownum < 2500;

  COUNT(1)
----------
      2499

Elapsed: 00:00:00.79

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       4258  consistent gets
          0  physical reads
          0  redo size
        412  bytes sent via SQL*Net to client
        380  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

SQL> create table myTable as select rownum As ID from all_objects where rownum < 2500;

Table created.

Elapsed: 00:00:00.46

SQL> select count(1) from mytable;

  COUNT(1)
----------
      2499

Elapsed: 00:00:00.00

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          6  consistent gets
          0  physical reads
          0  redo size
        412  bytes sent via SQL*Net to client
        380  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

I executed both queries three of four times each before recording the results. Obviously this is not a fully configured test environment, but it should be sufficient to explain my question and illustrate this difference.

Tom Kyte
October 29, 2007 - 12:30 pm UTC

do an explain plan on your all_objects query
then, do the same for your 1 column table.


that should make this answer "self evident"


In order to count rows, you need to manufacture the rows - get the rows. Consider how complex "getting a row" from all_objects is - compared to a simple single column table.

I'm at a loss to understand why you think
...
One would expect that a
count(1) query of a table of 2,500 rows to complete instantly,
....

is true, that thought would never enter my mind - never.


select count(*)
from (select a, b, c, d, sum(x)
from ten_billion_record_view_that_joins_25_tables
group by a,b,c,d )
/

answer = 2,500
runtime = hours


I might expect that, if I had to join 25 tables to derive 10 billion rows that get aggregated to 2,500 records.


The count returned is utterly meaningless in helping you determine how long it takes to execute the query.

Robert, October 30, 2007 - 1:00 am UTC

Thank you for the comment.

Running explain plan answered my question immediately. I just forgot to use it when comparing the two queries.

Thank you for pointing that out to me.

A dead slow query

Qazi, November 22, 2007 - 11:42 am UTC

We have following query from a report. It was taking more than 24 hoours before but now it is take only 8 hours which is not acceptable.

I just tried to do a count rather than list all the columns.

We are still using 8.1.7.4.

SQL> select count(*)
2 from
3 (select * from ldc_customer_data_vw
4 ) inline,
5 (select *
6 from LDC_CSIS_REPORT_TRANS
7 where transaction_code = 33
8 and op_code >=50
9 and rp550_id='1'
10 and post_date between to_date('2007-Oct-01', 'yyyy-mon-dd') and to_date('2007-Nov-01', 'yyyy-mon-dd')
11 ) T1
12 where t1.ACCOUNT_NUMBER = inline.account_number;

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=101 Card=1 Bytes=94)
1 0 SORT (AGGREGATE)
2 1 NESTED LOOPS (Cost=101 Card=3 Bytes=282)
3 2 NESTED LOOPS (Cost=92 Card=3 Bytes=216)
4 3 HASH JOIN (Cost=38 Card=18 Bytes=1044)
5 4 HASH JOIN (Cost=31 Card=18 Bytes=828)
6 5 TABLE ACCESS (BY INDEX ROWID) OF 'LDC_SERVICE_LOCATION' (Cost=3 Card=2759 Bytes=38626)
7 6 INDEX (RANGE SCAN) OF 'LDC_SERVICE_LOCATION_IDX04' (NON-UNIQUE) (Cost=1 Card=2759)
8 5 TABLE ACCESS (BY INDEX ROWID) OF 'LDC_CSIS_ACCOUNT' (Cost=2 Card=3522 Bytes=112704)
9 8 INDEX (RANGE SCAN) OF 'JFM01' (NON-UNIQUE) (Cost=1 Card=3522)
10 4 TABLE ACCESS (BY INDEX ROWID) OF 'LDC_CSIS_CUSTOMER' (Cost=4 Card=6858 Bytes=82296)
11 10 INDEX (RANGE SCAN) OF 'LDC_CSIS_CUSTOMER_IDX_02' (NON-UNIQUE) (Cost=1 Card=6858)
12 3 TABLE ACCESS (BY INDEX ROWID) OF 'LDC_CSIS_CUSTOMER_ADDRESS' (Cost=3 Card=1773170 Bytes=24824380)
13 12 INDEX (RANGE SCAN) OF 'CUSTOMER_ADDRESS_PK' (UNIQUE) (Cost=2 Card=1773170)
14 2 TABLE ACCESS (BY INDEX ROWID) OF 'LDC_CSIS_REPORT_TRANS' (Cost=3 Card=8346 Bytes=183612)
15 14 INDEX (RANGE SCAN) OF 'CSIS_REPORT_TRANS_PK' (UNIQUE) (Cost=2 Card=8346)

ldc_customer_data_vw
********************
ldc_customer_data_vw is a view and here is its defination.

create or replace view ldc_customer_data_vw as
select t45.CUSTOMER_NAME, T45.HISTORY_END_DATE,
T32.ACCOUNT_NUMBER, T32.CUSTOMER_KEY, T32.SEI_AREA_NUMBER, T32.SEI_DISTRICT_NUMBER,
T32.SERVICE_ADDRESS, T32.SERVICE_CITY, T32.HISTORY_SEQ_NUMBER, T32.MAILING_ADDRESS_KEY
from
(select cust.CUSTOMER_KEY, cust.CUSTOMER_NAME, cust.HISTORY_END_DATE, lcca.MAILING_ADDRESS_KEY
from
(select CUSTOMER_KEY,lcc.CUSTOMER_NAME, lcc.HISTORY_END_DATE
from LDC_CSIS_CUSTOMER lcc
where lcc.history_end_date =to_date('9999-12-31 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
) cust,
(select *
from LDC_CSIS_CUSTOMER_ADDRESS addr
where addr.history_end_date =to_date('9999-12-31 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
) lcca
where cust.CUSTOMER_KEY=lcca.CUSTOMER_KEY
) T45,
(select T3.ACCOUNT_NUMBER, T3.CUSTOMER_KEY, T3.SEI_TOWN_ID, T3.SEI_PREMISE_NUMBER, T3.HISTORY_SEQ_NUMBER, T3.MAILING_ADDRESS_KEY,
T2.SEI_AREA_NUMBER, T2.SEI_DISTRICT_NUMBER, T2.SERVICE_ADDRESS, T2.SERVICE_CITY
from (
select ACCOUNT_NUMBER, CUSTOMER_KEY, lca.SEI_TOWN_ID, lca.SEI_PREMISE_NUMBER, HISTORY_SEQ_NUMBER, MAILING_ADDRESS_KEY
from LDC_CSIS_ACCOUNT lca
where lca.history_end_date = to_date('9999-12-31 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
and lca.history_seq_number = 0
) T3,
(Select lsc.SEI_AREA_NUMBER, lsc.SEI_DISTRICT_NUMBER, lsc.SERVICE_ADDRESS, lsc.SERVICE_CITY, lsc.SEI_PREMISE_NUMBER, lsc.sei_town_id
from LDC_SERVICE_LOCATION lsc
where lsc.history_end_date = to_date('9999-12-31 00:00:00', 'YYYY-MM-DD HH24:MI:SS')
) T2
where T2.sei_town_id = T3.sei_town_id
and T2.sei_premise_number = T3.sei_premise_number
) T32
where T45.CUSTOMER_KEY = T32.CUSTOMER_KEY
and T45.MAILING_ADDRESS_KEY = T32.MAILING_ADDRESS_KEY

********************

output from TKPROF
********************

select count(*)
from
(select * from ldc_customer_data_vw
) inline,
(select *
from LDC_CSIS_REPORT_TRANS
where transaction_code = 33
and op_code >=50
and rp550_id='1'
and post_date between to_date('2007-Oct-01', 'yyyy-mon-dd') and to_date('2007-Nov-01', 'yyyy-mon-dd')
) T1
where t1.ACCOUNT_NUMBER = inline.account_number

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 1078.93 5257.85 5110666 6892723 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 1078.93 5257.85 5110666 6892723 0 1

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: 21 (EDW)

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE
50 NESTED LOOPS
1043306 NESTED LOOPS
1043308 HASH JOIN
1043308 HASH JOIN
372757 TABLE ACCESS BY INDEX ROWID LDC_SERVICE_LOCATION
372758 INDEX RANGE SCAN (object id 3095)
1045519 TABLE ACCESS BY INDEX ROWID LDC_CSIS_ACCOUNT
1045520 INDEX RANGE SCAN (object id 3086)
1047714 TABLE ACCESS BY INDEX ROWID LDC_CSIS_CUSTOMER
1047715 INDEX RANGE SCAN (object id 3082)
2086612 TABLE ACCESS BY INDEX ROWID LDC_CSIS_CUSTOMER_ADDRESS
2086614 INDEX RANGE SCAN (object id 3083)
50 TABLE ACCESS BY INDEX ROWID LDC_CSIS_REPORT_TRANS
1058414 INDEX RANGE SCAN (object id 3091)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT GOAL: CHOOSE
1 SORT (AGGREGATE)
50 NESTED LOOPS
1043306 NESTED LOOPS
1043308 HASH JOIN
1043308 HASH JOIN
372757 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF 'LDC_SERVICE_LOCATION'
372758 INDEX (RANGE SCAN) OF 'LDC_SERVICE_LOCATION_IDX04' (NON-UNIQUE)
1045519 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF 'LDC_CSIS_ACCOUNT'
1045520 INDEX (RANGE SCAN) OF 'JFM01' (NON-UNIQUE)
1047714 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF 'LDC_CSIS_CUSTOMER'
1047715 INDEX (RANGE SCAN) OF 'LDC_CSIS_CUSTOMER_IDX_02' (NON-UNIQUE)
2086612 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF 'LDC_CSIS_CUSTOMER_ADDRESS'
2086614 INDEX (RANGE SCAN) OF 'CUSTOMER_ADDRESS_PK' (UNIQUE)
50 TABLE ACCESS GOAL: ANALYZED (BY INDEX ROWID) OF 'LDC_CSIS_REPORT_TRANS'
1058414 INDEX (RANGE SCAN) OF 'CSIS_REPORT_TRANS_PK' (UNIQUE)




Optimize the query

Chellam, November 28, 2007 - 11:59 pm UTC

Tom:

Any suggestions in rewriting/optimizing this query ?
I am using 9.2.0.6 DB. I gathered stats on the table/index using 
dbms_stats.gather_table_stats(user,'TABLE',CASCADE=> true) ;

Row count in each table used in the QUERY :
===========================================

SQL> select count(*) from customer_location ;

  COUNT(*)
----------
   1561122

SQL> select count(*) from port ;

  COUNT(*)
----------
  29840650

SQL> select count(*) from pvc ;

  COUNT(*)
----------
   3058137

SQL> select count(*) from pe_cos_profile_temp@ECDB2USRP ;

  COUNT(*)
----------
        26

SQL> select count(*) from logical_port@ECDB2USRP ;

  COUNT(*)
----------
    659481

QUERY :
=======
select distinct l.customer_id,port.uso_number,port.port_bill_type,port.mcn, port.grc, port.soc,
l.cust_location_id, l.loc_str2, l.loc_city, l.loc_state, l.loc_zip, l.loc_country, port.clne_incs_ind,
l.LOC_STR1, l.LOC_ROOM, l.LOC_FLOOR, l.LOCATION_BLDG, l.LOC_SUITE, pvc.gams_id, l.geocode_match_criteria,
l.geo_latitude, l.geo_longitude, port.dsl_vendor, port.dsl_type, port.dsl_srvc_options, port.dsl_vendor_cktid
-- pd066.02
, pe1.profile_name ingress_profile, pe2.profile_name egress_profile, port.cpe_max_up_speed upstream_speed,
port.cpe_max_down_speed downstream_speed
from customer_location l, port, pvc
-- pd066.02
, pe_cos_profile_temp@ECDB2USRP pe1, pe_cos_profile_temp@ECDB2USRP pe2, logical_port@ECDB2USRP lp
where
port.mcn='178750   '
and (port.cust_location_id=l.cust_location_id or pvc.a_cust_location_id=l.cust_location_id
or pvc.z_cust_location_id=l.cust_location_id) and
(pvc.a_aise_port_id=port.aise_port_id or pvc.z_aise_port_id=port.aise_port_id) and
port.turn_up_completion_date is null
and PORT.USO_NUMBER IS NOT NULL
and PORT.SALES_ORDER_NAME IS NOT NULL
and port.dsl_type is not null
-- pd066.02
and port.aise_port_id = lp.log_port_id(+)
and lp.ingress_profile_number = pe1.pe_cos_profile_id(+)
and lp.egress_profile_number = pe2.pe_cos_profile_id(+)


TKPROF OUTPUT :
===============

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.42       0.52          0          0          1           0
Execute      1      0.01       0.00          0          0          0           0
Fetch        3    177.11     175.85     546421     549677          0           3
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5    177.54     176.37     546421     549677          1           3

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 171

Rows     Row Source Operation
-------  ---------------------------------------------------
      3  SORT UNIQUE
     14   CONCATENATION
      5    NESTED LOOPS
      5     HASH JOIN OUTER
      5      HASH JOIN OUTER
      5       NESTED LOOPS OUTER
      5        NESTED LOOPS
      1         TABLE ACCESS BY INDEX ROWID OBJ#(233306)
   2404          INDEX RANGE SCAN OBJ#(233461) (object id 233461)
      5         TABLE ACCESS BY INDEX ROWID OBJ#(233334)
      5          INDEX RANGE SCAN OBJ#(233506) (object id 233506)
      5        REMOTE
     26       REMOTE
     26      REMOTE
      5     TABLE ACCESS FULL OBJ#(233262)
      9    NESTED LOOPS
      6     HASH JOIN OUTER
      6      HASH JOIN OUTER
      6       NESTED LOOPS OUTER
      6        NESTED LOOPS
      1         TABLE ACCESS BY INDEX ROWID OBJ#(233306)
   2404          INDEX RANGE SCAN OBJ#(233461) (object id 233461)
      6         TABLE ACCESS BY INDEX ROWID OBJ#(233334)
      6          INDEX RANGE SCAN OBJ#(233504) (object id 233504)
      6        REMOTE
     26       REMOTE
     26      REMOTE
      9     TABLE ACCESS FULL OBJ#(233262)




********************************************************************************

AUTOTRACE PLAN OUTPUT :
=======================

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=36287 Card=101422 By
          tes=28803848)

   1    0   SORT (UNIQUE) (Cost=36287 Card=101422 Bytes=28803848)
   2    1     CONCATENATION
   3    2       NESTED LOOPS (Cost=17090 Card=50711 Bytes=14401924)
   4    3         HASH JOIN (OUTER) (Cost=7532 Card=2 Bytes=370)
   5    4           HASH JOIN (OUTER) (Cost=7529 Card=2 Bytes=290)
   6    5             NESTED LOOPS (OUTER) (Cost=7526 Card=2 Bytes=210
          )

   7    6               NESTED LOOPS (Cost=7524 Card=2 Bytes=132)
   8    7                 TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cos
          t=7460 Card=16 Bytes=688)

   9    8                   INDEX (RANGE SCAN) OF 'PI_MCN' (NON-UNIQUE
          ) (Cost=29 Card=46304)

  10    7                 TABLE ACCESS (BY INDEX ROWID) OF 'PVC' (Cost
          =4 Card=1 Bytes=23)

  11   10                   INDEX (RANGE SCAN) OF 'PVC_Z_AISE_PRT_ID'
          (NON-UNIQUE) (Cost=2 Card=3)

  12    6               REMOTE* (Cost=1 Card=1 Bytes=39)               ECDB2USR
                                                                       P

  13    5             REMOTE* (Cost=2 Card=655 Bytes=26200)            ECDB2USR
                                                                       P

  14    4           REMOTE* (Cost=2 Card=655 Bytes=26200)              ECDB2USR
                                                                       P

  15    3         TABLE ACCESS (FULL) OF 'CUSTOMER_LOCATION' (Cost=477
          9 Card=27926 Bytes=2764674)

  16    2       NESTED LOOPS (Cost=17090 Card=50711 Bytes=14401924)
  17   16         HASH JOIN (OUTER) (Cost=7532 Card=2 Bytes=370)
  18   17           HASH JOIN (OUTER) (Cost=7529 Card=2 Bytes=290)
  19   18             NESTED LOOPS (OUTER) (Cost=7526 Card=2 Bytes=210
          )

  20   19               NESTED LOOPS (Cost=7524 Card=2 Bytes=132)
  21   20                 TABLE ACCESS (BY INDEX ROWID) OF 'PORT' (Cos
          t=7460 Card=16 Bytes=688)

  22   21                   INDEX (RANGE SCAN) OF 'PI_MCN' (NON-UNIQUE
          ) (Cost=29 Card=46304)

  23   20                 TABLE ACCESS (BY INDEX ROWID) OF 'PVC' (Cost
          =4 Card=1 Bytes=23)

  24   23                   INDEX (RANGE SCAN) OF 'PVC_A_AISE_PRT_ID'
          (NON-UNIQUE) (Cost=2 Card=3)

  25   19               REMOTE* (Cost=1 Card=1 Bytes=39)               ECDB2USR
                                                                       P

  26   18             REMOTE* (Cost=2 Card=655 Bytes=26200)            ECDB2USR
                                                                       P

  27   17           REMOTE* (Cost=2 Card=655 Bytes=26200)              ECDB2USR
                                                                       P

  28   16         TABLE ACCESS (FULL) OF 'CUSTOMER_LOCATION' (Cost=477
          9 Card=27926 Bytes=2764674)



  12 SERIAL_FROM_REMOTE            SELECT "LOG_PORT_ID","INGRESS_PROFILE_NUMBER
                                   ","EGRESS_PROFILE_NUMBER" FROM "LOGI

  13 SERIAL_FROM_REMOTE            SELECT "PE_COS_PROFILE_ID","PROFILE_NAME" FR
                                   OM "PE_COS_PROFILE_TEMP" "PE1"

  14 SERIAL_FROM_REMOTE            SELECT "PE_COS_PROFILE_ID","PROFILE_NAME" FR
                                   OM "PE_COS_PROFILE_TEMP" "PE2"

  25 SERIAL_FROM_REMOTE            SELECT "LOG_PORT_ID","INGRESS_PROFILE_NUMBER
                                   ","EGRESS_PROFILE_NUMBER" FROM "LOGI

  26 SERIAL_FROM_REMOTE            SELECT "PE_COS_PROFILE_ID","PROFILE_NAME" FR
                                   OM "PE_COS_PROFILE_TEMP" "PE1"

  27 SERIAL_FROM_REMOTE            SELECT "PE_COS_PROFILE_ID","PROFILE_NAME" FR
                                   OM "PE_COS_PROFILE_TEMP" "PE2"



Statistics
----------------------------------------------------------
          7  recursive calls
          1  db block gets
     549681  consistent gets
     546411  physical reads
        212  redo size
       2893  bytes sent via SQL*Net to client
        479  bytes received via SQL*Net from client
          3  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          3  rows processed

SQL> 

difference between UNION and UNION ALL

A reader, January 16, 2008 - 10:21 am UTC

Hi,

1 SELECT DISTINCT A.FP_ID FP_ID, A.MIRROR_FPID MIRROR_FPID, A.LINK_ID LINK_ID, A.ENTITY ENTITY, A
2 (
3 SELECT HLD.FP_ID FP_ID, LR.LINKED_POSITION_ID MIRROR_FPID, HLD.LINK_ID LINK_ID, HLD.LINK_ENTITY
4 UNION all
5 SELECT HLD.FP_ID FP_ID, LR.POSITION_ID MIRROR_FPID, HLD.LINK_ID LINK_ID, HLD.LINK_ENTITY ENTITY
6 UNION all
7 SELECT HLD.FP_ID FP_ID, '-1' MIRROR_FPID, HLD.LINK_ID LINK_ID, HLD.LINK_ENTITY ENTITY, HLD.DERI
8* ) A
9 /

118 rows selected.


Statistics
----------------------------------------------------------
1716 recursive calls
0 db block gets
52931 consistent gets <----------
5 physical reads
0 redo size
4715 bytes sent via SQL*Net to client
524 bytes received via SQL*Net from client
9 SQL*Net roundtrips to/from client
90 sorts (memory)
0 sorts (disk)
118 rows processed

dagstg@STGPRD1> edit
Wrote file afiedt.buf

1 SELECT DISTINCT A.FP_ID FP_ID, A.MIRROR_FPID MIRROR_FPID, A.LINK_ID LINK_ID, A.ENTITY ENTITY, A
2 (
3 SELECT HLD.FP_ID FP_ID, LR.LINKED_POSITION_ID MIRROR_FPID, HLD.LINK_ID LINK_ID, HLD.LINK_ENTITY
4 UNION
5 SELECT HLD.FP_ID FP_ID, LR.POSITION_ID MIRROR_FPID, HLD.LINK_ID LINK_ID, HLD.LINK_ENTITY ENTITY
6 UNION
7 SELECT HLD.FP_ID FP_ID, '-1' MIRROR_FPID, HLD.LINK_ID LINK_ID, HLD.LINK_ENTITY ENTITY, HLD.DERI
8* ) A
dagstg@STGPRD1> /

118 rows selected.


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
32657394 consistent gets <------
0 physical reads
0 redo size
4671 bytes sent via SQL*Net to client
518 bytes received via SQL*Net from client
9 SQL*Net roundtrips to/from client
3 sorts (memory)
0 sorts (disk)
118 rows processed

The only difference between the 2 SQLs is in UNION ALL
The SQL with UNION ALL takes only a few seconds whereas the one with UNION takes more than 10 minutes. But I was thinking the autotrace stats would show a big number for sorts (for UNION ) but it is the consistent gets numbers which is differing a lot ( even though the change between the SQLs is only in UNION/UNION ALL).

Why are the consistent gets numbers varying rather than the sort numbers ?

The sort numbers have in fact gone down for UNION

thanks
Apraim
Tom Kyte
January 16, 2008 - 3:57 pm UTC

no plan, no comment.

A reader, January 16, 2008 - 10:32 am UTC

hi,

Is it due to the fact that all the data is retrieved from the db side to client side (consistent gets will vary based on arraysize parameter) after which sorting is done because of UNION, that the consistent gets numbers are so high ?

thanks
Apraim
Tom Kyte
January 16, 2008 - 4:01 pm UTC

no, the number of rows are the same.

no plan
no comment

union and union all

A reader, January 16, 2008 - 4:53 pm UTC

The plan itself is different - between union and union all, which is making the consistent gets to go high

I thought the only difference between union and union all - will be in the sort unique to eliminate duplicates, but that is not the case here
Tom Kyte
January 17, 2008 - 11:08 am UTC

sample does give you an n% - about - approx - a sample is random, a 5% random sample might return anywhere between 0 and 100% of the data (you take each row, you roll the dice, you see if that row should be returned - depending on how the dice roll for each row - you get a different set of rows, with different cardinalities)

if you need PRECISELY some number, you will be limited in what you can do.

SQL tune

reader, January 21, 2008 - 2:38 pm UTC

Hi Tom,
Due to some PL/SQL developpers senior left the company, I've been assigned (just get familiar with Oracle from MS SQL knowledge) to help end user for the TUNE of some existing SQLs that we've performance issue.
The SQL STATEMENT below took 1 & half hour to run and return only one row. After suggest to add some Index, the elapse time went down to 1 hour.
Could you please take a look to this SQL STATEMENT below? and enlight me how to TUNE this one.

(*** By the way, I've limited rights on the DB ¿without Create Index, Analyze, DBMS_STAT, ...¿ the TKPROF below was extracted by DBA on demande)

>>> This is the main SELECT STATEMENT created by the front end application <<<
SELECT cl.idno, cl.sin, name, a1.loc_add, a2.bill_add, invno, cl.stat, cl.recv_date, sh.ordno, sh.pack_date, sh.ship_date, sh.last_ship_date
FROM client cl, loc_address a1, bill_address a2, invoice inv, sale sa, shipment sh, View_delivery vw
WHERE cl.idno = sa.idno (+)
AND sa.sano = inv.sano (+)
AND Inv.invno = a2.invno (+)
AND inv.invno = a2.invno (+)
AND cl.Idno = vw.idno (+)
AND cl.Idno = sh.idno (+)
AND cl.recv_date <> to_date('01-01-1900', 'dd-mm-yyyy') -->> hard coding (generated by the application)
AND vw.last_sh_date <= :v_0 -->> where binding variable V_0 is to_date('30-09-2007', 'dd-mm-yyyy')
AND sh.pack_date between :V_1 and :V_2 -->> where v_1 defined as to_date('01-04-2007','DD-MM-YYYY') and v_2 defined as to_date('30-04-2007','DD-MM-YYYY')
GROUP BY cl.idno, cl.sin, name, a1.loc_add, a2.bill_add, invno, cl.stat, cl.recv_date, sh.ordno, sh.pack_date, sh.ship_date, sh.last_ship_date;


TKPROF: Release 9.2.0.6.0 (for the SELECT STATEMENT above)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.01 0 0 0 0
Execute 2 0.00 0.00 0 0 0 0
Fetch 31 5.23 5.85 0 314040 0 1488
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 35 5.23 5.87 0 314040 0 1488

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: XXX

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 31 0.00 0.00
SQL*Net message from client 31 0.00 0.02
SQL*Net more data to client 1 0.00 0.00

(note: CLIENT TBL has 17168 records; LOC_ADDRESS TBL has 17168 records, BILL_ADDRESS TBL has ~3000,
INVOICE TBL has ~200000 records, SALE TBL has ~200000 records, SHIPMENT TBL has ~25000 records)



**** A VIEW called by the above STATEMENT
CREATE or replace view view_delivery (idno, adno, adname, matno, matype ....)
AS
SELECT cl.idno, ad.adno, ad.adname, mat.matno, mat.matype, f_getmax_date(cl.idno) as last_ship_date
FROM client cl, advertise ad, agency ag, material mat, ...
WHERE cl.idno = ad.idno
AND cl.agid = ag.agid
AND cl.maid = mat.maid;



**** A FUNCTION CALLED inside the VIEW
CREATE or replace function f_getmax_date(v_idno IN NUMBER) RETURN DATE
IS
v_max_date DATE;

BEGIN

SELECT MAX(max_date)
INTO v_max_date
FROM
(SELECT cl.idno, MAX(te.initdate) max_date
FROM client cl, tech te, commerce co, task ta
WHERE ta.evid = t2.evid
AND ta.initdate = te.initdate
AND cl.idno = te.techid
AND ta.detid = co.detid
AND ta.on_date = co.on_date
AND co.status = 'A'
AND cl.idno = v_idno
GROUP BY cl.idno
UNION ALL
SELECT cl.idno, MAX(te.initdate)+6 max_date
FROM client cl, tech te, commerce co, task ta
WHERE ta.evid = t2.evid
AND ta.initdate = te.initdate
AND cl.idno = te.techid
AND ta.detid = co.detid
AND ta.on_date = co.on_date
AND co.status = 'I'
AND cl.idno = v_idno
GROUP BY cl.idno);
RETURN v_max_date;
END f_getmax_date;
/

(note: CLIENT TBL has 17168 records; TECH TBL has ~5 million records;
COMMERCE TBL has ~2 million records; TASK TBL has ~27 million records)


TKPROF: Release 9.2.0.6.0 (for the FUNCTION above)
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 22 0 0
Execute 17168 3.09 2.73 0 0 0 0
Fetch 17168 111.03 112.50 0 21355032 0 17168
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 34338 114.12 115.24 0 21355054 0 17168

Misses in library cache during parse: 0
Optimizer goal: CHOOSE
Parsing user id: XXX (recursive depth: 1)

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
latch free 2 0.00 0.00

Tom Kyte
January 21, 2008 - 10:17 pm UTC

just looking at one thing here....
SELECT cl.idno, cl.sin, name, a1.loc_add, a2.bill_add, invno, cl.stat, cl.recv_date, sh.ordno, sh.pack_date, sh.ship_date, sh.last_ship_date
FROM client cl, loc_address a1, bill_address a2, invoice inv, sale sa, shipment sh, View_delivery vw
WHERE cl.idno = sa.idno (+)
AND sa.sano = inv.sano (+)
AND Inv.invno = a2.invno (+)
AND inv.invno = a2.invno (+)
AND cl.Idno = vw.idno (+)
AND cl.Idno = sh.idno (+)
AND cl.recv_date <> to_date('01-01-1900', 'dd-mm-yyyy') -->> hard coding (generated by the application)
AND vw.last_sh_date <= :v_0                    -->> where binding variable V_0 is to_date('30-09-2007', 'dd-mm-yyyy')
AND sh.pack_date between :V_1 and :V_2            -->> where v_1 defined as to_date('01-04-2007','DD-MM-YYYY') and v_2 defined as to_date('30-04-2007','DD-MM-YYYY')
GROUP BY cl.idno, cl.sin, name, a1.loc_add, a2.bill_add, invno, cl.stat, cl.recv_date, sh.ordno, sh.pack_date, sh.ship_date, sh.last_ship_date; 


tell me, please, if we outer join to VW:

AND cl.Idno = vw.idno (+)

how could:

AND vw.last_sh_date <= :v_0

be true? therefore, the outer join is NOT NECESSARY, which implies to me that whomever wrote this query either

a) did not know sql
b) did not understand the question being asked
c) did not understand the data model

likely - it was a, b, and c simultaneously.

therefore, I would encourage you to

a) well, I assume you have already mastered sql, you are tuning it...
b) GET THE QUESTION NAILED DOWN, phrase it in text, write it down, find out what it is, ignore the existing SQL (it is fundementally flawed already)
c) understand that

and start from scratch. Take B) and write the sql new.

(we can say the same about sh, the (+) to sh shows the original coder did not know what they where doing)

SQL tune

reader, January 22, 2008 - 12:59 am UTC

therefore, I would encourage you to

a) well, I assume you have already mastered sql, you are tuning it...
b) GET THE QUESTION NAILED DOWN, phrase it in text, write it down, find out what it is, ignore the existing SQL (it is fundementally flawed already)
c) understand that

and start from scratch. Take B) and write the sql new.

(we can say the same about sh, the (+) to sh shows the original coder did not know what they where doing)


Thanks for your advise Tom.
As I mentioned the SQL statement generated by the front end application. It means the End User select some criteria and the application generate and execute the SQL statement. I've no clue on this application yet since I've been assigned just few days !!! ... I still get to know the structure of DB. There is a lot of statement with outer join need to be fine tune :(
If I'm not wrong that you mentioned as "... affraid to miss some information that's why they use outer join ...", therefore the developpers used that method to implement in this application.
So, there is no way to fine tune this SQL ??? ... I've to build from zero ....
BTW, from Oracle side , how many table can we use in a view ? why I ask .. 'cause there are some existing Views which contain over 50 tables (in a view & a lot of outer join)

Thanks again.
Tom Kyte
January 22, 2008 - 7:01 am UTC

You have access to as many tables as you can type in a SQL statement.

If the sql is being generated
and you cannot change the sql being generated

what do you expect to be able to do in this case? Why should I tell you how the query could be more efficiently written if you won't be able to apply it in practice?


gosh, I hope this doesn't mean:

AND cl.recv_date <> to_date('01-01-1900', 'dd-mm-yyyy') -->> hard coding (generated by the 
application)


they used 1-jan-1900 as "null".



and no one here can/could tune this, the devil is in VW probably - and we cannot see that. (you have ... in the from list, and you bandied about the term "50 tables" - *ouch*)

Anil Kumar Appana, January 22, 2008 - 7:05 am UTC

Hi Tom,

Below given is the explain plan for the query.
If i take off the order by clause i am getting the results set in 4 seconds and with the order by clause it is taking more than a minute.


SELECT cartkey, basketname, ownedby, cartupdatedate, countrycode,
basketcountry, baskettypecode, baskettype, partnerids,
addressshiptonumber, addressshiptoname, originatorname,
basketforwardeddate, cartstatuscode, routestatuscode, lockedby,
basketownedbykey
FROM (SELECT cmgt_oil.cart_key cartkey, cmgt_oil.cart_name basketname,
cmgt_oil.owned_by ownedby,
DECODE (ab_oil_extn.basket_type,
40, ab_oil_promotion.valid_to,
45, ab_oil_promotion.valid_to,
50, ab_oil_promotion.valid_to,
55, ab_oil_promotion.valid_to,
41, ab_oil_promotion.valid_to,
46, ab_oil_promotion.valid_to,
51, ab_oil_promotion.valid_to,
56, ab_oil_promotion.valid_to,
cmgt_oil.update_date + 60
) cartupdatedate,
ab_oil_extn.country_code countrycode,
ctry_lkp.description basketcountry,
ab_oil_extn.basket_type baskettypecode,
basket_type_lkp.description baskettype,
ab_get_partner_ids (cmgt_oil_header.oil_header_key
) partnerids,
cmgt_order_addresses.addr_ref_number addressshiptonumber,
ab_order_address_extn.organization_name addressshiptoname,
ab_get_user_name_from_basket (cmgt_oil_header.oil_header_key
) originatorname,
ab_oil_extn.forwarded_date basketforwardeddate,
cmgt_oil.cart_status_code cartstatuscode,
cmgt_oil.route_status_code routestatuscode,
DECODE (cmgt_oil.route_status_code,
40, ab_get_user_name (cmgt_oil.owned_by),
''
) lockedby,
cmgt_oil.owned_by basketownedbykey,
ab_oil_promotion.valid_to quotepromoexpirydate
FROM cmgt_oil,
ab_oil_extn,
ab_oil_promotion,
cmgt_lookups ctry_lkp,
cmgt_lookups basket_type_lkp,
cmgt_oil_header,
cmgt_order_addresses,
ab_order_address_extn
WHERE cmgt_oil.active_flag = 'Y'
AND cmgt_oil.cart_key = ab_oil_extn.cart_key
AND ab_oil_extn.active_flag(+) = 'Y'
AND ab_oil_extn.ab_oil_promo_id = ab_oil_promotion.ab_oil_promo_id(+)
AND ( ( ab_oil_extn.basket_type IN (10, 30, 60, 70)
AND cmgt_oil.update_date + 60 >= SYSDATE
)
OR ( (ab_oil_extn.basket_type BETWEEN 40 AND 56)
AND ab_oil_promotion.valid_to >= SYSDATE
)
)
AND ab_oil_extn.country_code = ctry_lkp.lookup_code(+)
AND ( (ab_oil_extn.country_code IS NULL)
OR ( ctry_lkp.lookup_type = 'Country'
AND ctry_lkp.active_flag = 'Y'
AND ctry_lkp.locale = 'en_US'
)
)
AND ab_oil_extn.basket_type NOT IN (20)
AND ab_oil_extn.basket_type = basket_type_lkp.lookup_code
AND basket_type_lkp.active_flag = 'Y'
AND basket_type_lkp.locale = 'en_US'
AND basket_type_lkp.lookup_type = 'BasketType'
AND cmgt_oil_header.active_flag = 'Y'
AND cmgt_oil_header.cart_key = cmgt_oil.cart_key
AND cmgt_oil_header.oil_header_key =
cmgt_order_addresses.oil_header_key
AND cmgt_order_addresses.address_type = 6
AND cmgt_order_addresses.active_flag = 'Y'
AND ab_order_address_extn.active_flag(+) = 'Y'
AND cmgt_order_addresses.address_key = ab_order_address_extn.address_key(+)
AND ab_oil_extn.country_code IN (530, 700, 30, 170, 1050)
AND cmgt_oil.cart_status_code <> 30
AND cmgt_oil_header.oil_header_key =
ab_order_address_extn.oil_header_key)
WHERE countrycode = 1050
ORDER BY cartupdatedate ASC;

-----------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 225 | 13311 (8)| 00:02:40 | | |
| 1 | SORT ORDER BY | | 1 | 225 | 13311 (8)| 00:02:40 | | |
|* 2 | FILTER | | | | | | | |
| 3 | NESTED LOOPS OUTER | | 1 | 225 | 13310 (8)| 00:02:40 | | |
| 4 | NESTED LOOPS | | 1 | 186 | 13307 (8)| 00:02:40 | | |
|* 5 | HASH JOIN | | 1141 | 176K| 11017 (10)| 00:02:13 | | |
|* 6 | HASH JOIN | | 1141 | 148K| 7598 (10)| 00:01:32 | | |
|* 7 | HASH JOIN | | 1141 | 133K| 4586 (13)| 00:00:56 | | |
|* 8 | HASH JOIN OUTER | | 4245 | 294K| 1855 (14)| 00:00:23 | | |
|* 9 | HASH JOIN | | 4245 | 240K| 1731 (14)| 00:00:21 | | |
|* 10 | TABLE ACCESS BY INDEX ROWID| CMGT_LOOKUPS | 4 | 156 | 2 (0)| 00:00:01 | | |
|* 11 | INDEX RANGE SCAN | CMGT_LOOKUP_TYPE | 26 | | 1 (0)| 00:00:01 | | |
|* 12 | TABLE ACCESS FULL | AB_OIL_EXTN | 8822 | 163K| 1728 (14)| 00:00:21 | | |
| 13 | TABLE ACCESS FULL | AB_OIL_PROMOTION | 62847 | 797K| 120 (9)| 00:00:02 | | |
|* 14 | TABLE ACCESS FULL | CMGT_OIL | 244K| 11M| 2720 (11)| 00:00:33 | | |
|* 15 | TABLE ACCESS FULL | CMGT_OIL_HEADER | 353K| 4488K| 2996 (4)| 00:00:36 | | |
| 16 | PARTITION RANGE SINGLE | | 707K| 16M| 3387 (9)| 00:00:41 | 6 | 6 |
|* 17 | TABLE ACCESS FULL | CMGT_ORDER_ADDRESSES | 707K| 16M| 3387 (9)| 00:00:41 | 6 | 6 |
|* 18 | TABLE ACCESS BY INDEX ROWID | AB_ORDER_ADDRESS_EXTN | 1 | 28 | 2 (0)| 00:00:01 | | |
|* 19 | INDEX UNIQUE SCAN | AB_ORDER_ADDRESS_EXTN_INDX | 1 | | 1 (0)| 00:00:01 | | |
| 20 | TABLE ACCESS BY INDEX ROWID | CMGT_LOOKUPS | 5 | 195 | 3 (0)| 00:00:01 | | |
|* 21 | INDEX RANGE SCAN | SYS_C003027344 | 5 | | 1 (0)| 00:00:01 | | |
-----------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("AB_OIL_EXTN"."COUNTRY_CODE" IS NULL OR "CTRY_LKP"."LOOKUP_TYPE"='Country' AND "CTRY_LKP"."LOCALE"='en_US'
AND "CTRY_LKP"."ACTIVE_FLAG"='Y')
5 - access("CMGT_OIL_HEADER"."OIL_HEADER_KEY"="CMGT_ORDER_ADDRESSES"."OIL_HEADER_KEY")
6 - access("CMGT_OIL_HEADER"."CART_KEY"="CMGT_OIL"."CART_KEY")
7 - access("CMGT_OIL"."CART_KEY"="AB_OIL_EXTN"."CART_KEY")
filter(("AB_OIL_EXTN"."BASKET_TYPE"=10 OR "AB_OIL_EXTN"."BASKET_TYPE"=30 OR "AB_OIL_EXTN"."BASKET_TYPE"=60 OR
"AB_OIL_EXTN"."BASKET_TYPE"=70) AND INTERNAL_FUNCTION("CMGT_OIL"."UPDATE_DATE")+60>=SYSDATE@! OR
"AB_OIL_EXTN"."BASKET_TYPE">=40 AND "AB_OIL_EXTN"."BASKET_TYPE"<=56 AND "AB_OIL_PROMOTION"."VALID_TO">=SYSDATE@!)
8 - access("AB_OIL_EXTN"."AB_OIL_PROMO_ID"="AB_OIL_PROMOTION"."AB_OIL_PROMO_ID"(+))
9 - access("AB_OIL_EXTN"."BASKET_TYPE"="BASKET_TYPE_LKP"."LOOKUP_CODE")
10 - filter("BASKET_TYPE_LKP"."LOCALE"='en_US' AND "BASKET_TYPE_LKP"."ACTIVE_FLAG"='Y' AND
"BASKET_TYPE_LKP"."LOOKUP_CODE"<>20)
11 - access("BASKET_TYPE_LKP"."LOOKUP_TYPE"='BasketType')
12 - filter("AB_OIL_EXTN"."COUNTRY_CODE"=1050 AND "AB_OIL_EXTN"."ACTIVE_FLAG"='Y' AND "AB_OIL_EXTN"."BASKET_TYPE"<>20)
14 - filter("CMGT_OIL"."CART_STATUS_CODE"<>30 AND "CMGT_OIL"."ACTIVE_FLAG"='Y')
15 - filter("CMGT_OIL_HEADER"."ACTIVE_FLAG"='Y')
17 - filter("CMGT_ORDER_ADDRESSES"."ADDRESS_TYPE"=6 AND "CMGT_ORDER_ADDRESSES"."ACTIVE_FLAG"='Y')
18 - filter("AB_ORDER_ADDRESS_EXTN"."ACTIVE_FLAG"='Y')
19 - access("CMGT_OIL_HEADER"."OIL_HEADER_KEY"="AB_ORDER_ADDRESS_EXTN"."OIL_HEADER_KEY" AND
"CMGT_ORDER_ADDRESSES"."ADDRESS_KEY"="AB_ORDER_ADDRESS_EXTN"."ADDRESS_KEY")
21 - access("CTRY_LKP"."LOOKUP_CODE"(+)=1050)

Please help understand more about this.

Thanks in Advance.
A.Anil Kumar
Tom Kyte
January 22, 2008 - 7:37 am UTC

I doubt you are getting the results in 4 seconds.

More likely this is true:

when I remove the order by, and oracle does not have to get the last row before it can return the first row, I get the first row in 4 seconds, but it takes a minute to get ALL OF THE ROWS.

when I have the order by, and of course Oracle has to get the last row before the first row can be returned in my case, I wait a minute to get the first row and get all of the rows in a minute


EG: the throughput of this query is identical regardless of order by in real life, you are using a "tool" such as toad that shows you the first couple of rows and STOPS. Use page down, get the ENTIRE result set and then tell me what happens...



funny how you order by cartupdatedate

but I don't see cartupdatedate ANYWHERE in the query - eg: that puppy doesn't work.

Anil Kumar Appana, January 22, 2008 - 7:53 am UTC

Hi Tome,

Is the place where we are using the cartupdatekey.

DECODE (ab_oil_extn.basket_type,
40, ab_oil_promotion.valid_to,
45, ab_oil_promotion.valid_to,
50, ab_oil_promotion.valid_to,
55, ab_oil_promotion.valid_to,
41, ab_oil_promotion.valid_to,
46, ab_oil_promotion.valid_to,
51, ab_oil_promotion.valid_to,
56, ab_oil_promotion.valid_to,
cmgt_oil.update_date + 60
) cartupdatedate

And also see following the Tkprof output for the 500 rows.

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 1.89 1.88 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 15.62 70.42 56695 443073 0 500
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 17.51 72.30 56695 443073 0 500

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 917

Rows Row Source Operation
------- ---------------------------------------------------
500 SORT ORDER BY (cr=443073 pr=56695 pw=0 time=68725493 us)
10118 FILTER (cr=128690 pr=48613 pw=0 time=55794029 us)
80944 NESTED LOOPS OUTER (cr=128690 pr=48613 pw=0 time=144673683 us)
10118 NESTED LOOPS (cr=78098 pr=48607 pw=0 time=53179546 us)
10118 HASH JOIN (cr=47742 pr=44815 pw=0 time=32917536 us)
10118 HASH JOIN (cr=33759 pr=30842 pw=0 time=5796788 us)
10118 HASH JOIN (cr=20812 pr=17905 pw=0 time=12942499 us)
237914 HASH JOIN OUTER (cr=7235 pr=7222 pw=0 time=2073862 us)
237914 HASH JOIN (cr=6780 pr=6771 pw=0 time=1953073 us)
12 TABLE ACCESS BY INDEX ROWID CMGT_LOOKUPS (cr=4 pr=4 pw=0 time=30792 us)
26 INDEX RANGE SCAN CMGT_LOOKUP_TYPE (cr=2 pr=2 pw=0 time=22249 us)(object id 2193111)
237914 TABLE ACCESS FULL AB_OIL_EXTN (cr=6776 pr=6767 pw=0 time=1442078 us)
62848 TABLE ACCESS FULL AB_OIL_PROMOTION (cr=455 pr=451 pw=0 time=93099 us)
134313 TABLE ACCESS FULL CMGT_OIL (cr=13577 pr=10683 pw=0 time=1344314 us)
510782 TABLE ACCESS FULL CMGT_OIL_HEADER (cr=12947 pr=12937 pw=0 time=1045337 us)
707132 PARTITION RANGE SINGLE PARTITION: 6 6 (cr=13983 pr=13973 pw=0 time=2130948 us)
707132 TABLE ACCESS FULL CMGT_ORDER_ADDRESSES PARTITION: 6 6 (cr=13983 pr=13973 pw=0 time=1423741 us)
10118 TABLE ACCESS BY INDEX ROWID AB_ORDER_ADDRESS_EXTN (cr=30356 pr=3792 pw=0 time=13257654 us)
10118 INDEX UNIQUE SCAN AB_ORDER_ADDRESS_EXTN_INDX (cr=20238 pr=1245 pw=0 time=4391812 us)(object id 2192805)
80944 TABLE ACCESS BY INDEX ROWID CMGT_LOOKUPS (cr=50592 pr=6 pw=0 time=329595 us)
80944 INDEX RANGE SCAN SYS_C003027344 (cr=10120 pr=2 pw=0 time=138785 us)(object id 2193113)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 3 0.00 0.00
SQL*Net message from client 3 26.56 50.24
db file sequential read 3818 0.09 12.95
db file scattered read 2880 0.06 4.72
SQL*Net more data to client 33 1.38 1.69
********************************************************************************

Thanks in advance.
A.Anil Kumar
Tom Kyte
January 22, 2008 - 6:18 pm UTC

do you get what I'm saying though - you need to get the last row before you can return the first row if you sort by:
        DECODE (ab_oil_extn.basket_type,
                40, ab_oil_promotion.valid_to,
                45, ab_oil_promotion.valid_to,
                50, ab_oil_promotion.valid_to,
                55, ab_oil_promotion.valid_to,
                41, ab_oil_promotion.valid_to,
                46, ab_oil_promotion.valid_to,
                51, ab_oil_promotion.valid_to,
                56, ab_oil_promotion.valid_to,
                cmgt_oil.update_date + 60
                ) cartupdatedate, 

that is ordering by attributes from two different tables (eg: an index would not be able to retrieve the data sorted even, you order by something from two different segments)


and sqlnet message from client means --- we waited for the client to tell us to do something - so, there was really only 18 seconds of wait time there (for some 6,000 physical IO's)

Your tkprof for 500 rows with and without the order by would be similar - the presence of the order by is not the problem, the problem is it is a large query hitting a ton of data. nothing I can fix here in a review followup.

Regular query tuning 101 chore for you.


I hate it when I see inappropriate uses of outer joins..

<b>AND ab_order_address_extn.active_flag(+) = 'Y'
 AND cmgt_order_addresses.address_key = ab_order_address_extn.address_key(+)</b>
 AND ab_oil_extn.country_code IN (530, 700, 30, 170, 1050)
 AND cmgt_oil.cart_status_code <> 30<b>
 AND cmgt_oil_header.oil_header_key = ab_order_address_extn.oil_header_key) </b>



if we outer join to ab_order_address_extn, then oil_header_key will be NULL and that is never equal to anything, hence the outer join is not necessary - the presence of it makes me question if the author of the query knew what it was they were querying for in the first place.

that might be the best place to start - by erasing this query from your mind and going back to the documentation for the system to determine what this result was intended to be - studying the data model to understand the relationships and write the query from scratch using only that knowledge.

SQL Tuning

reader, January 22, 2008 - 4:45 pm UTC

gosh, I hope this doesn't mean:

AND cl.recv_date <> to_date('01-01-1900', 'dd-mm-yyyy') -->> hard coding (generated by the application)

they used 1-jan-1900 as "null".



That's what it is, they do not allow NULL in recv_date ...
Actually, that VIEW has only 10 tables, and I narrow down with 4 tables (tune it) the ",..." was my typo ... :)
The problem is the function "f_getmax_date(cl.idno)" call in the VIEW which take so long (over 1 hour), that function combine 4 tables as I mentioned earlier.
I did ask DBA to do the partition on the field "ON_DATE" for the 2 big tables (TECH TBL and TASK TBL) in order to tune the FUNCTION with date range (to satisfy the criteria of the End User choose from begining as "last_sh_date")

Is there a way to pass Parameter in a VIEW? in order to pass a date range in my new function call by the VIEW. Currently, the part that I help on this application, it uses only the view to output query on screen for user !!!!

Thanks.
(Note: the result of the VIEW return in 3ms if there is no "last_sh_date" criteria selected by user)
Tom Kyte
January 22, 2008 - 6:45 pm UTC

You need to revise this sentence then:

... Due to some PL/SQL developpers senior left the company, ...


they were not senior.

Oh great, they stuffed a plsql "getter" function in there instead of just using sql :(


search this site for


parameterized view

how to do tuning on the query with bind variable

HelloKitty, February 11, 2008 - 3:01 pm UTC

Hey Tom:

I have read something about the disadvantage of the bind variable. acutally, we have an query having this problem. when we use the true value, the query is using index, but when we use bind variable, the optimizor is using full table scan. and we the query is used very often from the sites. so if we don't use bind variable, the hard parse will kill us. so what shall we do?

table alias name for columns will speed up the query processing

Lutz Hartmann, February 18, 2008 - 12:08 pm UTC

Question was:
1) using table alias name for columns will speed up the query processing or is just only for
readability.
i.e Select e.empno,e.ename,d.dname,d.loc instead of
Select empno,ename,dname,loc as mentioned above.

My answer is taken from the manual:
http://download.oracle.com/docs/cd/B28359_01/server.111/b28286/queries002.htm#sthref3207

"...However, it is always a good idea to qualify table and column references explicitly. Oracle often does less work with fully qualified table and column names..."
Lutz Hartmann
sysdba database consulting GmbH
Tom Kyte
February 18, 2008 - 2:04 pm UTC

well, we'll file a documentation bug then.

same amount of cpu, same amount of latching, about the same work done.

this is not to say "do not use correlation names" - use them, they are good, they are excellent.

this is to say "do not believe you are doing a performance thing when you do it, you are doing a good coding practice thing"

ops$tkyte%ORA10GR2> create table emp as select * from scott.emp;

Table created.

ops$tkyte%ORA10GR2> create table dept as select * from scott.dept;

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> declare
  2          l_cursor sys_refcursor;
  3  begin
  4          for i in 1..1000
  5          loop
  6                  open l_cursor for 'select empno, ename, dname, loc from emp, dept where 1='||i;
  7                  close l_cursor;
  8          end loop;
  9  end;
 10  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> declare
  2          l_cursor sys_refcursor;
  3  begin
  4          for i in 1..1000
  5          loop
  6                  open l_cursor for 'select e.empno, e.ename, d.dname, d.loc from emp e, dept d where 1='||i;
  7                  close l_cursor;
  8          end loop;
  9  end;
 10  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> exec runStats_pkg.rs_stop(500);
Run1 ran in 196 hsecs
Run2 ran in 198 hsecs
run 1 ran in 98.99% of the time

Name                                  Run1        Run2        Diff
STAT...physical read total byt      16,384           0     -16,384
STAT...physical read bytes          16,384           0     -16,384
STAT...session pga memory         -393,216      65,536     458,752

Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
156,803     157,821       1,018     99.35%

PL/SQL procedure successfully completed.

question about SQL tuning with CBO

A reader, February 19, 2008 - 2:23 pm UTC

hey Tom:

we are in 10gr2 now. and if I am not mistaken 10gr2 is automatically using CBO right? and if this is true, does it matter if we change the order of the conditions in the where clause? will the CBO optimizer will choose the different plan?

one example, one query with multiple joins on couple of tables, will the join order will be affected by the order of the conditions in the where clause?

And another example, there are 3 columns in one index. and when the table is accessed by index, will the order of the columns will affect the consistent gets and physical gets?

Thank you very very much!
Tom Kyte
February 20, 2008 - 7:50 am UTC

In general, the order of predicates will not affect the plan. The optimizer is using cpu and io costing in 10g, and takes the relative 'cost' of executing each bit of the where clause and does them in the least costly order.

the join orders are not going to be materially affected by the order of predicates.


.. And another example, there are 3 columns in one index. and when the table
is accessed by index, will the order of the columns will affect the consistent
gets and physical gets? ..

of course, unless you use equality on all three.

ops$tkyte%ORA10GR2> create table t
  2  as
  3  select all_objects.*
  4    from all_objects
  5  /

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx1 on t(object_id,owner,object_name);

Index created.

ops$tkyte%ORA10GR2> create index t_idx2 on t(owner,object_name,object_id);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set termout off
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace on
ops$tkyte%ORA10GR2> select /*+ index( t t_idx1 ) */ *
  2    from t
  3   where owner = USER
  4     and object_name = 'T'
  5     and object_id > 0;

OWNER                          OBJECT_NAME                    SUBOBJECT_NAME                  OBJECT_ID DATA_OBJECT_ID OBJECT_TYPE         CREATED   LAST_DDL_ TIMESTAMP           STATUS  T G S
------------------------------ ------------------------------ ------------------------------ ---------- -------------- ------------------- --------- --------- ------------------- ------- - - -
OPS$TKYTE                      T                                                                 156990         156990 TABLE               20-FEB-08 20-FEB-08 2008-02-20:08:13:23 VALID   N N N


Execution Plan
----------------------------------------------------------
Plan hash value: 4055207394

--------------------------------------------------------------------------------------
| Id  | Operation                   | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |        |     1 |   128 |   339   (2)| 00:00:02 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T      |     1 |   128 |   339   (2)| 00:00:02 |
|*  2 |   INDEX RANGE SCAN          | T_IDX1 |     1 |       |   338   (2)| 00:00:02 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OBJECT_ID">0 AND "OWNER"=USER@! AND "OBJECT_NAME"='T')
       filter("OWNER"=USER@! AND "OBJECT_NAME"='T')

Note
-----
   - dynamic sampling used for this statement


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        320  consistent gets
          0  physical reads
          0  redo size
       1203  bytes sent via SQL*Net to client
        385  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA10GR2> select /*+ index( t t_idx2 ) */ *
  2    from t
  3   where owner = USER
  4     and object_name = 'T'
  5     and object_id > 0;

OWNER                          OBJECT_NAME                    SUBOBJECT_NAME                  OBJECT_ID DATA_OBJECT_ID OBJECT_TYPE         CREATED   LAST_DDL_ TIMESTAMP           STATUS  T G S
------------------------------ ------------------------------ ------------------------------ ---------- -------------- ------------------- --------- --------- ------------------- ------- - - -
OPS$TKYTE                      T                                                                 156990         156990 TABLE               20-FEB-08 20-FEB-08 2008-02-20:08:13:23 VALID   N N N


Execution Plan
----------------------------------------------------------
Plan hash value: 3371054274

--------------------------------------------------------------------------------------
| Id  | Operation                   | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |        |     1 |   128 |     3   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T      |     1 |   128 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX2 |     1 |       |     2   (0)| 00:00:01 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OWNER"=USER@! AND "OBJECT_NAME"='T' AND "OBJECT_ID">0)

Note
-----
   - dynamic sampling used for this statement


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
       1203  bytes sent via SQL*Net to client
        385  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA10GR2> set autotrace off


In general, you want things that you use "=" in the "front" of the index and things you range on at the "end"

See how when we lead with object_id > 0 - it takes 320 IOs (we ended up range scanning the entire index)

when we lead with owner = ? and object_name = ? - it takes 4 IO's - we find the index entries and then range scan over just them for object_id > 0 - and that is easy to do.

A reader, February 20, 2008 - 9:22 am UTC

Thank you very very much for your detail explanation. that is very helpful to me!!!

SQL> desc reporting_data
Name Null? Type
----------------------------------------- -------- ----------------------------
RD_ID NUMBER
PAGE_ID NOT NULL NUMBER
HTTP_ID NOT NULL NUMBER
HIT_DATE NOT NULL DATE
HIT_COUNT NOT NULL NUMBER
RP_ID NOT NULL NUMBER
LAST_UPDATE NOT NULL DATE
CREATE_DATE NOT NULL DATE
C_ID NOT NULL NUMBER
PACKAGE_FLAG VARCHAR2(10)
PACKAGE_ID NUMBER

GLOBAL INDEX ON (C_ID, HIT_DATE, HTTP_ID,PAGE_ID)

table partitioned on hit_date by month

we have two queries:

first one:predicates not in the same order with index


select sum(hit_count) as count
from reporting_data
where c_id in (263300,263200)
and http_id = 2
and page_id = 1
and hit_date between to_date('02-JAN-08','DD-MON-YY')
and to_date('03-JAN-08','DD-MON-YY')


second one: predicates in the same order of index

select sum(hit_count) as count
from reporting_data
where c_id in (263300,263200)
and hit_date between to_date('02-JAN-08','DD-MON-YY')
and to_date('03-JAN-08','DD-MON-YY')
and http_id = 2
and page_id = 1

so will the predicates affect the stats (consistent gets...)?
actually, I found the same index is being used all the time. And the information under
"Predicate Information (identified by operation id): " are the same too. gets are different,
Not sure if it comes from the cache or from change on the order of the predicates.
But I checked in the tkprof, the second query got hard parsed too.

"Misses in library cache during parse: 1"


and another question:

we have such pain during tuning queries in the sqlplus, because we can not see the real consistent gets.
when the query is get executed second time, the gets is less and the time is shorter too. we have to wait
for long time to execute it again, but sometime it is still cached.

is there any way to see the time and stats every time I run the query? I heard something about flush the shared memory,
but this is impossible for us, since it is production database.
Tom Kyte
February 20, 2008 - 9:54 am UTC

the order of the predicate is not meaningful (as stated)

the OPERATORS YOU USE are.


given:

where c_id in (263300,263200)
and http_id = 2
and page_id = 1
and hit_date between to_date('02-JAN-08','DD-MON-YY')
and to_date('03-JAN-08','DD-MON-YY')


in ANY ORDER, you would want http_id, page_id FIRST (for the equals) and probably C_ID next and probably hit_date last

think about what needs to be done to walk the index to retrieve your data (close eyes, visualize it - we can find

http_id = 2, page_id = 1, c_id = 263300 and hit_date >= to_date('02-JAN-08','DD-MON-YY'), range scan until hit_date exceeds our upper bound and then

find
http_id = 2, page_id = 1, c_id = 263200 and hit_date >= to_date('02-JAN-08','DD-MON-YY'), range scan until hit_date exceeds our upper bound

and be done.

If hit_date were first, we'd have to inspect EVERYTHING with that hit date to find the rows of interest.



... we have such pain during tuning queries in the sqlplus, because we can not see the real consistent gets.
when the query is get executed second time, the gets is less and the time is shorter too. we have to wait
for long time to execute it again, but sometime it is still cached. ...


that is not true, consistent gets are CACHE gets - they will not go down.

but maybe the physical IO will.


do not tune on a production database, just stop that, that is not sane.

A reader, February 20, 2008 - 10:48 am UTC

Thank you very much, Tom. I am clear with this now.

for the second issue:

yes, the consistent gets are not changing that much. physical gets did. and also the recursive call. I read something, it says "Recursive calls are also generated
when data dictionary information is not available in the data dictionary cache and must be retrieved from disk."

so when executing the query second time, we most likely see the recursive call is getting dropped. is that because the info is still cached in the data dictionary? and what is this info in the data dictionary?

and another situation: I executed the couple of times. execute it, then after a while I execute it again. and get the stats like following:

stats for one time:

Elapsed: 00:01:37.46

Statistics
----------------------------------------------------------
415 recursive calls
0 db block gets
39653 consistent gets
7792 physical reads
0 redo size
1336 bytes sent via SQL*Net to client
510 bytes received via SQL*Net from client
4 SQL*Net roundtrips to/from client
5 sorts (memory)
0 sorts (disk)
36 rows processed


stats for another time:

Elapsed: 00:00:10.18

Statistics
----------------------------------------------------------
1090 recursive calls
0 db block gets
39793 consistent gets
7081 physical reads
0 redo size
1336 bytes sent via SQL*Net to client
510 bytes received via SQL*Net from client
4 SQL*Net roundtrips to/from client
25 sorts (memory)
0 sorts (disk)
36 rows processed

the consistent gets, and physical gets don't have much difference. even the longer one has less recursive call. but how come the time has so much difference?


I appreciated your quick response!!

Tom Kyte
February 20, 2008 - 12:46 pm UTC

... "Recursive calls are also generated
when data dictionary information is not available in the data dictionary cache and must be retrieved from disk." ..

that is not true.

Recursive SQL is SQL executed in order to execute your SQL. Type in a brand new query and you'll hard parse. We MIGHT have to execute SQL in order to process your SQL, that SQL may or may not hit the disk.

and you should see the recursive sql go away, that is correct - and desirable. Because in real life, you will have executed the sql once already and subsequent executions won't do the recursive sql (unless that recursive sql is doing something else like space management or sequence advancing or whatever)


as for "why did it run faster", likely - you are using conventional buffered file systems. When you did the IO the first time, it was a true physical IO. The second time you did the IO, we didn't have it in OUR cache, but the operating system did have it in ITS file system cache. So, Oracle issues an IO call, but the OS says "oh, don't bother, here it is".

See:


http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:7413988573867

A reader, February 20, 2008 - 1:07 pm UTC

GREAT, THANK YOU TOM!!!

YOU ARE THE BEST!!

question about tuning

A reader, February 22, 2008 - 9:53 am UTC

Hey Tom:

I think about hte index again. we can still use the same example:

where c_id in (263300,263200)
and http_id = 2
and page_id = 1
and hit_date between to_date('02-JAN-08','DD-MON-YY')
and to_date('03-JAN-08','DD-MON-YY')

do we always need to put the column which has the "=" operator in the predicates as the leading or front columns in the index?

or we just put the most selective ones in the leading position.

like here, the whole table has 500 million records. half of them with http_id =1, half of them have http_id=2. (so each value has 250 million records.) but through "and hit_date between to_date('02-JAN-08','DD-MON-YY') and to_date('03-JAN-08','DD-MON-YY') ", there are 120 million.
if we use page_id, it also retures more records than using the hit_date.

now, page_id and http_id are using "=" and hit_date is using ">=" and "<=", so which column should be the leading column of hte index. the most selective one, or the "=" one?

Tom Kyte
February 22, 2008 - 12:12 pm UTC

... do we always need to put the column which has the "=" operator in the
predicates as the leading or front columns in the index? ..

no, but think about the work that needs be done, it usually makes the most sense to do so.

with this,

where c_id in (263300,263200)
and http_id = 2
and page_id = 1
and hit_date between to_date('02-JAN-08','DD-MON-YY')
and to_date('03-JAN-08','DD-MON-YY')

c_id, http_id, page_id are all candidates for being "first" (c_id will probably be an inlist iterator - like a big "or" statement)


or we just put the most selective ones in the leading position.


That has NEVER BEEN TRUE, discard that thought from you mind. the distinct cardinality of a column has nothing whatsoever to do with its placement in the index, how you query the table does.

consider: copy all_objects into t.

you have three questions:

show me scotts stuff
show me scotts tables
show me scotts emp table

what index makes sense? index i on t(owner,object_type,object_name)

object_name is most selective.
object_name belongs LAST.
because of the set of questions you ask.


I already told you what index makes sense here

http_id, page_id, c_id, hit_date

it'll go RIGHT to the first (http_id,page_id,c_id,hit_date) - RIGHT THERE, regardless of the distinct cardinality of the leading edge. It can then range scan and hit JUST INDEX ENTRIES THAT ARE RELEVANT, there will be nothing in the index it hits it cannot use. Until it finds the last row.

A reader, February 22, 2008 - 1:31 pm UTC

Thank you Tom. I will digest this a little bit and try it on my test table. and I am reading your book now. Those books are fatastic. It sounds like they are just for me! They answer a lot of my questions.

book recommandation

A reader, February 22, 2008 - 4:32 pm UTC

Hey Tom:

one question, have you written any book about the data warehousing? If yes, what is the name? if not, do you have any recommandation for me?

Thank you very much!

Tom Kyte
February 22, 2008 - 4:38 pm UTC

not on warehousing in particular, only on how Oracle works.

A reader, February 25, 2008 - 4:37 pm UTC

ok, thank you!

SQL Tuning using CASE and WITH

Shubhasree, February 29, 2008 - 4:07 am UTC

Hi Tom,

I have query which is UNION of 2 similar queries. Each of these 2 queries are exactly same except just 1 WHERE condition. Due to this, each and every table is scanned 2 times which I believe would reduce it to one-pass if we write the query using WITH (extracting the common part) and writing the uncommon separaetly OR using CASE in WHERE clause.

SELECT sfk_acc.acc_nbr AS sfkacc, sc.sc_id AS sc, scaa.acc_nbr AS cptyscaa,
       inx.m_client_of_cpty_agent AS ptysca,
       (SELECT acc_nbr
          FROM sfk_acc s
         WHERE s.sfk_acc_db_id =
                              inx.m_sfk_acc_id_matc_cpty_client)
                                                                AS cptyclient,
       sec_local_code.local_code AS localsec, sec.isin AS isin,
       inx_client_info.c_client_inx_ref_id AS clientref,
       inx.our_reference AS ourreference,
       inx_client_info.p_status AS insstatus,
       inx_client_info.p_qty AS quantity,
       inx_client_info.p_cash_amnt AS cashamount, exec.deal_type AS issedeal,
       inx_client_info.p_cash_amnt_ccy AS cashamountccy,
       inx.trade_date AS tradedate, inx.esd AS asd,
       exec.contract_note AS typeofcontract,
       exec.deal_price_value AS tradeprice, '' AS brokerage, '' AS commission,
       se.se_id AS selocation, exec.price_difference_value AS pricedifference,
       inx.m_sc_inx_reference_id AS screference,
       exec.se_deal_trade_date_time AS tradetime,
       SYSDATE AS reportgentimestamp,
       exec.se_deal_trade_date_time AS executiontimetag72,
       exec.exec_time AS executiontimetag30,
       exec.se_reference AS sedealnumber,
       exec.reconciliation_ind AS reconciliationindicator,
       inx_client_info.c_reason_code AS failurereasoncode,
       inx_client_info.p_status AS instructionstatusasname,
       exec.trading_system_reference AS xetrareference,
       exec.trader_id AS traderreference, exec.netting_type AS nettingtype,
       exec.ccp_ind AS isccpinvolved, exec.agent_prop_trading AS acctype,
       sec.short_name AS securityname, sec.sec_cfi_category AS cficategory,
       inx_client_info.p_securities_way AS way, '' AS tradingsuffix,
       '' AS kepler, inx.TYPE AS inxtype,                                 inx.SUBTYPE AS inxsubtype                                   
  FROM se,
       exec,
       inx,
       sc,
       sfk_acc,
       inx_client_info,
       scaa,
       sec,
       sec_local_code,
       (SELECT p_status, inx_client_info_db_id
          FROM inx_client_info
         WHERE p_status IN ('MATC', 'COMP', '2BVA', 'PROV')
        UNION ALL
        (SELECT p_status, inx_client_info_db_id
           FROM inx_client_info
          WHERE (    inx_client_info.p_status = 'SETT'
                 AND inx_client_info.p_asd = (SYSDATE - 30)
                )
             OR (    inx_client_info.p_status = 'CAND'
                 AND TRUNC (inx_client_info.updating_date) = (SYSDATE - 30)
                ))) pstatus
 WHERE se.se_db_id(+) = exec.se_db_id
   AND (inx.inx_db_id = exec.inx_db_id(+)
        AND inx.original_mother_inx_db_id IS NULL)
   AND sc.sc_db_id = inx.m_sc_db_id_sc
   AND sfk_acc.sfk_acc_db_id = inx_client_info.c_sfk_acc_db_id
   AND scaa.scaa_db_id = inx.m_scaa_id_cpty_agent
   AND inx_client_info.inx_db_id = inx.inx_db_id
   AND inx.sec_db_id = sec.sec_db_id
   AND sec.sec_db_id = sec_local_code.sec_db_id(+)
   AND sec_local_code.nbr_scheme_type = 'WKN'
   AND sfk_acc.sfk_acc_db_id = 10000005463
   AND inx.m_agent_location NOT IN ('ALEG', 'SCMG')
   AND pstatus.inx_client_info_db_id = inx_client_info.inx_client_info_db_id
UNION
SELECT sfk_acc.acc_nbr AS sfkacc, sc.sc_id AS sc, scaa.acc_nbr AS cptyscaa,
       inx.m_client_of_cpty_agent AS ptysca,
       (SELECT acc_nbr
          FROM sfk_acc s
         WHERE s.sfk_acc_db_id =
                              inx.m_sfk_acc_id_matc_cpty_client)
                                                                AS cptyclient,
       sec_local_code.local_code AS localsec, sec.isin AS isin,
       inx_client_info.c_client_inx_ref_id AS clientref,
       inx.our_reference AS ourreference,
       inx_client_info.p_status AS insstatus,
       inx_client_info.p_qty AS quantity,
       inx_client_info.p_cash_amnt AS cashamount, exec.deal_type AS issedeal,
       inx_client_info.p_cash_amnt_ccy AS cashamountccy,
       inx.trade_date AS tradedate, inx.esd AS asd,
       exec.contract_note AS typeofcontract,
       exec.deal_price_value AS tradeprice, '' AS brokerage, '' AS commission,
       se.se_id AS selocation, exec.price_difference_value AS pricedifference,
       inx.m_sc_inx_reference_id AS screference,
       exec.se_deal_trade_date_time AS tradetime,
       SYSDATE AS reportgentimestamp,
       exec.se_deal_trade_date_time AS executiontimetag72,
       exec.exec_time AS executiontimetag30,
       exec.se_reference AS sedealnumber,
       exec.reconciliation_ind AS reconciliationindicator,
       inx_client_info.c_reason_code AS failurereasoncode,
       inx_client_info.p_status AS instructionstatusasname,
       exec.trading_system_reference AS xetrareference,
       exec.trader_id AS traderreference, exec.netting_type AS nettingtype,
       exec.ccp_ind AS isccpinvolved, exec.agent_prop_trading AS acctype,
       sec.short_name AS securityname, sec.sec_cfi_category AS cficategory,
       inx_client_info.p_securities_way AS way, '' AS tradingsuffix,
       '' AS kepler, inx.TYPE AS inxtype,                          
       inx.SUBTYPE AS inxsubtype                                   
  FROM se,
       exec,
       inx,
       sc,
       sfk_acc,
       inx_client_info,
       scaa,
       sec,
       sec_local_code,
       (SELECT p_status, inx_client_info_db_id
          FROM inx_client_info
         WHERE p_status IN ('MATC', 'COMP', '2BVA', 'PROV')
        UNION ALL
        (SELECT p_status, inx_client_info_db_id
           FROM inx_client_info
          WHERE (    inx_client_info.p_status = 'SETT'
                 AND inx_client_info.p_asd = (SYSDATE - 30)
                )
             OR (    inx_client_info.p_status = 'CAND'
                 AND TRUNC (inx_client_info.updating_date) = (SYSDATE - 30)
                ))) pstatus
 WHERE se.se_db_id(+) = exec.se_db_id
   AND (   (    inx.original_mother_inx_db_id = exec.inx_db_id(+)
            AND inx.original_mother_inx_db_id IS NOT NULL
           )
        OR (inx.inx_db_id = exec.inx_db_id(+)
            AND inx.original_mother_inx_db_id IS NULL)
       )
   AND sc.sc_db_id = inx.m_sc_db_id_sc
   AND sfk_acc.sfk_acc_db_id = inx_client_info.c_sfk_acc_db_id
   AND scaa.scaa_db_id = inx.m_scaa_id_cpty_agent
   AND inx_client_info.inx_db_id = inx.inx_db_id
   AND inx.sec_db_id = sec.sec_db_id
   AND sec.sec_db_id = sec_local_code.sec_db_id(+)
   AND sec_local_code.nbr_scheme_type = 'WKN'
   AND sfk_acc.sfk_acc_db_id = 10000005463
   AND inx.m_agent_location NOT IN ('ALEG', 'SCMG')
   AND pstatus.inx_client_info_db_id = inx_client_info.inx_client_info_db_id;


Could you please help me writing it in a better performant way?
Tom Kyte
March 01, 2008 - 10:23 am UTC

not getting something:

diff -b t1 t2
57c57,60
<    AND (inx.inx_db_id = exec.inx_db_id(+)
---
>    AND (   (    inx.original_mother_inx_db_id = exec.inx_db_id(+)
>             AND inx.original_mother_inx_db_id IS NOT NULL
>            )
>         OR (inx.inx_db_id = exec.inx_db_id(+)
58a62
>        )



that is the only difference between them.

umm, am I missing something - I see an OR there, so the second query actually retrieves what the FIRST query retrieved already - and then the UNION (which distincts) gets rid of them.

Can you explain why just the second query isn't what you need in the first place, why are you running the first one?



SQL Tuning

Shubhasree, March 03, 2008 - 7:34 am UTC

Sorry Tom,

It was my mistake while copy-paste.
The actual correct query is below:

SELECT sfk_acc.acc_nbr AS sfkacc, sc.sc_id AS sc, scaa.acc_nbr AS cptyscaa,
       inx.m_client_of_cpty_agent AS ptysca,
       (SELECT acc_nbr
          FROM sfk_acc s
         WHERE s.sfk_acc_db_id =
                              inx.m_sfk_acc_id_matc_cpty_client)
                                                                AS cptyclient,
       sec_local_code.local_code AS localsec, sec.isin AS isin,
       inx_client_info.c_client_inx_ref_id AS clientref,
       inx.our_reference AS ourreference,
       inx_client_info.p_status AS insstatus,
       inx_client_info.p_qty AS quantity,
       inx_client_info.p_cash_amnt AS cashamount, exec.deal_type AS issedeal,
       inx_client_info.p_cash_amnt_ccy AS cashamountccy,
       inx.trade_date AS tradedate, inx.esd AS asd,
       exec.contract_note AS typeofcontract,
       exec.deal_price_value AS tradeprice, '' AS brokerage, '' AS commission,
       se.se_id AS selocation, exec.price_difference_value AS pricedifference,
       inx.m_sc_inx_reference_id AS screference,
       exec.se_deal_trade_date_time AS tradetime,
       SYSDATE AS reportgentimestamp,
       exec.se_deal_trade_date_time AS executiontimetag72,
       exec.exec_time AS executiontimetag30,
       exec.se_reference AS sedealnumber,
       exec.reconciliation_ind AS reconciliationindicator,
       inx_client_info.c_reason_code AS failurereasoncode,
       inx_client_info.p_status AS instructionstatusasname,
       exec.trading_system_reference AS xetrareference,
       exec.trader_id AS traderreference, exec.netting_type AS nettingtype,
       exec.ccp_ind AS isccpinvolved, exec.agent_prop_trading AS acctype,
       sec.short_name AS securityname, sec.sec_cfi_category AS cficategory,
       inx_client_info.p_securities_way AS way, '' AS tradingsuffix,
       '' AS kepler, inx.TYPE AS inxtype, inx.SUBTYPE AS inxsubtype
  FROM se,
       exec,
       inx,
       sc,
       sfk_acc,
       inx_client_info,
       scaa,
       sec,
       sec_local_code,
       (SELECT p_status, inx_client_info_db_id
          FROM inx_client_info
         WHERE p_status IN ('MATC', 'COMP', '2BVA', 'PROV')
        UNION ALL
        (SELECT p_status, inx_client_info_db_id
           FROM inx_client_info
          WHERE (    inx_client_info.p_status = 'SETT'
                 AND inx_client_info.p_asd = (SYSDATE - 30)
                )
             OR (    inx_client_info.p_status = 'CAND'
                 AND TRUNC (inx_client_info.updating_date) = (SYSDATE - 30)
                ))) pstatus
 WHERE se.se_db_id(+) = exec.se_db_id
   AND (inx.inx_db_id = exec.inx_db_id(+)
        AND inx.original_mother_inx_db_id IS NULL)
   AND sc.sc_db_id = inx.m_sc_db_id_sc
   AND sfk_acc.sfk_acc_db_id = inx_client_info.c_sfk_acc_db_id
   AND scaa.scaa_db_id = inx.m_scaa_id_cpty_agent
   AND inx_client_info.inx_db_id = inx.inx_db_id
   AND inx.sec_db_id = sec.sec_db_id
   AND sec.sec_db_id = sec_local_code.sec_db_id(+)
   AND sec_local_code.nbr_scheme_type = 'WKN'
   AND sfk_acc.sfk_acc_db_id = 10000005463
   AND inx.m_agent_location NOT IN ('ALEG', 'SCMG')
   AND pstatus.inx_client_info_db_id = inx_client_info.inx_client_info_db_id
UNION
SELECT sfk_acc.acc_nbr AS sfkacc, sc.sc_id AS sc, scaa.acc_nbr AS cptyscaa,
       inx.m_client_of_cpty_agent AS ptysca,
       (SELECT acc_nbr
          FROM sfk_acc s
         WHERE s.sfk_acc_db_id =
                              inx.m_sfk_acc_id_matc_cpty_client)
                                                                AS cptyclient,
       sec_local_code.local_code AS localsec, sec.isin AS isin,
       inx_client_info.c_client_inx_ref_id AS clientref,
       inx.our_reference AS ourreference,
       inx_client_info.p_status AS insstatus,
       inx_client_info.p_qty AS quantity,
       inx_client_info.p_cash_amnt AS cashamount, exec.deal_type AS issedeal,
       inx_client_info.p_cash_amnt_ccy AS cashamountccy,
       inx.trade_date AS tradedate, inx.esd AS asd,
       exec.contract_note AS typeofcontract,
       exec.deal_price_value AS tradeprice, '' AS brokerage, '' AS commission,
       se.se_id AS selocation, exec.price_difference_value AS pricedifference,
       inx.m_sc_inx_reference_id AS screference,
       exec.se_deal_trade_date_time AS tradetime,
       SYSDATE AS reportgentimestamp,
       exec.se_deal_trade_date_time AS executiontimetag72,
       exec.exec_time AS executiontimetag30,
       exec.se_reference AS sedealnumber,
       exec.reconciliation_ind AS reconciliationindicator,
       inx_client_info.c_reason_code AS failurereasoncode,
       inx_client_info.p_status AS instructionstatusasname,
       exec.trading_system_reference AS xetrareference,
       exec.trader_id AS traderreference, exec.netting_type AS nettingtype,
       exec.ccp_ind AS isccpinvolved, exec.agent_prop_trading AS acctype,
       sec.short_name AS securityname, sec.sec_cfi_category AS cficategory,
       inx_client_info.p_securities_way AS way, '' AS tradingsuffix,
       '' AS kepler, inx.TYPE AS inxtype, inx.SUBTYPE AS inxsubtype
  FROM se,
       exec,
       inx,
       sc,
       sfk_acc,
       inx_client_info,
       scaa,
       sec,
       sec_local_code,
       (SELECT p_status, inx_client_info_db_id
          FROM inx_client_info
         WHERE p_status IN ('MATC', 'COMP', '2BVA', 'PROV')
        UNION ALL
        (SELECT p_status, inx_client_info_db_id
           FROM inx_client_info
          WHERE (    inx_client_info.p_status = 'SETT'
                 AND inx_client_info.p_asd = (SYSDATE - 30)
                )
             OR (    inx_client_info.p_status = 'CAND'
                 AND TRUNC (inx_client_info.updating_date) = (SYSDATE - 30)
                ))) pstatus
 WHERE se.se_db_id(+) = exec.se_db_id
   AND (    inx.original_mother_inx_db_id = exec.inx_db_id(+)
        AND inx.original_mother_inx_db_id IS NOT NULL
       )
   AND sc.sc_db_id = inx.m_sc_db_id_sc
   AND sfk_acc.sfk_acc_db_id = inx_client_info.c_sfk_acc_db_id
   AND scaa.scaa_db_id = inx.m_scaa_id_cpty_agent
   AND inx_client_info.inx_db_id = inx.inx_db_id
   AND inx.sec_db_id = sec.sec_db_id
   AND sec.sec_db_id = sec_local_code.sec_db_id(+)
   AND sec_local_code.nbr_scheme_type = 'WKN'
   AND sfk_acc.sfk_acc_db_id = 10000005463
   AND inx.m_agent_location NOT IN ('ALEG', 'SCMG')
   AND pstatus.inx_client_info_db_id = inx_client_info.inx_client_info_db_id;


Please could you suggest me some solution of refactoring it into a better one?
Tom Kyte
March 03, 2008 - 8:15 am UTC

[tkyte@dellpe ~]$ diff -b t1 t2
56,57c56,58
<    AND (inx.inx_db_id = exec.inx_db_id(+)
<         AND inx.original_mother_inx_db_id IS NULL)
---
>    AND (    inx.original_mother_inx_db_id = exec.inx_db_id(+)
>         AND inx.original_mother_inx_db_id IS NOT NULL
>        )
[tkyte@dellpe ~]



depends on the relationship, is inx.inx_db_id to exec 1:1 optional, and is inx.original_mother_inx_db_id to exec 1:1 optional...

if so, we might be looking at using a scalar subquery to replace the outer join and remove the UNION.


Actually, you review the query and look for obvious low hanging fruit too - something as simple as:
 (SELECT p_status, inx_client_info_db_id
          FROM inx_client_info
         WHERE p_status IN ('MATC', 'COMP', '2BVA', 'PROV')
        UNION ALL
        (SELECT p_status, inx_client_info_db_id
           FROM inx_client_info
          WHERE (    inx_client_info.p_status = 'SETT'
                 AND inx_client_info.p_asd = (SYSDATE - 30)
                )
             OR (    inx_client_info.p_status = 'CAND'
                 AND TRUNC (inx_client_info.updating_date) = (SYSDATE - 30)
                ))) 


so, why do you need a union all there for example?

you don't need all of your outer joins (which makes me think someone that understands the data model hasn't really looked at this one from your side yet...)
 AND sec.sec_db_id = sec_local_code.sec_db_id(+)
   AND sec_local_code.nbr_scheme_type = 'WKN'


IF we make up a row for sec_local_code, then nbr_schem_type cannot be WKN, so that outer join is - well, not needed.

suggestion: you rip this query apart, make sure you understand the needs of the query and the data it is querying and try to make it as simple as possible first.


Hint: if the two things I asked about are 1:1 optional relations then an outer join of the type:

create table t ( x int primary key, fk_t1 int, fk_t2 int, data int );
create table t1 ( pk int primary key, c1 int, c2 int );
create table t2 ( pk int primary key, c1 int, c2 int );

insert into t values ( 1, 1, 1, 100 );
insert into t values ( 2, 2, 2, 200 );
insert into t values ( 3, 3, 3, 300 );

insert into t1 values ( 2, 100, null );
insert into t2 values ( 3, null, 300 );

select x, fk_t1, fk_t2,
       to_number( trim( substr( t1_data, 1, 30 ))) t1_c1,
       to_number( trim( substr( t1_data, 31    ))) t1_c2,
       to_number( trim( substr( t2_data, 1, 30 ))) t2_c1,
       to_number( trim( substr( t2_data, 31    ))) t2_c2
  from (
select t.*,
       (select rpad(nvl(to_char(t1.c1),' '),30) || rpad(nvl(to_char(t1.c2),' '),30) from t1 where t1.pk = t.fk_t1) t1_data,
       (select rpad(nvl(to_char(t2.c1),' '),30) || rpad(nvl(to_char(t2.c2),' '),30) from t2 where t2.pk = t.fk_t2) t2_data
  from t
       )
/



ops$tkyte%ORA9IR2> select x, fk_t1, fk_t2,
  2         to_number( trim( substr( t1_data, 1, 30 ))) t1_c1,
  3         to_number( trim( substr( t1_data, 31    ))) t1_c2,
  4         to_number( trim( substr( t2_data, 1, 30 ))) t2_c1,
  5         to_number( trim( substr( t2_data, 31    ))) t2_c2
  6    from (
  7  select t.*,
  8         (select rpad(nvl(to_char(t1.c1),' '),30) || rpad(nvl(to_char(t1.c2),' '),30) from t1 where t1.pk = t.fk_t1) t1_data,
  9         (select rpad(nvl(to_char(t2.c1),' '),30) || rpad(nvl(to_char(t2.c2),' '),30) from t2 where t2.pk = t.fk_t2) t2_data
 10    from t
 11         )
 12  /

         X      FK_T1      FK_T2      T1_C1      T1_C2      T2_C1      T2_C2
---------- ---------- ---------- ---------- ---------- ---------- ----------
         1          1          1
         2          2          2        100
         3          3          3                                         300




query tuning issue

A reader, March 03, 2008 - 9:56 am UTC

Hello Tom:

we have a query always causing problem, like high load. I checked the plan which was used during high load. The plan is pretty bad (with bind variable) and has big gets. The interesting thing is every time the query causes the high load, we just need to analyze the kernel table, and then we are fine. we have schedule to gether stats every wednesday and Saturday. and we use

EXECUTE dbms_stats.gather_schema_stats(ownname=>'LIBMIN', method_opt=>'FOR ALL INDEXED COLUMNS', cascade=>TRUE);

to gather stats based on schema. I was wondering if the difference between the "analyze" and dbms_stats makes the difference. since the package gathers histogram but the analyze doesn't. but not sure. what do you think the reason is? and what we should do to prevent the query to cause the high load again.


Tom Kyte
March 03, 2008 - 10:09 am UTC

and if you used dbms_stats instead of analyze, do you not see EXACTLY the same thing happening - meaning, why do you think this is analyze, it sounds more like either

a) you have a bind peeking issue, gathering stats invalidated the cursors and causes a new hard parse and we peek at the current binds and you like what you get
http://asktom.oracle.com/Misc/tuning-with-sqltracetrue.html
http://asktom.oracle.com/Misc/sqltracetrue-part-two.html


b) you had stale statistics and the addition of current statistics naturally corrects the plan. This could be combined with a) actually in that you are gathering stats in indexed columns. Over time, the high value of your indexed column (on a timestamp or sequence generated key) goes up and up. The optimizer however doesn't know that (because you haven't gathered statistics) and it peeks at a bind - thinking "oh, I'll get very very few rows" and inappropriately uses an index. After gathering stats, it says "ok, I'll get an enormous number of rows, best not use the index anymore"




(you should compare the before and after plans to see what changes when it gets "fixed", that'll give you a ton of information as to the material change that statistics is making to the plan, leading you to understanding "why". Then you need to figure out what to do - which might be as simple as using SET_xxx_statistics to adjust the "high value".


see how newly added data can lead to a 'bad plan' quickly:

ops$tkyte%ORA10GR2> create table t as select * from all_objects;

Table created.

ops$tkyte%ORA10GR2> create index t_idx on t(created);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'T', method_opt=>'for all indexed columns' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from t where created >= to_date( '03-mar-2008', 'dd-mon-yyyy' );

Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |    51 |  4743 |     3   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |    51 |  4743 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |    51 |       |     2   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("CREATED">=TO_DATE('2008-03-03 00:00:00', 'yyyy-mm-dd
              hh24:mi:ss'))

ops$tkyte%ORA10GR2> set autotrace off
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> insert into t
  2  select OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID,
  3  DATA_OBJECT_ID, OBJECT_TYPE, sysdate + 1/24 * rownum,
  4  LAST_DDL_TIME, TIMESTAMP, STATUS, TEMPORARY, GENERATED, SECONDARY
  5   from t
  6  /

49687 rows created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from t where created >= to_date( '03-mar-2008', 'dd-mon-yyyy' );

Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |    51 |  4743 |     3   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |    51 |  4743 |     3   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |    51 |       |     2   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("CREATED">=TO_DATE('2008-03-03 00:00:00', 'yyyy-mm-dd
              hh24:mi:ss'))

ops$tkyte%ORA10GR2> set autotrace off
ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'T', method_opt=>'for all indexed columns' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from t where created >= to_date( '03-mar-2008', 'dd-mon-yyyy' );

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      | 49700 |  4513K|   445   (4)| 00:00:03 |
|*  1 |  TABLE ACCESS FULL| T    | 49700 |  4513K|   445   (4)| 00:00:03 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("CREATED">=TO_DATE('2008-03-03 00:00:00', 'yyyy-mm-dd
              hh24:mi:ss'))

ops$tkyte%ORA10GR2> set autotrace off



tuning issue

A reader, March 03, 2008 - 6:37 pm UTC

hey Tom:

I read the link you provided, it is very good explanation about the bind peeking. and I have couple of question for part1:

1. does cursor_sharing work for both user bind variables and system bind variables? for example, if I set up cursor_sharing=similar, will it choose the different plan for a query,(no matter this query contains user bind variables or system automatically bind variables),if the histogram, stats makes the difference?

For the example in the first part, you gathered the stats for table including the histogram. And you used user bind variable. Does this mean no matter what you set for cursor_sharing, the bind peeking will still happen no matter if there is histogram which is able to make difference. Is this correct?


2.Another question, I remember you said it before, autotrace also does hard parse every time we run the query. And the stats you got in the example are from the "set autotrace traceonly statistics". Will these stats be the right one?

What I mean is sql_trace will use the another child cursor and not sharing the plan for the queries that didn't got sql_trace enabled. What about the autotrace. When we set autotrace on, and run the query, will the query is also hard parsed everytime, or just share the plan that already exists in the system. If they use the existing plan, then this means the autotrace tells the truth. But the autotrace is blind to bind peeking right? If no, then the gets from the autotrace can not be used as the stats in comparison. We need to go to v$view to get the real stats.

2. where is the parent cursor? In the library cache?
where is the child cursor? In the privary sql area in the PGA? (if using dedicated server)
I check the dbms_stats, here is the definition for the parameter:

"no_invalidate
Does not invalidate the dependent cursors if set to TRUE. The procedure invalidates the dependent cursors immediately if set to FALSE. Use DBMS_STATS.AUTO_INVALIDATE. to have Oracle decide when to invalidate dependent cursors. This is the default. "

so here is the dependent cursor is the same thing with the child cursor?

do you have a link about the parent and child cursor and the difference of the v$sql, v$sqlarea....?


thank you very much!

Tom Kyte
March 03, 2008 - 9:06 pm UTC

1) bind peeking happens - yes. And if you are using cursor sharing similar - it marks various binds as not being bind safe which will permit it to set up a child cursor for EACH unique set of binds (which is not desirable in most cases either)

2) autotrace uses explain plan. explain plan always hard parses the query, yes.

but the statistics that come out - they are from the v$ tables, they represent ACTUAL MEASURED WORK performed by the execution of the query - so, even if autotrace shows the wrong plan, the statistics are accurate - they are "reality"

when you run the query with autotrace is

a) runs the query - that'll use shared sql without sql trace being on at all.
b) queries the v$ tables to report how much work was just done
c) explain plan the query - that'll hard parse and display whatever plan it displays


2nd 2) the parent cursor is just the FIRST cursor, it is where every other shared cursor bit is - out there in the shared pool.


In the context of dbms_stats, dependent means "cursors that reference the object we just gathered statistics on", the cursors are dependent on that table, gathering statistics normally invalidates the cursors that are dependent (reference) that object you just gathered stats on.




do not over analyze "parent and child", there is one parent, whatever query was first put out there, the rest are "child cursors", but they are the same, just not first.


v$sql is aggregated to make v$sqlarea

Query tuning

A reader, March 05, 2008 - 8:44 am UTC

Hello,
We have a Select which we are trying to tune. The problem is, that the runtime of this select is different depending on the maschine: in the production the query is running about 12 minutes and in a database which is copy of the production about 2-3 minutes. Even the server with the copy environment is not so powerfull like the production.
We've tried to add new indexes, but this did not help too much. We are assuming, that big discrepancy in the runtime depends on the environment where SQL is running and not on SQL itself. If this is correct,what could our DBA's do to speed up the query.
Thanks

Tom Kyte
March 05, 2008 - 9:30 am UTC

*trace it*

on both

see what is different.

A reader, March 05, 2008 - 6:25 pm UTC

Hey Tom:

    I found two sql statement in the memory:


SQL> select sql_id, child_number from v$sql where sql_text like 'select distinct s.make_id, n.make%';

SQL_ID        CHILD_NUMBER
------------- ------------
c3x0650yh479h            0
g168rttntqkbq            0

SQL> select * from table(dbms_xplan.display_cursor('c3x0650yh479h',0));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
SQL_ID  c3x0650yh479h, child number 0
-------------------------------------
select distinct s.make_id, n.make     from autodata.stock_photo s, autodata.name
s n     where s.make_id = :"SYS_B_0"     and s.ad_veh_id = n.ad_veh_id

Plan hash value: 3969676706


SQL> select * from table(dbms_xplan.display_cursor('g168rttntqkbq',0));

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
SQL_ID  g168rttntqkbq, child number 0
-------------------------------------
select distinct s.make_id, n.make  from autodata.stock_photo s, autodata.names n
  where s.make_id = :make_id  and s.ad_veh_id = n.ad_veh_id

Plan hash value: 3969676706


they have different sql_id, bind variable(one user bind, one system bind). but they have same plan hash value. what is the plan hash value? And will these two sql share the same plan? is this plan_hash_value the same thing with the "HASH_VALUE" in the v$sql?


Thank you!

Tom Kyte
March 06, 2008 - 8:15 am UTC

a hash is a non-unique thing. it is quite possible to get the same hash for two different things (rare, but absolutely possible - one of the reasons we use sql_id in 10g is because the old 32bit hash of 9i and before was not good enough)


this hash is used to identify when plans change typically, don't worry about it, it is not wrong or broken or anything. It just hashed two things to the same value - it is expected.

Query tuning

A reader, March 06, 2008 - 9:07 am UTC

Hi Tom,
the DBA's run the trace for both databases. The only difference what I can see is, that in the production the query need much more cpu, disc space :
In Production:
OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 10 0.13 0.14 1 3 0 0
Execute 10 0.00 0.00 0 0 0 0
Fetch 22 145.70 284.66 126108 10417295 0 415
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 42 145.83 284.81 126109 10417298 0 415

Misses in library cache during parse: 3
On the copy database:
OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 10 0.16 0.16 0 0 0 0
Execute 10 0.01 0.00 0 0 0 0
Fetch 13 1.49 2.09 45 3977 0 157
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 33 1.66 2.25 45 3977 0 157

Misses in library cache during parse: 2
How is such a difference possible. The tables have on both databases nearly the same amount of data?
The DBA's proposed to create indexes or are speaking from "Bind Variable Peeking".
Could you please give some hints, what we can take into account to speed up this query.
Thanks a lot
Tom Kyte
March 07, 2008 - 4:46 pm UTC

I do not believe we are looking at anything remotely even a little bit SIMILAR here.

Instead of looking at aggregate totals, please look at individual sql statements.

Asheesh Dhupper, March 07, 2008 - 4:17 am UTC

Hi Tom,

Is there any guide/book for SQL Tuning. I am a PL/SQL Developer and sometimes has problems with Tuning my SQLs as there are restrictions on Database(being production box) to use Explain Plan.

Tom Kyte
March 10, 2008 - 9:56 am UTC

step number 1:

do not tune on production!


You would be doing this in an environment whereby there would be no restrictions - no one 'tunes' on production (although many people do launch a denial of service attack on production "by accident" that way)


Step number 2:

I've found that for 'sql tuning' you want to

a) understand what is available and how it works

most books say "here is a trick, here is another trick" and you end up with five tricks, which you then try to apply to every single problem.

Rather than understanding and conceptualizing "how the data is organized, how it relates to the other bits and bytes out there and how using analytics for this, aggregation for that, a WITH subquery factored out for that, an inline view for this, a scalar subquery in that case, etc etc etc" would be useful.

To that end - suggest the data warehouse guide (yes, even for OLTP, they have lots of good stuff in there). Also, the performance guide. And if you are interested, I have a chapter "efficient sql" in effective oracle by design that describes how the various ACCESS paths work - what they do and why they are useful

question about elapsed time

A reader, March 19, 2008 - 3:42 pm UTC

Hey Tom:

    I got a question about the elapsed time. I run a script and set the time on;

49999 rows selected. 

Elapsed: 00:01:25.03 

and I count the time too, it is around 1 and half mins.

but in the grid control, and in the awr, and in the dba_hist_sqlstat table, they all show this query's elapsed time is 5.72 second:

SQL> select ELAPSED_TIME_TOTAL/1000000 from dba_hist_sqlstat where sql_id='fspzwgsrtd8qd' 
2 order by 
3 ELAPSED_TIME_TOTAL; 

ELAPSED_TIME_TOTAL/1000000 
-------------------------- 
5.715981 

so is the elapsed time for a query here the same with we got from "set timing on"???

Thank you very much!

Tom Kyte
March 24, 2008 - 9:52 am UTC

that means you spent most of your time updating your screen to print 49,999 rows - which makes sense, screen IO is very slow.


AWR reports database time, set timing on reports client time plus database time.

you just 'proved' that this query takes 1.5 minutes because the client is very slow in processing the data.

Tune Aggregate functions

Stephan, March 26, 2008 - 3:49 am UTC

Hi Tom,
I am trying to tune this SQL below. I have few questions to you.
1. Why there is long gap between cpu time and elapsed time? According to my
Understanding, that is waiting time. Am I correct? What reasons to make that gap long?
2. Is there anyway I can write this SQL better to get the output fast? Presently it is taking long time get the output.

Pls. give an advice.


SELECT SUM(t.TRXN_AMT), SUM(t.TRXN_UNIT)
FROM TRXN_HISTORIES t, POLICYS P
WHERE FND_ID = :b1
AND t.POL_NUM = p.POL_NUM
AND t.PRCES_DT < :b2
AND p.SRC_OF_FND = :b3;


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 3.46 11.61 77494 108010 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 3.46 11.62 77494 108010 0 1


Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=6674 Card=1 Bytes=50
)

1 0 SORT (AGGREGATE)
2 1 HASH JOIN (Cost=6674 Card=38192 Bytes=1909600)
3 2 TABLE ACCESS (FULL) OF 'TRXN_HISTORIES' (Cost=65
13 Card=38192 Bytes=1413104)

4 2 INDEX (FAST FULL SCAN) OF 'IDX_TPSG_001' (NON-UNIQUE)
(Cost=72 Card=217021 Bytes=2821273)





Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
108011 consistent gets
77516 physical reads
60 redo size
338 bytes sent via SQL*Net to client
417 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed

Tom Kyte
March 26, 2008 - 9:00 am UTC

yes, and if you use a 10046 level 12 trace, tkprof would show you what you waited on.

i would guess 77494 physical io's would account for it all.


not knowing whence fnd_id is coming from - cannot comment.

Tune Aggregate functions

Stephan, March 27, 2008 - 12:02 am UTC

Thank you very much for your comments.

>>i would guess 77494 physical io's would account for it all.
It is mean the table's HWM is very high. So that I need to alter the table to reduce it. Am going in right direction?

fnd_id is character field.
SELECT SUM(t.TRXN_AMT), SUM(t.TRXN_UNIT)
FROM TRXN_HISTORIES t, POLICYS P
WHERE t.FND_ID = 'RTDR'
AND t.POL_NUM = p.POL_NUM
AND t.PRCES_DT < '27/03/2008'
AND p.SRC_OF_FND = 'L';

Kindly help me to write the query in better way.

Tom Kyte
March 27, 2008 - 10:40 am UTC

... It is mean the table's HWM is very high. ...

wow, how did you jumnp to that huge conclusion.

no, you do not need to "alter the table" - I have no idea where you got the idea that this is a high water mark issue?

You have two full scans right now

a) index fast full scan
b) table full scan

and a hash join.

what is the output of:

select count(*),
count(case when fnd_id='RTDR' and prces_dt<TO_DATE('27/03/2008','dd/mm/yyyy') then 1 end) from TRXN_HISTORIES;

select count(*), count(case when src_of_fnd='L' then 1 end ) from POLICYS ;

Tune Aggregate functions

Stephan, March 27, 2008 - 11:58 pm UTC

Hi Tom,

Thank you for your reply.

B'se only 12% of data need to scan from TRXN_HISTORIES table to get the output.So index scaning will be fast.But optimizer going for a FULL table scan, may be b'se it need scan more blocks to get the output.

Present Indexes:
TRXN_HISTORIES - NONUNIQUE - (FND_ID,PRCES_DT)
POLICYS - UNIQUE - POL_NUM

select count(*) all_rows,
count(case when fnd_id='RTDR' and prces_dt<TO_DATE('27/03/2008','dd/mm/yyyy') then 1 end) condition_cnt from TRXN_HISTORIES;


ALL_ROWS CONDITION_CNT
--------- -------------
3401002 390298

select count(*)all_rows, count(case when src_of_fnd='L' then 1 end )condition_cnt from POLICYS ;

ALL_ROWS CONDITION_CNT
--------- -------------
429186 428844

Tom Kyte
April 01, 2008 - 9:31 am UTC

what is this gibberish?

B'se only 12% of data need to scan from TRXN_HISTORIES table to get the
output.So index scaning will be fast.But optimizer going for a FULL table scan,
may be b'se it need scan more blocks to get the output.

b'se - is that Gaelic or something?


But in any case - who says "12% should use an index", it completely and totally depends on the nature of the data on disk.

Here, look - less than 5% of the rows - and the optimizer MIGHT consider a full scan more efficient - depending on the clustering of the data on disk (how many blocks it will need to visit).

I would guess that the clustering factor on your trxn_histories index is near the number of ROWS (modified from blocks, that was a mistake..) in the table - and that is the cause - it feels it would have to visit 390,298 different blocks in the table to retrieve those rows, so a full scan is better.



ops$tkyte%ORA11GR1> create table organized
  2  as
  3  select x.*
  4    from (select * from all_objects order by object_name) x
  5  /
Table created.

ops$tkyte%ORA11GR1> create table disorganized
  2  as
  3  select x.*
  4    from (select * from all_objects order by dbms_random.random) x
  5  /
Table created.

ops$tkyte%ORA11GR1> create index organized_idx on organized(object_name);
Index created.

ops$tkyte%ORA11GR1> create index disorganized_idx on disorganized(object_name);
Index created.

ops$tkyte%ORA11GR1> begin
  2  dbms_stats.gather_table_stats
  3  ( user, 'ORGANIZED', method_opt=>'for all indexed columns size 254' );
  4  dbms_stats.gather_table_stats
  5  ( user, 'DISORGANIZED', method_opt=>'for all indexed columns size 254' );
  6  end;
  7  /
PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> select table_name, blocks, num_rows, 0.05*num_rows, 0.10*num_rows from user_tables
  2  where table_name like '%ORGANIZED' order by 1;

TABLE_NAME                         BLOCKS   NUM_ROWS 0.05*NUM_ROWS 0.10*NUM_ROWS
------------------------------ ---------- ---------- ------------- -------------
DISORGANIZED                          137      20000          1000 2000
ORGANIZED                             137      20000          1000 2000

ops$tkyte%ORA11GR1> select table_name, index_name, clustering_factor from user_indexes
  2  where table_name like '%ORGANIZED' order by 1;

TABLE_NAME                     INDEX_NAME                     CLUSTERING_FACTOR
------------------------------ ------------------------------ -----------------
DISORGANIZED                   DISORGANIZED_IDX                           19853
ORGANIZED                      ORGANIZED_IDX                                125

ops$tkyte%ORA11GR1> set autotrace traceonly explain
ops$tkyte%ORA11GR1> select * from organized where object_name like 'A%';
-------------------------------------------------------------------------------
| Id  | Operation                   | Name          | Rows  | Bytes | Cost (%CP
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |               |   973 | 37947 |    13   (
|   1 |  TABLE ACCESS BY INDEX ROWID| ORGANIZED     |   973 | 37947 |    13   (
|*  2 |   INDEX RANGE SCAN          | ORGANIZED_IDX |   973 |       |     6   (
-------------------------------------------------------------------------------

ops$tkyte%ORA11GR1> select * from disorganized where object_name like 'A%';
-------------------------------------------------------------------------------
| Id  | Operation         | Name         | Rows  | Bytes | Cost (%CPU)| Time
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |              |   973 | 37947 |    39   (0)| 00:00:0
|*  1 |  TABLE ACCESS FULL| DISORGANIZED |   973 | 37947 |    39   (0)| 00:00:0
-------------------------------------------------------------------------------

How will you tacle this case of IN

A reader, March 28, 2008 - 9:47 pm UTC

select company, code
from table1, table 2
where table1.company = 'IBM'
and table1.name = table2.name
and table1.recent = 'P'
and table1.company in (
select unique table1.company
from table3, table4, table5,table6
where table5.nameid = table6.nameid
and table3.key = table4.unit_id
and table3.id = table1.id
and table3.recent = 'P'
and table4.recent ='P'
and table3.lang = 'ENGLISH' )
order by table3.name

Tom Kyte
March 31, 2008 - 8:16 am UTC

I wouldn't, I'd let the optimizer deal with it.

You can lose that unique, it is harmless but meaningless - it makes it look like the person writing the query didn't understand SQL.

The optimizer will either decide to semi-join to the subquery - or to do it like an "exists" - it totally depends on the statistics and estimated cardinality values.

Tune Aggregate functions

Stephan, April 01, 2008 - 2:53 am UTC

Hi Tom,
Thanks for your reply.

>> "clustering factor on your trxn_histories index is near the number of blocks in the table".
Your guessing is right.

TRXN_HISTORIES>>

num_rows blocks clusting_factor
----------------------------------
3491241 106838 1136400


Then I recreated the table and indexes:

CREATE TABLE TRXN_HISTORIES AS SELECT /*+ index(TRXN_HISTORIES_BK I_TFH_2) */ * FROM TRXN_HISTORIES_BK;

TRXN_HISTORIES>>

num_rows blocks clusting_factor
----------------------------------
3519669 105622 1134714

But tom, after recreate table and index, clustering factor is not near to the number of blocks in

the table.

1. What could be possible reason.

for POLICYS table it worked. it mean clustering factor is near the number of blocks in the

table.


2. Is there any better way to write SQL.

Pls. help me.
Tom Kyte
April 01, 2008 - 9:30 am UTC

sorry, I meant "clustering factor is near the number of ROWS in your table"

and it is much closer to the number of rows than the number of blocks.

quote from Expert Oracle Database Architecture:


The Clustering Factor
Next, let¿s look at some of the information Oracle will use. We are specifically going to look at the CLUSTERING_FACTOR column found in the USER_INDEXES view. The Oracle Reference Manual tells us this column has the following meaning:
Begin Quote
Indicates the amount of order of the rows in the table based on the values of the index:
 * If the value is near the number of blocks, then the table is very well ordered. In this case, the index entries in a single leaf block tend to point to rows in the same data blocks.
 * If the value is near the number of rows, then the table is very randomly ordered. In this case, it is unlikely that index entries in the same leaf block point to rows in the same data blocks.
End Quote
We could also view the clustering factor as a number that represents the number of logical I/Os against the table that would be performed to read the entire table via the index. That is, the CLUSTERING_FACTOR is an indication of how ordered the table is with respect to the index itself, and when we look at these indexes we find the following:
ops$tkyte@ORA10G> select a.index_name,
  2         b.num_rows,
  3         b.blocks,
  4         a.clustering_factor
  5    from user_indexes a, user_tables b
  6  where index_name in ('COLOCATED_PK', 'DISORGANIZED_PK' )
  7    and a.table_name = b.table_name
  8  /
 
INDEX_NAME        NUM_ROWS     BLOCKS CLUSTERING_FACTOR
--------------- ---------- ---------- -----------------
COLOCATED_PK        100000       1252              1190
DISORGANIZED_PK     100000       1219             99932
Note I used an ASSM managed tablespace for this section¿s example, which explains why the clustering factor for the COLOCATED table is less than the number of blocks in the table. There are unformatted blocks in the COLOCATED table below the HWM that do not contain data, as well as blocks used by ASSM itself to manage space, and we will not read these blocks ever in a index range scan. Chapter 10 explains HWMs and ASSM in more detail.
So the database is saying, ¿If we were to read every row in COLOCATED via the index COLOCATED_PK from start to finish, we would perform 1,190 I/Os. However, if we did the same to DISORGANIZED, we would perform 99,932 I/Os against the table.¿ The reason for the large difference is that as Oracle range scans through the index structure, if it discovers the next row in the index is on the same database block as the prior row, it does not perform another I/O to get the table block from the buffer cache. It already has a handle to one and just uses it. However, if the next row is not on the same block, then it will release that block and perform another I/O into the buffer cache to retrieve the next block to be processed. Hence the COLOCATED_PK index, as we range scan through it, will discover that the next row is almost always on the same block as the prior row. The DISORGANIZED_PK index will discover the opposite is true. In fact, we can actually see this measurement is very accurate. Using hints to have the optimizer use an index full scan to read the entire table and just count the number of non-null Y values¿we can see exactly how many I/Os it will take to read the entire table via the index:
select count(Y)
from
 (select /*+ INDEX(COLOCATED COLOCATED_PK) */ * from colocated)
                                                                     
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.10       0.16          0       1399          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.10       0.16          0       1399          0           1

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=1399 pr=0 pw=0 time=160325 us)
 100000   TABLE ACCESS BY INDEX ROWID COLOCATED (cr=1399 pr=0 pw=0 time=500059 us)
 100000    INDEX FULL SCAN COLOCATED_PK (cr=209 pr=0 pw=0 time=101057 us)(object ¿
********************************************************************************
select count(Y)
from
 (select /*+ INDEX(DISORGANIZED DISORGANIZED_PK) */ * from disorganized)

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.34       0.40          0     100141          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.34       0.40          0     100141          0           1

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=100141 pr=0 pw=0 time=401109 us)
 100000   TABLE ACCESS BY INDEX ROWID OBJ#(66615) (cr=100141 pr=0 pw=0 time=800058¿
 100000    INDEX FULL SCAN OBJ#(66616) (cr=209 pr=0 pw=0 time=101129 us)(object¿
In both cases, the index needed to perform 209 logical I/Os (cr=209 in the Row Source Operation lines). If you subtract 209 from the total consistent reads and measure just the number of I/Os against the table, then you¿ll find that they are identical to the clustering factor for each respective index. The COLOCATED_PK is a classic ¿the table is well ordered¿ example, whereas the DISORGANIZE_PK is a classic ¿the table is very randomly ordered¿ example. It is interesting to see how this affects the optimizer now. If we attempt to retrieve 25,000 rows, Oracle will now choose a full table scan for both queries (retrieving 25 percent of the rows via an index is not the optimal plan, even for the very ordered table). However, if we drop down to 10 percent (bear in mind that 10 percent is not a threshold value¿it is just a number less than 25 percent that caused an index range scan to happen in this case) of the table data:
ops$tkyte@ORA10G> select * from colocated where x between 20000 and 30000;
 
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=143 Card=10002 Bytes=800160)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'COLOCATED' (TABLE) (Cost=143 ¿
   2    1     INDEX (RANGE SCAN) OF 'COLOCATED_PK' (INDEX (UNIQUE)) (Cost=22 ¿
 
 
 
ops$tkyte@ORA10G> select * from disorganized where x between 20000 and 30000;
 
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=ALL_ROWS (Cost=337 Card=10002 Bytes=800160)
   1    0   TABLE ACCESS (FULL) OF 'DISORGANIZED' (TABLE) (Cost=337 Card=10002 ¿
Here we have the same table structures¿the same indexes¿but different clustering factors. The optimizer in this case chose an index access plan for the COLOCATED table and a full scan access plan for the DISORGANIZED table.
The key point to this discussion is that indexes are not always the appropriate access method. The optimizer may very well be correct in choosing to not use an index, as the preceding example demonstrates. Many factors influence the use of an index by the optimizer, including physical data layout. You might be tempted therefore to run out and try to rebuild all of your tables now to make all indexes have a good clustering factor, but that would be a waste of time in most cases. It will affect cases where you do index range scans of a large percentage of a table. Additionally, you must keep in mind that in general the table will have only one index with a good clustering factor! The rows in a table may be sorted in only one way. In the example just show, if I had another index on the column Y it would be very poorly clustered in the COLOCATED table, but very nicely clustered in the DISORGANIZED table. If having the data physically clustered is important to you, consider the use of an IOT, a B*Tree cluster, or a hash cluster over continuous table rebuilds. 


Alexander the ok, April 11, 2008 - 3:33 pm UTC

Tom,

Can you help improve this query. I don't have tkprof at the moment, I wasn't expecting it to take this long but I have autotrace.

I'm thinking of trying to lose the scalar subqueries and push everything into the main query, and perhaps outer join to replace the union. I keep getting lost though, can you suggest?

SQL> select distinct
  2       pmv.personid,
  3       lm.legalmatterid,
  4       lm.matterid,
  5       lm.mattername,
  6       0 collection,
  7       (select count(distinct ln.noticeid)
  8           from person p1,
  9           mv_notice_type ln,
 10           legalrequest lr,
 11           mv_legalmatter_type lm,
 12           mv_matterperformer_type mp,
 13           noticeremindersent nrs
 14           where lr.requestid = ln.requestid
 15           and lm.legalmatterid = lr.legalmatterid
 16           and lm.legalmatterid = r.legalmatterid
 17           and nrs.noticeid = ln.noticeid
 18           and mp.matterperformerid = nrs.matterperformerid
 19           and p1.lastname || ', ' || p1.firstname = mp.performername
 20           and p1.personid = pmv.personid) AS notices,
 21             (select count(planid)
 22              from ( select p1.personid,lr.legalmatterid,cip.planid
 23              from mv_legalmatter_type lm,
 24              legalrequest lr,
 25              mv_collinterviewplan_type2 cip,
 26              mv_mattertarget_type mt,
 27              person p1
 28              where lr.legalmatterid = lm.legalmatterid
 29              and mt.targetsysteminstanceid = p1.personid
 30              and cip.requestid = lr.requestid
 31              and mt.planid = cip.planid
 32              union
 33              select p1.personid,lr.legalmatterid,cip.planid
 34              from mv_legalmatter_type lm,
 35              legalrequest lr,
 36              mv_collinterviewplan_type2 cip,
 37              mv_matterperformer_type mp,
 38              person p1
 39              where lr.legalmatterid = lm.legalmatterid
 40              and mp.performersysteminstanceid = p1.personid
 41              and cip.requestid = lr.requestid
 42              and mp.planid = cip.planid )
 43              where personid=pmv.personid
 44              and legalmatterid=r.legalmatterid) AS interviews,
 45             (select count(nrs.status)
 46             from person p1,
 47             mv_notice_type ln,
 48             legalrequest lr,
 49             mv_legalmatter_type lm,
 50             mv_matterperformer_type mp,
 51             mv_noticereminder_type nrs
 52             where lr.requestid = ln.requestid
 53             and lm.legalmatterid = lr.legalmatterid
 54             and lm.legalmatterid = r.legalmatterid
 55             and nrs.noticeid = ln.noticeid
 56             and mp.matterperformerid = nrs.matterperformerid
 57             and p1.lastname || ', ' || p1.firstname = mp.performername
 58             and p1.personid = pmv.personid) AS noticeexceptions
 59       from mv_legalmatter_type lm,
 60            mv_scopetarget_type st,
 61            legalrequest r,
 62            person pmv
 63       where r.legalmatterid = lm.legalmatterid
 64       and st.targetsysteminstanceid = pmv.personid
 65       and r.requestid = st.requestid;

50887 rows selected.

Elapsed: 02:30:05.11

Execution Plan
----------------------------------------------------------
Plan hash value: 354045871

----------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                            | Name                        | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                     |                             | 58277 |  3699K|       |   980   (3)| 00:00:12 |
|   1 |  SORT GROUP BY                       |                             |     1 |    70 |       |            |          |
|*  2 |   HASH JOIN                          |                             |     1 |    70 |       |   208   (3)| 00:00:03 |
|*  3 |    HASH JOIN                         |                             |     6 |   372 |       |   205   (3)| 00:00:03 |
|   4 |     TABLE ACCESS BY INDEX ROWID      | NOTICEREMINDERSENT          |     1 |     9 |       |     3   (0)| 00:00:01 |
|   5 |      NESTED LOOPS                    |                             |     6 |   330 |       |   201   (2)| 00:00:03 |
|   6 |       NESTED LOOPS                   |                             |     7 |   322 |       |   189   (3)| 00:00:03 |
|   7 |        NESTED LOOPS                  |                             |     1 |    25 |       |     2   (0)| 00:00:01 |
|*  8 |         INDEX UNIQUE SCAN            | PK_LEGALMATTER_LEGALMATTER1 |     1 |     4 |       |     1   (0)| 00:00:01 |
|   9 |         TABLE ACCESS BY INDEX ROWID  | PERSON                      |     1 |    21 |       |     1   (0)| 00:00:01 |
|* 10 |          INDEX UNIQUE SCAN           | PK_PERSON_PERSONID          |     1 |       |       |     0   (0)| 00:00:01 |
|* 11 |        MAT_VIEW ACCESS FULL          | MV_MATTERPERFORMER_TYPE     |     7 |   147 |       |   187   (3)| 00:00:03 |
|* 12 |       INDEX RANGE SCAN               | IDX_NOTICEREMINDERSENT_01   |     3 |       |       |     1   (0)| 00:00:01 |
|  13 |     MAT_VIEW ACCESS FULL             | MV_NOTICE_TYPE              |   300 |  2100 |       |     3   (0)| 00:00:01 |
|  14 |    TABLE ACCESS BY INDEX ROWID       | LEGALREQUEST                |     1 |     8 |       |     3   (0)| 00:00:01 |
|* 15 |     INDEX RANGE SCAN                 | IDX_LEGALREQUEST_04         |     1 |       |       |     2   (0)| 00:00:01 |
|  16 |  SORT AGGREGATE                      |                             |     1 |    39 |       |            |          |
|  17 |   VIEW                               |                             |     2 |    78 |       |   203   (4)| 00:00:03 |
|  18 |    SORT UNIQUE                       |                             |     2 |    64 |       |   203  (96)| 00:00:03 |
|  19 |     UNION-ALL                        |                             |       |       |       |            |          |
|  20 |      NESTED LOOPS                    |                             |     1 |    33 |       |     9   (0)| 00:00:01 |
|  21 |       MERGE JOIN CARTESIAN           |                             |     7 |   182 |       |     8   (0)| 00:00:01 |
|  22 |        NESTED LOOPS                  |                             |     1 |    17 |       |     3   (0)| 00:00:01 |
|  23 |         NESTED LOOPS                 |                             |     1 |     9 |       |     1   (0)| 00:00:01 |
|* 24 |          INDEX UNIQUE SCAN           | PK_PERSON_PERSONID          |     1 |     5 |       |     1   (0)| 00:00:01 |
|* 25 |          INDEX UNIQUE SCAN           | PK_LEGALMATTER_LEGALMATTER1 |     1 |     4 |       |     0   (0)| 00:00:01 |
|  26 |         TABLE ACCESS BY INDEX ROWID  | LEGALREQUEST                |     1 |     8 |       |     2   (0)| 00:00:01 |
|* 27 |          INDEX RANGE SCAN            | IDX_LEGALREQUEST_01         |     1 |       |       |     1   (0)| 00:00:01 |
|  28 |        BUFFER SORT                   |                             |    11 |    99 |       |     6   (0)| 00:00:01 |
|* 29 |         MAT_VIEW ACCESS FULL         | MV_MATTERTARGET_TYPE        |    11 |    99 |       |     5   (0)| 00:00:01 |
|* 30 |       MAT_VIEW ACCESS BY INDEX ROWID | MV_COLLINTERVIEWPLAN_TYPE2  |     1 |     7 |       |     1   (0)| 00:00:01 |
|* 31 |        INDEX UNIQUE SCAN             | PK_COLCTNINTERVWPLAN_PLANI2 |     1 |       |       |     0   (0)| 00:00:01 |
|  32 |      NESTED LOOPS                    |                             |     1 |    31 |       |   192   (4)| 00:00:03 |
|  33 |       NESTED LOOPS                   |                             |     1 |    23 |       |   191   (4)| 00:00:03 |
|  34 |        NESTED LOOPS                  |                             |     1 |    16 |       |   190   (4)| 00:00:03 |
|  35 |         NESTED LOOPS                 |                             |     1 |     9 |       |     1   (0)| 00:00:01 |
|* 36 |          INDEX UNIQUE SCAN           | PK_PERSON_PERSONID          |     1 |     5 |       |     1   (0)| 00:00:01 |
|* 37 |          INDEX UNIQUE SCAN           | PK_LEGALMATTER_LEGALMATTER1 |     1 |     4 |       |     0   (0)| 00:00:01 |
|* 38 |         MAT_VIEW ACCESS FULL         | MV_MATTERPERFORMER_TYPE     |     1 |     7 |       |   189   (4)| 00:00:03 |
|  39 |        MAT_VIEW ACCESS BY INDEX ROWID| MV_COLLINTERVIEWPLAN_TYPE2  |     1 |     7 |       |     1   (0)| 00:00:01 |
|* 40 |         INDEX UNIQUE SCAN            | PK_COLCTNINTERVWPLAN_PLANI2 |     1 |       |       |     0   (0)| 00:00:01 |
|* 41 |       TABLE ACCESS BY INDEX ROWID    | LEGALREQUEST                |     1 |     8 |       |     1   (0)| 00:00:01 |
|* 42 |        INDEX UNIQUE SCAN             | PK_LEGALREQUEST_REQUESTID   |     1 |       |       |     0   (0)| 00:00:01 |
|  43 |  SORT AGGREGATE                      |                             |     1 |    79 |       |            |          |
|  44 |   NESTED LOOPS                       |                             |     1 |    79 |       |   137   (1)| 00:00:02 |
|* 45 |    HASH JOIN                         |                             |   107 |  6206 |       |    30   (4)| 00:00:01 |
|  46 |     MAT_VIEW ACCESS FULL             | MV_NOTICE_TYPE              |   300 |  2100 |       |     3   (0)| 00:00:01 |
|  47 |     MERGE JOIN CARTESIAN             |                             | 28346 |  1411K|       |    27   (4)| 00:00:01 |
|  48 |      NESTED LOOPS                    |                             |     1 |    33 |       |     4   (0)| 00:00:01 |
|  49 |       NESTED LOOPS                   |                             |     1 |    25 |       |     2   (0)| 00:00:01 |
|* 50 |        INDEX UNIQUE SCAN             | PK_LEGALMATTER_LEGALMATTER1 |     1 |     4 |       |     1   (0)| 00:00:01 |
|  51 |        TABLE ACCESS BY INDEX ROWID   | PERSON                      |     1 |    21 |       |     1   (0)| 00:00:01 |
|* 52 |         INDEX UNIQUE SCAN            | PK_PERSON_PERSONID          |     1 |       |       |     0   (0)| 00:00:01 |
|  53 |       TABLE ACCESS BY INDEX ROWID    | LEGALREQUEST                |     1 |     8 |       |     2   (0)| 00:00:01 |
|* 54 |        INDEX RANGE SCAN              | IDX_LEGALREQUEST_04         |     1 |       |       |     1   (0)| 00:00:01 |
|  55 |      BUFFER SORT                     |                             | 21853 |   384K|       |    25   (4)| 00:00:01 |
|  56 |       MAT_VIEW ACCESS FULL           | MV_NOTICEREMINDER_TYPE      | 21853 |   384K|       |    23   (5)| 00:00:01 |
|* 57 |    MAT_VIEW ACCESS BY INDEX ROWID    | MV_MATTERPERFORMER_TYPE     |     1 |    21 |       |     1   (0)| 00:00:01 |
|* 58 |     INDEX UNIQUE SCAN                | PK_MATERPERFRMR_MATERPRFRM1 |     1 |       |       |     0   (0)| 00:00:01 |
|  59 |  HASH UNIQUE                         |                             | 58277 |  3699K|  8264K|   980   (3)| 00:00:12 |
|  60 |   NESTED LOOPS                       |                             | 58277 |  3699K|       |    69  (22)| 00:00:01 |
|* 61 |    HASH JOIN                         |                             | 57688 |  3380K|       |    57   (6)| 00:00:01 |
|* 62 |     HASH JOIN                        |                             |   848 | 43248 |       |    12   (9)| 00:00:01 |
|  63 |      TABLE ACCESS FULL               | LEGALREQUEST                |   848 |  6784 |       |     6   (0)| 00:00:01 |
|  64 |      MAT_VIEW ACCESS FULL            | MV_LEGALMATTER_TYPE         |  1782 | 76626 |       |     5   (0)| 00:00:01 |
|  65 |     MAT_VIEW ACCESS FULL             | MV_SCOPETARGET_TYPE         | 57688 |   507K|       |    44   (3)| 00:00:01 |
|* 66 |    INDEX UNIQUE SCAN                 | PK_PERSON_PERSONID          |     1 |     5 |       |     0   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("LR"."REQUESTID"="LN"."REQUESTID")
   3 - access("NRS"."NOTICEID"="LN"."NOTICEID")
   8 - access("LM"."LEGALMATTERID"=:B1)
  10 - access("P1"."PERSONID"=:B1)
  11 - filter("MP"."PERFORMERNAME"="P1"."LASTNAME"||', '||"P1"."FIRSTNAME")
  12 - access("MP"."MATTERPERFORMERID"="NRS"."MATTERPERFORMERID")
  15 - access("LR"."LEGALMATTERID"=:B1)
  24 - access("P1"."PERSONID"=:B1)
  25 - access("LM"."LEGALMATTERID"=:B1)
  27 - access("LR"."LEGALMATTERID"=:B1)
       filter("LR"."LEGALMATTERID"="LM"."LEGALMATTERID")
  29 - filter("MT"."TARGETSYSTEMINSTANCEID"=:B1)
  30 - filter("CIP"."REQUESTID"="LR"."REQUESTID")
  31 - access("MT"."PLANID"="CIP"."PLANID")
  36 - access("P1"."PERSONID"=:B1)
  37 - access("LM"."LEGALMATTERID"=:B1)
  38 - filter("MP"."PLANID" IS NOT NULL AND "MP"."PERFORMERSYSTEMINSTANCEID"=:B1)
  40 - access("MP"."PLANID"="CIP"."PLANID")
  41 - filter("LR"."LEGALMATTERID"=:B1 AND "LR"."LEGALMATTERID"="LM"."LEGALMATTERID")
  42 - access("CIP"."REQUESTID"="LR"."REQUESTID")
  45 - access("LR"."REQUESTID"="LN"."REQUESTID" AND "NRS"."NOTICEID"="LN"."NOTICEID")
  50 - access("LM"."LEGALMATTERID"=:B1)
  52 - access("P1"."PERSONID"=:B1)
  54 - access("LR"."LEGALMATTERID"=:B1)
  57 - filter("MP"."PERFORMERNAME"="P1"."LASTNAME"||', '||"P1"."FIRSTNAME")
  58 - access("MP"."MATTERPERFORMERID"="NRS"."MATTERPERFORMERID")
  61 - access("R"."REQUESTID"="ST"."REQUESTID")
  62 - access("R"."LEGALMATTERID"="LM"."LEGALMATTERID")
  66 - access("ST"."TARGETSYSTEMINSTANCEID"="PMV"."PERSONID")


Statistics
----------------------------------------------------------
         98  recursive calls
          0  db block gets
  101674701  consistent gets
        436  physical reads
          0  redo size
    1697421  bytes sent via SQL*Net to client
      38629  bytes received via SQL*Net from client
       3394  SQL*Net roundtrips to/from client
     228748  sorts (memory)
          0  sorts (disk)
      50887  rows processed


I know you're limited with no schema, this is what I have at the moment. I just need a shove in the right dierction, thanks.

SQL tuning

Sudip Sarkar, April 14, 2008 - 7:38 pm UTC

Hi Tom,
I have been trying to tune a update statement on Oracle 10g running on Solaris.
We were earlier updating the master table in a loop. Then we changed it to a single update. But the performance has not improved.
The Tables are analyzed and the update is using the required indexes.I am not able to get what is going wrong here. Can you please suggest something.
Thanks
Sudip
UPDATE MASTER T1
SET( NUM_CASE,NAME_CASE,NUM_CLIENT,NAME_CLIENT,DT_BIRTH) =
( SELECT( CASE WHEN NVL(B.NUM_CASE, 99) <> NVL(A.NUM_CASE, 99) THEN LPAD(B.NUM_CASE, 9, 0) ELSE LPAD(A.NUM_CASE, 9, 0) END) NUM_CASE,
( CASE WHEN NVL(B.NAME_CASE, '!') <> NVL(A.NAME_CASE, '!') THEN PA_MN_LIBRARY.FN_NAME_ORDER(B.NAME_CASE) ELSE A.NAME_CASE END) NAME_CASE,
A.NUM_CLIENT NUM_CLIENT,
( CASE WHEN(NVL(B.NAME_CLIENT, '!') <> NVL(A.NAME_CLIENT, '!')) THEN PA_MN_LIBRARY.FN_NAME_ORDER(B.NAME_CLIENT) ELSE A.NAME_CLIENT END) NAME_CLIENT,
( CASE WHEN(NVL(TO_NUMBER(TO_CHAR(B.DT_BIRTH, 'MMDDYYYY')), 99999999) <> NVL(TO_NUMBER(TO_CHAR(A.DT_BIRTH, 'MMDDYYYY')), 99999999)) THEN B.DT_BIRTH ELSE A.DT_BIRTH END) DT_BIRTH
FROM MASTER A, ST B
WHERE A.NUM_CLIENT = B.NUM_CLIENT
AND A.FLAG_UPDATE NOT IN('I','P')
AND B.ID_BATCH_RUN=1
AND T1.ROWID = A.ROWID
)
WHERE EXISTS
( SELECT 1
FROM MASTER a,
ST b
WHERE A.NUM_CLIENT = B.NUM_CLIENT
AND A.FLAG_UPDATE NOT IN('I','P')
AND B.ID_BATCH_RUN=1
AND T1.ROWID = A.ROWID);

Execution Plan
----------------------------------------------------------
Plan hash value: 1341364780

----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------
| 0 | UPDATE STATEMENT | | 1 | 71 | 8 (13)| 00:00:01 |
| 1 | UPDATE | MASTER | | | | |
| 2 | NESTED LOOPS | | 1 | 71 | 8 (13)| 00:00:01 |
| 3 | VIEW | VW_SQ_1 | 1 | 7 | 6 (0)| 00:00:01 |
| 4 | SORT UNIQUE | | 1 | 27 | | |
| 5 | NESTED LOOPS | | 1 | 27 | 6 (0)| 00:00:01 |
| 6 | TABLE ACCESS BY INDEX ROWID| ST | 1 | 11 | 4 (0)| 00:00:01
|* 7 | INDEX RANGE SCAN | IX_ST_02 | 1 | | 3 (0)| 00:00:01 |
|* 8 | TABLE ACCESS BY INDEX ROWID| MASTER | 1 | 16 | 2 (0)| 00:00:01 |
|* 9 | INDEX UNIQUE SCAN | MASTER_1_PK | 1 | | 1 (0)| 00:00:01 |
| 10 | TABLE ACCESS BY USER ROWID | MASTER | 1 | 64 | 1 (0)| 00:00:01 |
| 11 | NESTED LOOPS | | 1 | 126 | 4 (0)| 00:00:01 |
|* 12 | TABLE ACCESS BY USER ROWID | MASTER | 1 | 66 | 1 (0)| 00:00:01 |
|* 13 | TABLE ACCESS BY INDEX ROWID | ST | 1 | 60 | 3 (0)| 00:00:01 |
|* 14 | INDEX RANGE SCAN | IX_ST_02 | 1 | | 2 (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

7 - access("B"."ID_BATCH_RUN"=1)
8 - filter("A"."FLAG_UPDATE"<>'I' AND "A"."FLAG_UPDATE"<>'P')
9 - access("A"."NUM_CLIENT"="B"."NUM_CLIENT")
12 - filter("A"."FLAG_UPDATE"<>'I' AND "A"."FLAG_UPDATE"<>'P')
13 - filter("A"."NUM_CLIENT"="B"."NUM_CLIENT")
14 - access("B"."ID_BATCH_RUN"=1)


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
527 bytes sent via SQL*Net to client
1808 bytes received via SQL*Net from client
4 SQL*Net roundtrips to/from client
2 sorts (memory)
0 sorts (disk)
0 rows processed


Tom Kyte
April 16, 2008 - 2:19 pm UTC

      3 consistent gets 


looks awesome from where i'm sitting.


but we digress, this is really funky looking:
UPDATE MASTER T1
        SET( .... ) =
        ( SELECT  ...
            FROM MASTER A, ST B
           WHERE A.NUM_CLIENT = B.NUM_CLIENT
             AND A.FLAG_UPDATE NOT IN('I','P')
             AND B.ID_BATCH_RUN=1
             AND T1.ROWID = A.ROWID
          ) 


umm, why would you query master AGAIN???

why isn't this simply:
UPDATE MASTER T1
        SET( .... ) =
        ( SELECT  ...
            FROM ST B
           WHERE t1.NUM_CLIENT = B.NUM_CLIENT
             AND B.ID_BATCH_RUN=1
          ) 



and you have a where clause that includes the IN clause????


tuning

jas, April 17, 2008 - 9:24 am UTC

SELECT /*+ index(a DMMS_ID) */
A.id, B.id, A.dmms_id, A.date_rev from account_profile A, account_profile B
where A.dmms_id=B.dmms_id and A.id > B.id and A.dmms_id>0 and A.date_rev < sysdate - 7 order by B.id desc
/


---------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost |
---------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 46M| 1406M| | 427K|
| 1 | SORT ORDER BY | | 46M| 1406M| 3530M| 427K|
|* 2 | HASH JOIN | | 46M| 1406M| 1120K| 8973 |
|* 3 | TABLE ACCESS FULL | ACCOUNT_PROFILE | 35732 | 697K| | 4347 |
|* 4 | TABLE ACCESS FULL | ACCOUNT_PROFILE | 714K| 8374K| | 4347 |
---------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("A"."DMMS_ID"="B"."DMMS_ID")
filter("A"."ID">"B"."ID")
3 - filter("A"."DMMS_ID">0 AND "A"."DATE_REV"<SYSDATE@!-7)
4 - filter("B"."DMMS_ID">0)

any help to tune the above will be appreciated
Tom Kyte
April 17, 2008 - 9:34 am UTC

well, you give us *nothing at all to work with*

I really wish we'd see more questions along the lines of "this is my data, let me describe it to you. Now, we have this question"

rather than:

hey, tune this query - this query that might be a) wrong b) full of assumptions you don't need to make.


no primary keys
no indexing scheme
no schema to see what we are dealing with

and no clue what the real question is :(

we could probably do something nice with analytics here - resulting in a single pass on the table (partition by dmms_id order by id desc) but who knows - we don't know what question you are actually trying to answer.


The plan as it is - looks very efficient.

Given that we know nothing about how selective

and A.dmms_id>0
and A.date_rev < sysdate - 7

is - we cannot really evaluate whether an index on (dmms_id,date_rev) would be useful.

SQL tuning

Sudip Sarkar, April 17, 2008 - 9:44 am UTC

Hi Tom,
Thanks for the answer.
1) The reason to join Master table in the Select clause is that I have to compare all columns from the transaction table and master table and if not equal update the relevant column.
2) the exists clause makes sure that the update works the particular set of record and does not update the rest of rows to a NULL value (I hope I am correct in my assumption).

Thanks and Regards
Sudip
Tom Kyte
April 17, 2008 - 11:49 am UTC

1) ok, so tell me why you had to join again please

Look - don't you realize that if you can access T.ROWID, you can, umm, well, access any of the columns?!?!?!

You do NOT need to reselect that record out in order to have the columns - YOU ALREADY HAVE THEM.

2) I know that, I don't know why you mentioned it though. I'm just saying to add the IN clause to the where clause that has the where exists.


SQL tuning

Sudip Sarkar, April 17, 2008 - 12:39 pm UTC

Oh Dear! I was looking at the statement for ages, how did I miss that. Thanks again for pointing it out again.

Regards
Sudip

Different statistics for same dataset on 2 similar envs

Sanji, April 21, 2008 - 5:47 pm UTC

Tom,

I'm getting different explain plans on 2 similar machines for the same dataset.

Environment
HP-UX 11i, 9.2.0.7 EE.

WORKAREA_SIZE_POLICY=AUTO
PGA_AGGREGATER_TARGET=1.5G

I do a RMAN restore of the production db onto a test machine and then do a
dbms_stats.gather_schema_stats('<schema_name>',method_opt=>'for all columns size auto',cascade=>true, degree=>4)
I then export these statistics to the production machine and import them over there.
So i have the same set of statistics on both machines

I then run the following SQL

on development

OPEN:SANJI:PFIN@ORADEV1>set autotrace traceonly explain
OPEN:SANJI:PFIN@ORADEV1>
select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),p.vendor, p.vendor_vname, p.company, p.proc_level,
p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit, d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01, n.level_detail_02,'','','','', d.activity, d.acct_category,
p.batch_num, p.po_number
from lawson.apdistrib d,
lawson.glchartdtl g,
lawson.glnames n,
TEMP2 p
where p.obj_id=d.api_obj_id
and d.dist_company=n.company
and d.dis_acct_unit=n.acct_unit
and g.chart_name='UR_CHART'
and d.dis_account=g.account
and d.dis_sub_acct=g.sub_account
and d.distrib_date between '01-MAR-2008' and '31-MAR-2008'

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=268708 Card=64297 Bytes=19224803)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'TEMP2' (Cost=4 Card=1 Bytes=96)
2 1 NESTED LOOPS (Cost=268708 Card=64297 Bytes=19224803)
3 2 HASH JOIN (Cost=75112 Card=64297 Bytes=13052291)
4 3 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
5 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=18 Card=21 Bytes=1932)
6 5 NESTED LOOPS (Cost=75060 Card=90233 Bytes=10827960)
7 6 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
8 6 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=15 Card=3)
9 2 INDEX (RANGE SCAN) OF 'TEMP2_OBJID' (NON-UNIQUE) (Cost=3 Card=1)



and on production

OPEN:SANJI:PFIN@LAWSON1>/
Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=106683 Card=64297 Bytes=19224803)
1 0 HASH JOIN (Cost=106683 Card=64297 Bytes=19224803)
2 1 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=29 Card=5734 Bytes=475922)
3 1 HASH JOIN (Cost=106546 Card=90233 Bytes=19490328)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=17Card=21 Bytes=1932)
5 4 NESTED LOOPS (Cost=74839 Card=90233 Bytes=10827960)
6 5 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=22 Card=4401 Bytes=123228)
7 5 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=14 Card=3)
8 3 TABLE ACCESS (FULL) OF 'TEMP2' (Cost=18008 Card=6546905 Bytes=628502880)



Row count

APINVOICE 27492920
GLCHARTDTL 5734
GLNAMES 4401
TEMP2 6546905

TEMP2 is created as

create table temp2 unrecoverable as
select
i.obj_id, i.invoice_dte, i.create_date, v.vendor,v.vendor_vname,i.company, i.proc_level,i.base_inv_amt,
i.batch_num, i.po_number
from lawson.apinvoice i,
lawson.apvenmast v
where i.pay_group in (' 1',' 10',' 15', 'BURL','BSSC','KITC','EFTC', 'CORP','COR1','MODE', 'RENT','MOD1','INFO')
and i.create_date >'01-DEC-2003'
and i.rec_status > 0
and i.vendor=v.vendor
and i.vendor_group=v.vendor_group
and v.vendor_group='UR'
order by 1
/

Row count

322020 APVENMAST
15299884 APINVOICE

alter table sanji.temp2 add constraint temp2_objid primary key(obj_id);

exec dbms_stats.gather_table_stats('SANJI','TEMP2', METHOD_OPT=>'FOR ALL INDEXED COLUMNS SIZE AUTO',CASCADE=>TRUE, DEGREE=>4)

Surprisingly if i delete APDISTRIB statistics on the production environment, i get the same explain plan as on development.
I fail to understand this behaviour. Would appreciate if you can help me on this.

OPEN:SANJI:PFIN@LAWSON1>exec dbms_stats.delete_table_stats('LAWSON','APDISTRIB')
OPEN:SANJI:PFIN@LAWSON1>set autotrace traceonly explain
OPEN:SANJI:PFIN@LAWSON1>select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),p.vendor, p.vendor_vname, p.company, p.proc_level,
2 p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit, d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01, n.level_detail_02,'','','','', d.activity, d.acct_category,
3 p.batch_num, p.po_number
4 from lawson.apdistrib d,
5 lawson.glchartdtl g,
6 lawson.glnames n,
7 TEMP2 p
8 where p.obj_id=d.api_obj_id
9 and d.dist_company=n.company
10 and d.dis_acct_unit=n.acct_unit
11 and g.chart_name='UR_CHART'
12 and d.dis_account=g.account
13 and d.dis_sub_acct=g.sub_account
14 and d.distrib_date between '01-MAR-2008' and '31-MAR-2008'
15 /
Elapsed: 00:00:00.00

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=9311 Card=145 Bytes=50170)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'TEMP2' (Cost=3 Card=1 Bytes=96)
2 1 NESTED LOOPS (Cost=9311 Card=145 Bytes=50170)
3 2 HASH JOIN (Cost=8876 Card=145 Bytes=36250)
4 3 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=29 Card=5734 Bytes=475922)
5 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=2 Card=4 Bytes=556)
6 5 NESTED LOOPS (Cost=8824 Card=19583 Bytes=3270361)
7 6 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=22 Card=4401 Bytes=123228)
8 6 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=1Card=1)
9 2 INDEX (RANGE SCAN) OF 'TEMP2_OBJID' (NON-UNIQUE) (Cost=2 Card=1)


Tom Kyte
April 23, 2008 - 5:28 pm UTC

run a 10053 trace (google for that or search this site for that) and determine what OTHER init.ora parameters affecting the optimizer have come into play.

Different explain plan issue

Sanji, April 25, 2008 - 4:08 pm UTC

Tom, Pertaining to the previous post from me, I generated 10053 event and the only different init parameter's value was of QUERY_REWRITE_ENABLED.
I did see a difference in the table access path
On the test machine it is

SINGLE TABLE ACCESS PATH
Column: DISTRIB_DA Col#: 28 Table: APDISTRIB Alias: D
NDV: 3270 NULLS: 0 DENS: 5.0430e-04
HEIGHT BALANCED HISTOGRAM: #BKT: 200 #VAL: 201
TABLE: APDISTRIB ORIG CDN: 27492920 ROUNDED CDN: 90233 CMPTD CDN: 90233
Access path: tsc Resc: 354383 Resp: 353744
Skip scan: ss-sel 0 andv 15287240
ss cost 15287240
table io scan cost 338844
Access path: index (no sta/stp keys)
Index: APDSET2
TABLE: APDISTRIB
RSC_CPU: 5385579321 RSC_IO: 891847
IX_SEL: 1.0000e+00 TB_SEL: 6.9740e-03
Skip scan: ss-sel 0 andv 15287240
ss cost 15287240
table io scan cost 338844
Access path: index (no sta/stp keys)
Index: APDSET3
TABLE: APDISTRIB
RSC_CPU: 4391016486 RSC_IO: 720687
IX_SEL: 1.0000e+00 TB_SEL: 6.9740e-03
Skip scan: ss-sel 0 andv 15287240
ss cost 15287240
table io scan cost 338844
Access path: index (no sta/stp keys)
Index: APDSET4
TABLE: APDISTRIB
RSC_CPU: 4950176261 RSC_IO: 816916
IX_SEL: 1.0000e+00 TB_SEL: 6.9740e-03
Access path: index (no sta/stp keys)

On the production machine, it is (since it's in production, some amount of data has been loaded since test was created)

SINGLE TABLE ACCESS PATH
Column: DISTRIB_DA Col#: 28 Table: APDISTRIB Alias: D
NDV: 3285 NULLS: 0 DENS: 5.0200e-04
HEIGHT BALANCED HISTOGRAM: #BKT: 200 #VAL: 201
TABLE: APDISTRIB ORIG CDN: 27579595 ROUNDED CDN: 144680 CMPTD CDN: 144680
Access path: tsc Resc: 221314 Resp: 221314
Skip scan: ss-sel 0 andv 15337828
ss cost 15337828
table io scan cost 221314
Access path: index (no sta/stp keys)
Index: APDSET2
TABLE: APDISTRIB
RSC_CPU: 0 RSC_IO: 952897
IX_SEL: 1.0000e+00 TB_SEL: 9.9525e-03
Skip scan: ss-sel 0 andv 15337828
ss cost 15337828
table io scan cost 221314
Access path: index (no sta/stp keys)
Index: APDSET3
TABLE: APDISTRIB
RSC_CPU: 0 RSC_IO: 697705
IX_SEL: 1.0000e+00 TB_SEL: 9.9525e-03
Skip scan: ss-sel 0 andv 15337828
ss cost 15337828
table io scan cost 221314
Access path: index (no sta/stp keys)
Index: APDSET4
TABLE: APDISTRIB
RSC_CPU: 0 RSC_IO: 837267
IX_SEL: 1.0000e+00 TB_SEL: 9.9525e-03
Access path: index (no sta/stp keys)

The values of RSC_CPU & TB_SEL on the production db are 0 & 9.9525e-03 respectively.
Quite different from the test machine.
Am not sure if this is what's causing the plans to change.
Any insight is appreciated.
Thanks
Sanji

Tom Kyte
April 28, 2008 - 12:45 pm UTC

... QUERY_REWRITE_ENABLED ...

and did you try setting it the same on both, that would have been the first obvious thing to do? it is a session level parameter, you can change your session safely without affecting anyone.

Different explain plans issue

Sanji, April 30, 2008 - 9:59 am UTC

Tried that... plans are still different....

Rgds
Tom Kyte
April 30, 2008 - 11:04 am UTC

prove it, lets see the traces afterwards, I'd expect both to have rsc cpu after the change. do they.

Different explain plans issue

Sanji, April 30, 2008 - 11:28 am UTC

I did a "explain plan for", followed by utlxps

The explan plan's predicate information revealed that i had to gather system statistics.

Predicate Information (identified by operation id):
---------------------------------------------------

1 - access("D"."DIS_ACCOUNT"="G"."ACCOUNT" AND "D"."DIS_SUB_ACCT"="G"."SUB_ACCOUNT")
2 - filter("G"."CHART_NAME"='UR_CHART')
3 - access("P"."OBJ_ID"="D"."API_OBJ_ID")
7 - access("D"."DIST_COMPANY"="N"."COMPANY" AND "D"."DIS_ACCT_UNIT"="N"."ACCT_UNIT"
AND "D"."DISTRIB_DATE">=TO_DATE('2008-03-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND
"D"."DISTRIB_DATE"<=TO_DATE('2008-03-31 00:00:00', 'yyyy-mm-dd hh24:mi:ss'))
filter("D"."DISTRIB_DATE">=TO_DATE('2008-03-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss')
AND "D"."DISTRIB_DATE"<=TO_DATE('2008-03-31 00:00:00', 'yyyy-mm-dd hh24:mi:ss'))

Note: CPU Costing is off

I then executed dbms_stats.gather_system_stats and this time too the explain plan was same. The only difference being "Note" wasn't there.

Looking at the predicate information, i realized it's enforcing the to_date function on the inputs, so i changed the query to have the clause

"and d.distrib_date between '2008-03-01' and '2008-03-31'"
instead of
"and d.distrib_date between '01-MAR-2008' and '31-MAR-2008'"

This time, surprisingly i had the same plan as on development

OPEN:SANJI:PFIN@LAWSON1>explain plan for
2 select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),
3 to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),
4 p.vendor, p.vendor_vname, p.company, p.proc_level,
5 p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit,
6 d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
7 n.level_detail_02,'','','','', d.activity, d.acct_category,
8 p.batch_num, p.po_number
9 from lawson.apdistrib d,
10 lawson.glchartdtl g,
11 lawson.glnames n,
12 ur298 p
13 where p.obj_id=d.api_obj_id
14 and d.dist_company=n.company
15 and d.dis_acct_unit=n.acct_unit
16 and g.chart_name='UR_CHART'
17 and d.dis_account=g.account
18 and d.dis_sub_acct=g.sub_account
19 and d.distrib_date between '2008-03-01' and '2008-03-31'
20 /

Explained.

Elapsed: 00:00:00.01
OPEN:SANJI:PFIN@LAWSON1>@?/rdbms/admin/utlxpls

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------

----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 49344 | 14M| 161K (1)|
|* 1 | FILTER | | | | |
| 2 | TABLE ACCESS BY INDEX ROWID | UR298 | 1 | 96 | 3 (34)|
| 3 | NESTED LOOPS | | 49344 | 14M| 161K (1)|
|* 4 | HASH JOIN | | 49344 | 9782K| 61878 (1)|
|* 5 | TABLE ACCESS FULL | GLCHARTDTL | 5734 | 464K| 47 (7)|
| 6 | TABLE ACCESS BY INDEX ROWID| APDISTRIB | 16 | 1472 | 15 (7)|
| 7 | NESTED LOOPS | | 68949 | 8079K| 61827 (1)|
| 8 | TABLE ACCESS FULL | GLNAMES | 4401 | 120K| 35 (6)|
|* 9 | INDEX RANGE SCAN | APDSET4 | 1 | | 14 (8)|
|* 10 | INDEX RANGE SCAN | UR298_OBJID_PK | 1 | | 2 (50)|
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter(TO_DATE('2008-03-01')<=TO_DATE('2008-03-31'))
4 - access("D"."DIS_ACCOUNT"="G"."ACCOUNT" AND "D"."DIS_SUB_ACCT"="G"."SUB_ACCOUNT")
5 - filter("G"."CHART_NAME"='UR_CHART')
9 - access("D"."DIST_COMPANY"="N"."COMPANY" AND "D"."DIS_ACCT_UNIT"="N"."ACCT_UNIT"
AND "D"."DISTRIB_DATE">='2008-03-01' AND "D"."DISTRIB_DATE"<='2008-03-31')
filter("D"."DISTRIB_DATE">='2008-03-01' AND "D"."DISTRIB_DATE"<='2008-03-31')
10 - access("P"."OBJ_ID"="D"."API_OBJ_ID")


This behaviour is not synchronous with the development machine as in i don't need to change the date format.

Thanks

Tom Kyte
April 30, 2008 - 12:54 pm UTC

never compare a string to a date

compare a date to a date

always use to_date WITH a format

Different explain plans issue

Sanji, April 30, 2008 - 11:32 am UTC

Just a small update...
I had renamed TEMP1 to UR298 and it's index to UR298_OBJID_PK.

Do i need to look into the system's default date format on the production machine.

Rgds
Tom Kyte
April 30, 2008 - 12:54 pm UTC

see above

DO NOT RELY ON IMPLICIT CONVERSIONS

you will be asking for trouble if you do.

Different explain plans issue

Sanji, April 30, 2008 - 12:59 pm UTC

With the clause (on production)

"and d.distrib_date between to_date('01-MAR-2008') and to_date('31-MAR-2008')

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=142799 Card=103542 Bytes=30959058)
1 0 HASH JOIN (Cost=142799 Card=103542 Bytes=30959058)
2 1 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
3 1 HASH JOIN (Cost=142744 Card=144680 Bytes=31250880)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=18 Card=33 Bytes=3036)
5 4 NESTED LOOPS (Cost=75075 Card=144680 Bytes=17361600)
6 5 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
7 5 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=14 Card=4)
8 3 TABLE ACCESS (FULL) OF 'UR298' (Cost=29351 Card=6572052 Bytes=630916992)

with clause (on production)

d.distrib_date between to_date('2008-03-01') and to_date('2008-03-31')

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=161018 Card=49344 Bytes=14753856)
1 0 FILTER
2 1 TABLE ACCESS (BY INDEX ROWID) OF 'UR298' (Cost=3 Card=1 Bytes=96)
3 2 NESTED LOOPS (Cost=161018 Card=49344 Bytes=14753856)
4 3 HASH JOIN (Cost=61878 Card=49344 Bytes=10016832)
5 4 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
6 4 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=15 Card=16 Bytes=1472)
7 6 NESTED LOOPS (Cost=61827 Card=68949 Bytes=8273880)
8 7 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
9 7 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=14 Card=1)
10 3 INDEX (RANGE SCAN) OF 'UR298_OBJID_PK' (UNIQUE) (Cost=2 Card=1)

I checked the nls_database/instance & session properties on both the dbs, and they are the same.
Do i need to look into something else ?

Rgds
Tom Kyte
April 30, 2008 - 1:04 pm UTC

please use the SAME QUERY on both systems.

Different explain plans issue

Sanji, April 30, 2008 - 1:11 pm UTC

On development (ORADEV1)

select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),
to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),
p.vendor, p.vendor_vname, p.company, p.proc_level,
p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit,
d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
n.level_detail_02,'','','','', d.activity, d.acct_category,
p.batch_num, p.po_number
from lawson.apdistrib d,
lawson.glchartdtl g,
lawson.glnames n,
ur298 p
where p.obj_id=d.api_obj_id
and d.dist_company=n.company
and d.dis_acct_unit=n.acct_unit
and g.chart_name='UR_CHART'
and d.dis_account=g.account
and d.dis_sub_acct=g.sub_account
and d.distrib_date between to_date('01-MAR-2008') and to_date('31-MAR-2008');

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=204264 Card=64297 Bytes=19224803)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'UR298' (Cost=3 Card=1 Bytes=96)
2 1 NESTED LOOPS (Cost=204264 Card=64297 Bytes=19224803)
3 2 HASH JOIN (Cost=75112 Card=64297 Bytes=13052291)
4 3 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
5 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=18 Card=21 Bytes=1932)
6 5 NESTED LOOPS (Cost=75060 Card=90233 Bytes=10827960)
7 6 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
8 6 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=15 Card=3)
9 2 INDEX (RANGE SCAN) OF 'UR298_OBJID_PK' (UNIQUE) (Cost=2 Card=1)


OPEN:SANJI:PFIN@ORADEV1>select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),
2 to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),
3 p.vendor, p.vendor_vname, p.company, p.proc_level,
4 p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit,
5 d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
6 n.level_detail_02,'','','','', d.activity, d.acct_category,
7 p.batch_num, p.po_number
8 from lawson.apdistrib d,
9 lawson.glchartdtl g,
10 lawson.glnames n,
11 ur298 p
12 where p.obj_id=d.api_obj_id
13 and d.dist_company=n.company
14 and d.dis_acct_unit=n.acct_unit
15 and g.chart_name='UR_CHART'
16 and d.dis_account=g.account
17 and d.dis_sub_acct=g.sub_account
18 and d.distrib_date between to_date('2008-03-01') and to_date('2008-03-31')
19 /
Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=164658 Card=48976 Bytes=14643824)
1 0 FILTER
2 1 TABLE ACCESS (BY INDEX ROWID) OF 'UR298' (Cost=3 Card=1Bytes=96)
3 2 NESTED LOOPS (Cost=164658 Card=48976 Bytes=14643824)
4 3 HASH JOIN (Cost=66281 Card=48976 Bytes=9942128)
5 4 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
6 4 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=16 Card=16 Bytes=1472)
7 6 NESTED LOOPS (Cost=66231 Card=68732 Bytes=8247840)
8 7 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
9 7 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=15 Card=1)
10 3 INDEX (RANGE SCAN) OF 'UR298_OBJID_PK' (UNIQUE) (Cost=2 Card=1)

The plan only seems to change on the production as depicted in the previous post.

Rgds
Tom Kyte
April 30, 2008 - 3:21 pm UTC

will you please use a date format - your default date formats are different remember.

Different explain plans issue

Sanji, April 30, 2008 - 4:33 pm UTC

Would this be correct

On development
"and d.distrib_date between to_date('2008-03-01','YYYY-MM-DD') and to_date('2008-03-31','YYYY-MM-DD')"

OPEN:SANJI:PFIN@ORADEV1>select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'), to_char(p.create_date,'MM/DD/YY'),
2 to_char(d.distrib_date,'MM/DD/YY'), p.vendor, p.vendor_vname, p.company, p.proc_level, p.base_inv_amt,
3 d.orig_base_amt, d.dist_company, d.dis_acct_unit, d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
4 n.level_detail_02,'','','','', d.activity, d.acct_category, p.batch_num, p.po_number
5 from lawson.apdistrib d,
6 lawson.glchartdtl g,
7 lawson.glnames n,
8 UR298 p
9 where p.obj_id=d.api_obj_id
10 and d.dist_company=n.company
11 and d.dis_acct_unit=n.acct_unit
12 and g.chart_name='UR_CHART'
13 and d.dis_account=g.account
14 and d.dis_sub_acct=g.sub_account
15 and d.distrib_date between to_date('2008-03-01','YYYY-MM-DD') and to_date('2008-03-31','YYYY-MM-DD')
16 /
Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=204264 Card=64297 Bytes=19224803)
1 0 TABLE ACCESS (BY INDEX ROWID) OF 'UR298' (Cost=3 Card=1 Bytes=96)
2 1 NESTED LOOPS (Cost=204264 Card=64297 Bytes=19224803)
3 2 HASH JOIN (Cost=75112 Card=64297 Bytes=13052291)
4 3 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
5 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=18 Card=21 Bytes=1932)
6 5 NESTED LOOPS (Cost=75060 Card=90233 Bytes=10827960)
7 6 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
8 6 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=15 Card=3)
9 2 INDEX (RANGE SCAN) OF 'UR298_OBJID_PK' (UNIQUE) (Cost=2 Card=1)

On production
OPEN:SANJI:PFIN@LAWSON1>select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'), to_char(p.create_date,'MM/DD/YY'),
2 to_char(d.distrib_date,'MM/DD/YY'), p.vendor, p.vendor_vname, p.company, p.proc_level, p.base_inv_amt,
3 d.orig_base_amt, d.dist_company, d.dis_acct_unit, d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
4 n.level_detail_02,'','','','', d.activity, d.acct_category, p.batch_num, p.po_number
5 from lawson.apdistrib d,
6 lawson.glchartdtl g,
7 lawson.glnames n,
8 UR298 p
9 where p.obj_id=d.api_obj_id
10 and d.dist_company=n.company
11 and d.dis_acct_unit=n.acct_unit
12 and g.chart_name='UR_CHART'
13 and d.dis_account=g.account
14 and d.dis_sub_acct=g.sub_account
15 and d.distrib_date between to_date('2008-03-01','YYYY-MM-DD') and to_date('2008-03-31','YYYY-MM-DD')
16 /
Elapsed: 00:00:00.00

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=142799 Card=103542 Bytes=30959058)
1 0 HASH JOIN (Cost=142799 Card=103542 Bytes=30959058)
2 1 TABLE ACCESS (FULL) OF 'GLCHARTDTL' (Cost=47 Card=5734 Bytes=475922)
3 1 HASH JOIN (Cost=142744 Card=144680 Bytes=31250880)
4 3 TABLE ACCESS (BY INDEX ROWID) OF 'APDISTRIB' (Cost=18 Card=33 Bytes=3036)
5 4 NESTED LOOPS (Cost=75075 Card=144680 Bytes=17361600)
6 5 TABLE ACCESS (FULL) OF 'GLNAMES' (Cost=35 Card=4401 Bytes=123228)
7 5 INDEX (RANGE SCAN) OF 'APDSET4' (UNIQUE) (Cost=14 Card=4)
8 3 TABLE ACCESS (FULL) OF 'UR298' (Cost=29351 Card=6572052 Bytes=630916992)
Tom Kyte
April 30, 2008 - 6:05 pm UTC

now, let us see the differences between these identical queries from the 10053 trace

Different explain plans issue

Sanji, May 01, 2008 - 1:08 pm UTC

And should i paste the entire text from the 10053 trace ?

Thanks
Tom Kyte
May 01, 2008 - 3:01 pm UTC

no, just what you did above, the relevant portions

if you have differences, that is what is causing the differing plans. If you do not have differences, then - well, then we have something interesting.

Different explain plans issue

Sanji, May 01, 2008 - 4:00 pm UTC

10053 trace from development

***********************
Join order[7]: GLCHARTDTL[G]#1 GLNAMES[N]#0 UR298[P]#3 APDISTRIB[D]#2
Now joining: UR298[P]#3 *******
NL Join
Outer table: cost: 197267 cdn: 25233134 rcz: 111 resp: 197266
Inner table: UR298
Access path: tsc Resc: 28931
Join: Resc: 730026715414 Resp: 730026715413
Best NL cost: 730026715414 resp: 730026715413
Join cardinality: 163884155455800 = outer (25233134) * inner (6494800) * sel (1.0000e+00) [flag=0]
***********************
Join order[8]: GLCHARTDTL[G]#1 APDISTRIB[D]#2 GLNAMES[N]#0 UR298[P]#3
Now joining: APDISTRIB[D]#2 *******
NL Join
Outer table: cost: 47 cdn: 5734 rcz: 83 resp: 45
Inner table: APDISTRIB
Access path: tsc Resc: 353744
Join: Resc: 2028370141 Resp: 2028370140
Access path: index (no sta/stp keys)
Index: APDSET2
TABLE: APDISTRIB
RSC_CPU: 4398744918 RSC_IO: 757001
IX_SEL: 1.0000e+00 TB_SEL: 8.6673e-07
Join: resc: 4352275908 resp: 4352275908
Access path: index (no sta/stp keys)
Index: APDSET3
TABLE: APDISTRIB
.
.
.
***********************
Join order[9]: GLCHARTDTL[G]#1 UR298[P]#3 GLNAMES[N]#0 APDISTRIB[D]#2
Now joining: UR298[P]#3 *******
NL Join
Outer table: cost: 47 cdn: 5734 rcz: 83 resp: 45
Inner table: UR298
Access path: tsc Resc: 28931
Join: Resc: 165891927 Resp: 165891926
Best NL cost: 165891927 resp: 165891926
Join cardinality: 37237935800 = outer (5734) * inner (6494800) * sel (1.0000e+00) [flag=0]
.
.
***********************
Join order[15]: APDISTRIB[D]#2 UR298[P]#3 GLCHARTDTL[G]#1 GLNAMES[N]#0
***********************
Join order[16]: UR298[P]#3 GLNAMES[N]#0 GLCHARTDTL[G]#1 APDISTRIB[D]#2
Now joining: GLNAMES[N]#0 *******
NL Join
Outer table: cost: 28932 cdn: 6494800 rcz: 96 resp: 28931
Inner table: GLNAMES
Access path: tsc Resc: 34
Join: Resc: 223417061 Resp: 223417061
Best NL cost: 223417061 resp: 223417061
Join cardinality: 28583614800 = outer (6494800) * inner (4401) * sel (1.0000e+00) [flag=0]
***********************
Join order[17]: UR298[P]#3 GLCHARTDTL[G]#1 GLNAMES[N]#0 APDISTRIB[D]#2
Now joining: GLCHARTDTL[G]#1 *******
NL Join
Outer table: cost: 28932 cdn: 6494800 rcz: 96 resp: 28931
Inner table: GLCHARTDTL
Access path: tsc Resc: 45
Join: Resc: 295123856 Resp: 295123856
.
.
Final - All Rows Plan:
JOIN ORDER: 3
CST: 204264 CDN: 64297 RSC: 204263 RSP: 204263 BYTES: 19224803
IO-RSC: 203488 IO-RSP: 203488 CPU-RSC: 1680019229 CPU-RSP: 1681452729
QUERY
explain plan for
select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),
to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),
p.vendor, p.vendor_vname, p.company, p.proc_level,
p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit,
d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
n.level_detail_02,'','','','', d.activity, d.acct_category,
p.batch_num, p.po_number
from lawson.apdistrib d,
lawson.glchartdtl g,
lawson.glnames n,
ur298 p
where p.obj_id=d.api_obj_id
and d.dist_company=n.company
and d.dis_acct_unit=n.acct_unit
and g.chart_name='UR_CHART'
and d.dis_account=g.account
and d.dis_sub_acct=g.sub_account
and d.distrib_date between TO_DATE('2008-03-01', 'yyyy-mm-dd') and TO_DATE('2008-03-31', 'yyyy-mm-dd')
PLAN
Cost of plan: 204264
Operation...........Object name.....Options.........Id...Pid..
SELECT STATEMENT 0
TABLE ACCESS UR298 BY INDEX ROWID 1
NESTED LOOPS 2 1
HASH JOIN 3 2
TABLE ACCESS GLCHARTDTL FULL 4 3
TABLE ACCESS APDISTRIB BY INDEX ROWID 5 3
NESTED LOOPS 6 5
TABLE ACCESS GLNAMES FULL 7 6
INDEX APDSET4 RANGE SCAN 8 6
INDEX UR298_OBJID_PK RANGE SCAN 9 2



10053 trace from production

***********************
Join order[7]: GLCHARTDTL[G]#1 APDISTRIB[D]#2 GLNAMES[N]#0 UR298[P]#3
Now joining: APDISTRIB[D]#2 *******
NL Join
Outer table: cost: 47 cdn: 5734 rcz: 83 resp: 46
Inner table: APDISTRIB
Access path: tsc Resc: 355708
Join: Resc: 2039630672 Resp: 2039630671
Access path: index (no sta/stp keys)
Index: APDSET2
TABLE: APDISTRIB
RSC_CPU: 4414676830 RSC_IO: 759741
IX_SEL: 1.0000e+00 TB_SEL: 1.2423e-06
Join: resc: 4368662640 resp: 4368662639
.
.
.
***********************
Join order[9]: APDISTRIB[D]#2 GLNAMES[N]#0 GLCHARTDTL[G]#1 UR298[P]#3
***********************
Join order[10]: APDISTRIB[D]#2 GLNAMES[N]#0 UR298[P]#3 GLCHARTDTL[G]#1
.
.
***********************
Join order[15]: UR298[P]#3 GLNAMES[N]#0 GLCHARTDTL[G]#1 APDISTRIB[D]#2
Now joining: GLNAMES[N]#0 *******
NL Join
Outer table: cost: 29351 cdn: 6572052 rcz: 96 resp: 29350
Inner table: GLNAMES
Access path: tsc Resc: 34
Join: Resc: 226571981 Resp: 226571981
Best NL cost: 226571981 resp: 226571981
Join cardinality: 28923600852 = outer (6572052) * inner (4401) * sel (1.0000e+00) [flag=0]
***********************
Join order[16]: UR298[P]#3 GLCHARTDTL[G]#1 GLNAMES[N]#0 APDISTRIB[D]#2
Now joining: GLCHARTDTL[G]#1 *******
NL Join
Outer table: cost: 29351 cdn: 6572052 rcz: 96 resp: 29350
Inner table: GLCHARTDTL
Access path: tsc Resc: 46
Join: Resc: 299146183 Resp: 299146183
Access path: index (scan)
.
.
***********************
Join order[17]: UR298[P]#3 APDISTRIB[D]#2 GLNAMES[N]#0 GLCHARTDTL[G]#1
Now joining: APDISTRIB[D]#2 *******
NL Join
Outer table: cost: 29351 cdn: 6572052 rcz: 96 resp: 29350
Inner table: APDISTRIB
Access path: tsc Resc: 355708
Join: Resc: 2337732595331 Resp: 2337732595331
Access path: index (scan)
Index: APDSET1
TABLE: APDISTRIB
RSC_CPU: 25909 RSC_IO: 4
.
.
Final - All Rows Plan:
JOIN ORDER: 4
CST: 142799 CDN: 103542 RSC: 142798 RSP: 142798 BYTES: 30959058
IO-RSC: 140150 IO-RSP: 140150 CPU-RSC: 5445730288 CPU-RSP: 5447163788
QUERY
explain plan for
select d.invoice,to_char(p.invoice_dte,'MM/DD/YY'),
to_char(p.create_date,'MM/DD/YY'), to_char(d.distrib_date,'MM/DD/YY'),
p.vendor, p.vendor_vname, p.company, p.proc_level,
p.base_inv_amt, d.orig_base_amt, d.dist_company, d.dis_acct_unit,
d.dis_account, d.dis_sub_acct, g.account_desc,n.level_detail_01,
n.level_detail_02,'','','','', d.activity, d.acct_category,
p.batch_num, p.po_number
from lawson.apdistrib d,
lawson.glchartdtl g,
lawson.glnames n,
ur298 p
where p.obj_id=d.api_obj_id
and d.dist_company=n.company
and d.dis_acct_unit=n.acct_unit
and g.chart_name='UR_CHART'
and d.dis_account=g.account
and d.dis_sub_acct=g.sub_account
and d.distrib_date between TO_DATE('2008-03-01', 'yyyy-mm-dd') and TO_DATE('2008-03-31', 'yyyy-mm-dd')
PLAN
Cost of plan: 142799
Operation...........Object name.....Options.........Id...Pid..
SELECT STATEMENT 0
HASH JOIN 1
TABLE ACCESS GLCHARTDTL FULL 2 1
HASH JOIN 3 1
TABLE ACCESS APDISTRIB BY INDEX ROWID 4 3
NESTED LOOPS 5 4
TABLE ACCESS GLNAMES FULL 6 5
INDEX APDSET4 RANGE SCAN 7 5
TABLE ACCESS UR298 FULL 8 3

Thanks
Tom Kyte
May 01, 2008 - 9:37 pm UTC

diff it please, just summarize *what is different*

tuning query question

A reader, May 06, 2008 - 8:52 am UTC

Hey Tom:

I have couple of questions about the query tuning:

1. before we use cost based optimizor, the order of the table and the order of the conditions in the where clause does matter. But in 10g, the COB is the default, so we don't need to consider these any more except we put /*+ ordered */ hint there, am I correct?

2. what is the effect of distinct to the query, will it more than likely cause the full table scan?

3. the similar question as the first one. before, we need to consider the difference of "EXISTS" AND "IN" , and "NOT EXISTS" and "NOT IN". but since it is CBO now, so we dont need to consider this. am I correct?


Tom Kyte
May 07, 2008 - 12:50 am UTC

1) except you would hardly ever in real life - so infrequently you might never even do it - use the ordered hint.

2) umm, no, it will not "more than likely cause the full table scan". distinct will distinct the results. that is all.

3) correct

ACCESS_PREDICATES and FILTER_PREDICATES

Stan, May 09, 2008 - 11:02 am UTC

Hi Tom,

I'm a little confused by what I'm see, I run:

select t2.module, t1.OBJECT_NAME, t1.operation, t1.access_predicates, t1.filter_predicates, t1.options, t2.EXECUTIONS,
t2.rows_processed, t2.cpu_time, t2.elapsed_time, t2.buffer_gets, t1.cardinality, t2.sql_text, t1.id, t2.address, t2.hash_value, t1.child_number, t1.depth
from v$sql_plan t1,
v$sql t2
where t2.sql_text like '%lb_test_%'
and t1.sql_id = t2.sql_id
and t1.child_number = t2.child_number
order by child_number, address, hash_value, id

To see the actual plan executed for some SQL. One of the results line in the plan shows:

OPERATION: INDEX

ACCESS_PREDICATES: "EVT1"."SUBMIT_TIME">SYSDATE@!-.0416666666666666666666666666666666666667 AND "EVT1"."MESSAGE_SUBTYPE"='EXECUTE_CASH_PROJECTION' AND "EVT1"."SUBMIT_TIME" IS NOT NULL

FILTER_PREDICATES: "EVT1"."MESSAGE_SUBTYPE"='EXECUTE_CASH_PROJECTION'

OPTIONS:RANGE SCAN

Why is ("EVT1"."MESSAGE_SUBTYPE"='EXECUTE_CASH_PROJECTION') present in both ACCESS and FILTER. I thought if we access the data by a component there would be no need to then filter on the same component?

Thanks in advance!



Tom Kyte
May 12, 2008 - 11:50 am UTC

why not:

select * from table(dbms_xplan.display_cursor(sql_id,cursor_child_no))

for an individual query. better formatting - use that when you post the *entire* example please.


ACCESS and FILTER showing same component

Stan, May 12, 2008 - 12:50 pm UTC

OK, same question, why is ("EVT1"."MESSAGE_SUBTYPE"=:SYS_B_1) appearing in the ACCESS and FILTER predicate? If you ACCESS by it why does it need to be in FILTER?

Thanks1


PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID d8dj6gkufsgvr, child number 0
-------------------------------------
SELECT max(instance) lb_test2 FROM
estar.estar_loopback_events evt1 WHERE
evt1.event_id = evt1.batch_event_id || :"SYS_B_0"
AND evt1.message_subtype = :"SYS_B_1"
AND evt1.submit_time > (SYSDATE - :"SYS_B_2"/:"SYS_B_3")

Plan hash value: 87861829

-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 2 |
| 1 | SORT AGGREGATE | | 1 | 64 | |
|* 2 | TABLE ACCESS BY INDEX ROWID| ESTAR_LOOPBACK_EVENTS | 1 | 64 | 2 |
|* 3 | INDEX RANGE SCAN | IND_LOOPBACK_SUBMIT_TIME | 1 | | 2 |
-----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("EVT1"."EVENT_ID"="EVT1"."BATCH_EVENT_ID"||:SYS_B_0)
3 - access("EVT1"."SUBMIT_TIME">SYSDATE@!-:SYS_B_2/:SYS_B_3 AND
"EVT1"."MESSAGE_SUBTYPE"=:SYS_B_1 AND "EVT1"."SUBMIT_TIME" IS NOT NULL)
filter("EVT1"."MESSAGE_SUBTYPE"=:SYS_B_1)

Note
-----
- cpu costing is off (consider enabling it)


31 rows selected

Tom Kyte
May 12, 2008 - 2:05 pm UTC

well, you've made this virtually unreadable...

can you remove some whitespace and show us the creates (tables and indexes).

I'd sort of like to be able to reproduce this all - then I can see what I see.

Access and Filter predicates

Stan, May 13, 2008 - 1:32 pm UTC

Sorry, should have reviewed, the input box doesn't show well. Thanks again.

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - 64bi
PL/SQL Release 10.2.0.3.0 - Production
CORE 10.2.0.3.0 Production
TNS for Solaris: Version 10.2.0.3.0 - Production
NLSRTL Version 10.2.0.3.0 - Production

5 rows selected

Original SQL:

SELECT MAX(instance) lb_test2
FROM estar.estar_loopback_events
WHERE event_id = batch_event_id || '#24271'
AND message_subtype = 'EXECUTE_CASH_PROJECTION'
AND submit_time >(sysdate -1 / 24)


Plan:


SQL_ID a6mbr5kpg4duh, child number 0
-------------------------------------
SELECT MAX(instance) lb_test2 FROM estar.estar_loopback_events WHERE event_id =
batch_event_id || :"SYS_B_0" AND message_subtype = :"SYS_B_1" AND submit_time
>(sysdate -:"SYS_B_2" / :"SYS_B_3")

Plan hash value: 87861829

-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 2 |
| 1 | SORT AGGREGATE | | 1 | 64 | |
|* 2 | TABLE ACCESS BY INDEX ROWID| ESTAR_LOOPBACK_EVENTS | 1 | 64 | 2 |
|* 3 | INDEX RANGE SCAN | IND_LOOPBACK_SUBMIT_TIME | 1 | | 2 |
-----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("EVENT_ID"="BATCH_EVENT_ID"||:SYS_B_0)
3 - access("SUBMIT_TIME">SYSDATE@!-:SYS_B_2/:SYS_B_3 AND
"MESSAGE_SUBTYPE"=:SYS_B_1 AND "SUBMIT_TIME" IS NOT NULL)
filter("MESSAGE_SUBTYPE"=:SYS_B_1)

Note
-----
- cpu costing is off (consider enabling it)


29 rows selected


DLL from SQL-Developer:


CREATE TABLE "ESTAR"."ESTAR_LOOPBACK_EVENTS"
( "INSTANCE" NUMBER(*,0),
"POSN_ID" NUMBER(*,0),
"TRADE_ID" NUMBER(*,0),
"CORP_ACT_INSTANCE" NUMBER(*,0),
"MESSAGE_TYPE" VARCHAR2(55 BYTE),
"MESSAGE_SUBTYPE" VARCHAR2(55 BYTE),
"ENTITY_ID" CHAR(8 BYTE),
"ASSET_ID" NUMBER(*,0),
"CP_REASON" VARCHAR2(50 BYTE),
"POST_DATE" DATE,
"ACCT_DATE" DATE,
"TRADE_DATE" DATE,
"BATCH_EVENT_ID" VARCHAR2(55 BYTE),
"EVENT_ID" VARCHAR2(55 BYTE),
"EVENT_STATUS" NUMBER(*,0),
"SUBMIT_TIME" DATE,
"PROCESS_TIME" DATE,
"UPDATE_USER" VARCHAR2(32 BYTE),
"ENGINE_INSTANCE" NUMBER(*,0),
"MESSAGE_SEQ_ID" NUMBER(*,0),
"PARENT_SEQ_ID" NUMBER(*,0),
"ORIGINAL_SEQ_ID" NUMBER(*,0),
"EVENT_PRIORITY" NUMBER(*,0),
"COMP_LEN" NUMBER(12,0),
"UNCOMP_LEN" NUMBER(12,0),
"CRC" NUMBER(28,0),
"SAVED_EVENT" BLOB,
"PROCESS_CENTER" VARCHAR2(2 BYTE),
"CONVERSION_STATUS" VARCHAR2(10 BYTE),
"BUNDLE_ID" NUMBER(*,0) DEFAULT 0
) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
LOB ("SAVED_EVENT") STORE AS (
TABLESPACE "ESTAR" ENABLE STORAGE IN ROW CHUNK 8192 PCTVERSION 10
NOCACHE LOGGING
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)) ;

COMMENT ON TABLE "ESTAR"."ESTAR_LOOPBACK_EVENTS" IS 'ACCOUNTING Table';

CREATE INDEX "ESTAR"."IDX_3_ESTAR_LOOKBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("EVENT_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LOOPBACK_EVENTS_POSN" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("POSN_ID", "CORP_ACT_INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LPBK_ENGINST_EVTSTAT" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENGINE_INSTANCE", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_ENTITY" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENTITY_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_SUBMIT_TIME" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("SUBMIT_TIME", "EVENT_STATUS", "MESSAGE_TYPE", "MESSAGE_SUBTYPE", "PROCESS_TIME")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LPBK_EVT_BATCH_ID" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("BATCH_EVENT_ID", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."PK_ESTAR_LOOPBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."SYS_IL0000037057C00027$$" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" (
PCTFREE 10 INITRANS 2 MAXTRANS 255
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
PARALLEL (DEGREE 0 INSTANCES 0) ;

CREATE INDEX "ESTAR"."IDX_3_ESTAR_LOOKBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("EVENT_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LOOPBACK_EVENTS_POSN" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("POSN_ID", "CORP_ACT_INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LPBK_ENGINST_EVTSTAT" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENGINE_INSTANCE", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_ENTITY" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENTITY_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_SUBMIT_TIME" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("SUBMIT_TIME", "EVENT_STATUS", "MESSAGE_TYPE", "MESSAGE_SUBTYPE", "PROCESS_TIME")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LPBK_EVT_BATCH_ID" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("BATCH_EVENT_ID", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."PK_ESTAR_LOOPBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."SYS_IL0000037057C00027$$" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" (
PCTFREE 10 INITRANS 2 MAXTRANS 255
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
PARALLEL (DEGREE 0 INSTANCES 0) ;

CREATE INDEX "ESTAR"."IDX_3_ESTAR_LOOKBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("EVENT_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LOOPBACK_EVENTS_POSN" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("POSN_ID", "CORP_ACT_INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LPBK_ENGINST_EVTSTAT" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENGINE_INSTANCE", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_ENTITY" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENTITY_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_SUBMIT_TIME" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("SUBMIT_TIME", "EVENT_STATUS", "MESSAGE_TYPE", "MESSAGE_SUBTYPE", "PROCESS_TIME")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LPBK_EVT_BATCH_ID" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("BATCH_EVENT_ID", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."PK_ESTAR_LOOPBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."SYS_IL0000037057C00027$$" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" (
PCTFREE 10 INITRANS 2 MAXTRANS 255
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
PARALLEL (DEGREE 0 INSTANCES 0) ;

CREATE INDEX "ESTAR"."IDX_3_ESTAR_LOOKBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("EVENT_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LOOPBACK_EVENTS_POSN" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("POSN_ID", "CORP_ACT_INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LPBK_ENGINST_EVTSTAT" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENGINE_INSTANCE", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_ENTITY" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENTITY_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_SUBMIT_TIME" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("SUBMIT_TIME", "EVENT_STATUS", "MESSAGE_TYPE", "MESSAGE_SUBTYPE", "PROCESS_TIME")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LPBK_EVT_BATCH_ID" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("BATCH_EVENT_ID", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."PK_ESTAR_LOOPBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."SYS_IL0000037057C00027$$" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" (
PCTFREE 10 INITRANS 2 MAXTRANS 255
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
PARALLEL (DEGREE 0 INSTANCES 0) ;

CREATE INDEX "ESTAR"."IDX_3_ESTAR_LOOKBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("EVENT_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LOOPBACK_EVENTS_POSN" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("POSN_ID", "CORP_ACT_INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LPBK_ENGINST_EVTSTAT" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENGINE_INSTANCE", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_ENTITY" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENTITY_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_SUBMIT_TIME" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("SUBMIT_TIME", "EVENT_STATUS", "MESSAGE_TYPE", "MESSAGE_SUBTYPE", "PROCESS_TIME")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LPBK_EVT_BATCH_ID" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("BATCH_EVENT_ID", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."PK_ESTAR_LOOPBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."SYS_IL0000037057C00027$$" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" (
PCTFREE 10 INITRANS 2 MAXTRANS 255
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
PARALLEL (DEGREE 0 INSTANCES 0) ;

CREATE INDEX "ESTAR"."IDX_3_ESTAR_LOOKBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("EVENT_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LOOPBACK_EVENTS_POSN" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("POSN_ID", "CORP_ACT_INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IDX_LPBK_ENGINST_EVTSTAT" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENGINE_INSTANCE", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_ENTITY" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("ENTITY_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LOOPBACK_SUBMIT_TIME" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("SUBMIT_TIME", "EVENT_STATUS", "MESSAGE_TYPE", "MESSAGE_SUBTYPE", "PROCESS_TIME")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE INDEX "ESTAR"."IND_LPBK_EVT_BATCH_ID" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("BATCH_EVENT_ID", "EVENT_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."PK_ESTAR_LOOPBACK_EVENTS" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" ("INSTANCE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR" ;

CREATE UNIQUE INDEX "ESTAR"."SYS_IL0000037057C00027$$" ON "ESTAR"."ESTAR_LOOPBACK_EVENTS" (
PCTFREE 10 INITRANS 2 MAXTRANS 255
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "ESTAR"
PARALLEL (DEGREE 0 INSTANCES 0) ;

Tom Kyte
May 13, 2008 - 3:25 pm UTC

Now, that is easy.

here is a small example showing the same:

ops$tkyte%ORA10GR2> create table t ( x int, y int, z int );

Table created.

ops$tkyte%ORA10GR2> create index t_idx on t(x,y,z);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> @at
ops$tkyte%ORA10GR2> column PLAN_TABLE_OUTPUT format a72 truncate
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from t where x > 0 and z = 5;

Execution Plan
----------------------------------------------------------
Plan hash value: 2946670127

------------------------------------------------------------------------
| Id  | Operation        | Name  | Rows  | Bytes | Cost (%CPU)| Time
------------------------------------------------------------------------
|   0 | SELECT STATEMENT |       |     1 |    39 |     2   (0)| 00:00:01
|*  1 |  INDEX RANGE SCAN| T_IDX |     1 |    39 |     2   (0)| 00:00:01
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("X">0 AND "Z"=5 AND "X" IS NOT NULL)
       filter("Z"=5)

Note
-----
   - dynamic sampling used for this statement



since Y is in the middle of X and Z in the index, the "access predicate"

... where x > 0 and z = 5; ...

is using the index (but really only for the X>0 bit for the access), and the filter Z=5 is being applied to the rows in the index.


It is not really happening twice, just 'quirk' of the reporting of the plan. The access is really "X>0" in my case (yours is the date greater than predicate) - the Z=5 bit has to be done for every "X>0" in the index - the index is being filtered.

Unless we put Z first in the index, then it would just be "access" without a subsequent filter. (and it would be more efficient in general, since only the rows of interest in the index would ever be inspected)

Consider:

ops$tkyte%ORA10GR2> create table t ( x int, y int, z int, data int );

Table created.

ops$tkyte%ORA10GR2> insert into t
  2  select object_id, 0, rownum, null
  3    from all_objects;

50357 rows created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx_xyz on t(x,y,z);

Index created.

ops$tkyte%ORA10GR2> create index t_idx_zxy on t(z,x,y);

Index created.

ops$tkyte%ORA10GR2> set termout off
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace on
ops$tkyte%ORA10GR2> select /*+ index(t t_idx_xyz) */ * from t where x > 0 and z = 5;

         X          Y          Z       DATA
---------- ---------- ---------- ----------
        29          0          5


Execution Plan
----------------------------------------------------------
Plan hash value: 3102597340

------------------------------------------------------------------------
| Id  | Operation                   | Name      | Rows  | Bytes | Cost (
------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |           |     2 |   104 |   179
|   1 |  TABLE ACCESS BY INDEX ROWID| T         |     2 |   104 |   179
|*  2 |   INDEX RANGE SCAN          | T_IDX_XYZ |   218 |       |   178
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("X">0 AND "Z"=5 AND "X" IS NOT NULL)
       filter("Z"=5)

Note
-----
   - dynamic sampling used for this statement


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        162  consistent gets
          0  physical reads
          0  redo size
        566  bytes sent via SQL*Net to client
        384  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA10GR2> select /*+ index(t t_idx_zxy) */ * from t where x > 0 and z = 5;

         X          Y          Z       DATA
---------- ---------- ---------- ----------
        29          0          5


Execution Plan
----------------------------------------------------------
Plan hash value: 3737401332

------------------------------------------------------------------------
| Id  | Operation                   | Name      | Rows  | Bytes | Cost (
------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |           |     2 |   104 |     3
|   1 |  TABLE ACCESS BY INDEX ROWID| T         |     2 |   104 |     3
|*  2 |   INDEX RANGE SCAN          | T_IDX_ZXY |     2 |       |     2
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("Z"=5 AND "X">0 AND "X" IS NOT NULL)

Note
-----
   - dynamic sampling used for this statement


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
        566  bytes sent via SQL*Net to client
        384  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA10GR2> set autotrace off





Access and Filter predicates

Stan, May 13, 2008 - 9:16 pm UTC

Hi Tom,

Thank you for the explanation. I'm a little surprised since I have seen vary complex SQL broken up into pieces in the plan. As an FYI, It is an important distinction that the Access predicate may contain a column name which was not used for access. In trying to analyze an existing system one consideration was "when an index is being used how many of the columns in that index are being used?". So, I was considering that if I found the column from the index in the access predicate it was being used (via instr(access_predicate, column_name)).

OK, 1 more question :). In some plans I will see a predicate saying ¿colx=:B and colx is not null¿. Is there ¿extra¿ work happening because the column in the table may contain NULLs? That is to say, would it be ¿quicker¿ we knew the column would never contain NULLs and was defined as NOT NULL?

Tom Kyte
May 14, 2008 - 3:54 pm UTC

but the column IS BEING USED in that index - you are avoiding the table, the index is using that column in it's act of being processed. Not sure why you think it isn't?

anytime you have a not null attribute that is defined as nullable - you have a bug in your model, fix it. Yes, define everything that is NOT NULL as NOT NULL - the optimizer will use that fact when optimizing queries!! It opens up access paths that might not be otherwise possible.


Access and Filter predicates

Stan, May 14, 2008 - 11:25 am UTC

Hi Tom,

thanks again for your response. So, just to clarify, for the same plan id if the filter predicate contains a component then that component was NOT used in the access predicate?

Also, then I don't understand why id 7 below was a "skip scan" and did not use the other components from the index since here they appear in a "matching" order to the index?

--------------------------------------------------------------------------
| Id | Operation | Name --------------------------------------------------------------------------
| 0 | SELECT STATEMENT | |
|* 1 | COUNT STOPKEY | |
|* 2 | FILTER | |
| 3 | NESTED LOOPS OUTER | |
| 4 | NESTED LOOPS OUTER | |
| 5 | NESTED LOOPS OUTER | |
| 6 | TABLE ACCESS BY INDEX ROWID| ESTAR_LOOPBACK_EVENTS |
|* 7 | INDEX SKIP SCAN | IND_LOOPBACK_SUBMIT_TIME |
| 8 | TABLE ACCESS BY INDEX ROWID| SECURITY_MASTER |
|* 9 | INDEX UNIQUE SCAN | PK_SECURITY_MASTER |
| 10 | TABLE ACCESS BY INDEX ROWID | ESTAR_MESSAGE_NAMES |
|* 11 | INDEX UNIQUE SCAN | UK_ELBEN |
| 12 | TABLE ACCESS BY INDEX ROWID | ENGINE_CONFIGURATION_HIST |
|* 13 | INDEX RANGE SCAN | IDX_ENGINE_CONFIGURATION_HIST --------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter(ROWNUM<:SYS_B_12)
2 - filter(TO_DATE(:SYS_B_05,:SYS_B_06)<TO_DATE(:SYS_B_07,:SYS_B_08))
7 - access("A"."SUBMIT_TIME">TO_DATE(:SYS_B_05,:SYS_B_06) AND "A"."EVENT_STATUS"=:SYS_B_11 AND
"A"."MESSAGE_TYPE"=:SYS_B_09 AND "A"."MESSAGE_SUBTYPE"=:SYS_B_10 AND
"A"."SUBMIT_TIME"<TO_DATE(:SYS_B_07,:SYS_B_08))
filter(("A"."EVENT_STATUS"=:SYS_B_11 AND "A"."MESSAGE_SUBTYPE"=:SYS_B_10 AND
"A"."MESSAGE_TYPE"=:SYS_B_09))
9 - access("A"."ASSET_ID"="B"."SECURITY_ALIAS")
11 - access("C"."MESSAGE_TYPE"=:SYS_B_09 AND "C"."MESSAGE_SUBTYPE"=:SYS_B_10)
13 - access("A"."ENGINE_INSTANCE"="D"."ENGINE_INSTANCE")

Tom Kyte
May 14, 2008 - 3:56 pm UTC

the column was used from the index, it was in the index - we had to filter on it since using the index to read the data sorted or anything like that was out of the question.

as for the second part - start over, I don't know what the query was. Please try to keep it concise - we don't need all indexes, we need just the ones in question AND the query.

I don't hip hop up and down the page - i like everything self contained - gets too confusing to have to page up and down and all around.

Performance Issue of sql query

A reader, May 20, 2008 - 11:55 am UTC

SELECT /*+ RULE */
a.interface_header_attribute1 order_num,
a.interface_header_context SOURCE, a.trx_number inv_num,
a.trx_date inv_date, d.gl_date, hzp.party_name customer_name,
hzca.account_number cust_number, d.cust_trx_line_gl_dist_id,
e.segment1, e.segment2, e.segment3, e.segment4, e.segment5, e.segment6,
e.segment7, e.segment8, e.segment9, e.segment10,
a.invoice_currency_code, d.amount,
(CASE
WHEN a.invoice_currency_code = 'USD'
THEN d.amount
WHEN a.invoice_currency_code <> 'USD'
THEN (d.amount * exchange_rate)
END
) foreign_currency_amount,
d.org_id, hzp.country country_code,
ftv.territory_short_name country_name
FROM ra_customer_trx_all a,
ra_batch_sources_all b,
ra_cust_trx_types_all c,
ra_cust_trx_line_gl_dist_all d,
gl_code_combinations e,
ra_site_uses_all rsu,
hz_cust_accounts hzca,
hz_cust_acct_sites_all hzcas,
hz_parties hzp,
hz_party_sites hzps,
fnd_territories_vl ftv
WHERE a.batch_source_id = b.batch_source_id
AND a.customer_trx_id = d.customer_trx_id
AND a.bill_to_site_use_id = rsu.site_use_id
AND hzca.cust_account_id = hzcas.cust_account_id
AND hzcas.cust_acct_site_id = rsu.address_id
AND hzcas.party_site_id = hzps.party_site_id
AND hzps.party_id = hzp.party_id
AND site_use_code = 'BILL_TO'
AND d.code_combination_id = e.code_combination_id
AND a.cust_trx_type_id = c.cust_trx_type_id
AND d.account_class = 'REV'
AND e.segment6 = '509'
AND d.account_set_flag = 'N'
AND c.NAME NOT IN ('CH-CM Dealer-Exp', 'CH-DM Dealer-Exp')
AND ftv.territory_code = hzp.country
-- and a.trx_number = '6003439' -- remove later
-- and a.interface_header_attribute1 = '19025832' -- remove later
AND a.interface_header_attribute1 IN (
SELECT /*+ unnest */ a1.interface_header_attribute1
FROM ra_customer_trx_all a1,
ra_batch_sources_all b,
ra_cust_trx_types_all c,
ra_cust_trx_line_gl_dist_all d,
gl_code_combinations e
WHERE a1.batch_source_id = b.batch_source_id
AND a1.customer_trx_id = d.customer_trx_id
AND d.code_combination_id = e.code_combination_id
AND d.account_class = 'REV'
AND a1.cust_trx_type_id = c.cust_trx_type_id
AND c.NAME IN ('CH-CM Dealer-Exp', 'CH-DM Dealer-Exp')
AND TO_CHAR (d.gl_date, 'YYYY/MM/DD HH24:MI:SS')
BETWEEN ('2008/04/01 00:00:00')
AND ('2008/04/30 00:00:00')
AND e.segment6 = '509'
AND d.account_set_flag = 'N')
UNION
SELECT /*+ RULE */
a.interface_header_attribute1 order_num,
a.interface_header_context SOURCE, a.trx_number inv_num,
a.trx_date inv_date, d.gl_date, hzp.party_name customer_name,
hzca.account_number cust_number, d.cust_trx_line_gl_dist_id,
e.segment1, e.segment2, e.segment3, e.segment4, e.segment5, e.segment6,
e.segment7, e.segment8, e.segment9, e.segment10,
a.invoice_currency_code, d.amount,
(CASE
WHEN a.invoice_currency_code = 'USD'
THEN d.amount
WHEN a.invoice_currency_code <> 'USD'
THEN (d.amount * exchange_rate)
END
) foreign_currency_amount,
d.org_id, hzp.country country_code,
ftv.territory_short_name country_name
FROM ra_customer_trx_all a,
ra_batch_sources_all b,
ra_cust_trx_types_all c,
ra_cust_trx_line_gl_dist_all d,
gl_code_combinations e,
ra_site_uses_all rsu,
hz_cust_accounts hzca,
hz_cust_acct_sites_all hzcas,
hz_parties hzp,
hz_party_sites hzps,
fnd_territories_vl ftv
WHERE a.batch_source_id = b.batch_source_id
AND a.customer_trx_id = d.customer_trx_id
AND a.bill_to_site_use_id = rsu.site_use_id
AND hzca.cust_account_id = hzcas.cust_account_id
AND hzcas.cust_acct_site_id = rsu.address_id
AND hzcas.party_site_id = hzps.party_site_id
AND hzps.party_id = hzp.party_id
AND to_char(site_use_code) = to_char('BILL_TO')
AND d.code_combination_id = e.code_combination_id
AND a.cust_trx_type_id = c.cust_trx_type_id
AND d.account_class = 'REV'
AND e.segment6 = '509'
AND d.account_set_flag = 'N'
-- and a.trx_number = '6003439' -- remove later
-- and a.interface_header_attribute1 = '19025832' -- remove later
AND c.NAME IN ('CH-CM Dealer-Exp', 'CH-DM Dealer-Exp')
AND ftv.territory_code = hzp.country
AND c.NAME IN ('CH-CM Dealer-Exp', 'CH-DM Dealer-Exp')
AND TO_CHAR (d.gl_date, 'YYYY/MM/DD HH24:MI:SS')
BETWEEN ('2008/04/01 00:00:00')
AND ('2008/04/30 00:00:00');

Please could you give me a senoriou how to optimize this sql query.I looking for your feedback.I hope that you will give the feedback as early as possible.

Regards
Abdul.
Tom Kyte
May 20, 2008 - 3:31 pm UTC

remote the rule hint of course.


and don't expect anyone to take a multi-page query and just "tune" it for you - software might be willing to do that since software isn't bored by

a) reverse engineering a query
b) reviewing a schema (which, well, heck - we don't even have!)
c) figuring out other ways to write said query.


do you need union - could it be union all? Do you know the difference between the two (don't just change it, it'll POSSIBLY change the answer you are getting)

this is sort of strange don't you think:

[tkyte@dellpe ~]$ diff x.sql y.sql
36c36
<    AND site_use_code = 'BILL_TO'
---
>    AND to_char(site_use_code) = to_char('BILL_TO')


why to_char one time and not the other - and what the heck - to_char('BILL_TO') - hmmmmmmm


you query the same exact set of tables - I'd be asking myself "hey, can we do this in a single pass??!?!"

Answer is probably "yes", so use your knowledge of SQL to do so.


and for goodness sake, lose the rule hint and the other hints in there as well.

tuning on the queries with variation

A reader, May 27, 2008 - 11:59 am UTC

Hey Tom:

I have a question about query tuning. On the site of my company, we provide customers couple of drop downs to make their own search. But the queries from the search are really hard to tune. like for the same query:

select gd_id
from good_deals
where
price between *** to ****
year between *** to ****
longitude between *** to ***
latititude between *** to ***
.....

so the queries' value really depend on what user want to search. but it creates problem for us because a big price range and the small price range, big year range or small year range etc will definitely make the query to use different indexes. and sometime the CBO is not smart enough to choose the best index. If we add a hint for one specific set of value, it will hurt others. so how do we tune this kind of queries with plenty of variations. how can we make it to pick up the right index all the time?


Tom Kyte
May 27, 2008 - 3:08 pm UTC

well, how often are these queries executed?

continued on above topic

A reader, May 29, 2008 - 8:24 am UTC

Hey Tom:

those queries are executed very often. almost all time.
Tom Kyte
May 29, 2008 - 8:32 am UTC

Ok, let me be more exact:


how many times per second are these queries parsed.

Please help me to solve thiis issue

Nishank Jain, June 02, 2008 - 10:02 am UTC

In one of my interview , I have been asked that suppose we write a query for the table that has 1 million records. And for that query took 2 sec.Now we add 5 million records to the same table ,now the query is taking 10 sec.What are we suppose to do for the query to get the result in less amount of time?
Tom Kyte
June 02, 2008 - 11:54 am UTC

delete 5,000,000 records and rebuild the table (or shrink it) :)


The answer is "it might not be possible, it depends, one would be daft to try to respond given the information"


What if the original query was "select * from t"

it took 2 seconds to return 1,000,000 rows - that was sheer network and IO time.

Now, you add 5,000,000 more records, it takes 10 seconds because of the increased volume of data - unless you upgrade your network and make your disks faster - it is what it is. Maybe you could compress the data, maybe not.



What if the original query was "select * from t where x=? and y=?" and you had an index on X. And the query returns 500 rows (but the index range scan hit 50,000 index entries - accounting for the run time - we did 50,000 index hits and 50,000 table access by index rowids - to get 500 rows)

And you added the 5,000,000 records.

And the query still returns the same 500 records

but takes 5 times as long.

Now, you would research the query and see that it finds 250,000 index hits, does 250,000 table access by index rowids - and returns 500 records.

answer here would be: drop existing index, create index on (x,y). Now both the query against the 1,000,000 row table and 6,000,000 row table will take exactly the same amount of time pretty much and both will be much faster than 2 seconds.




Tuning

Pawan, June 04, 2008 - 6:05 am UTC

Hi Tom,
i am working on 10g database.
i have two table "PATH_RELATIONSHIP_TEMP " contains 2.5 lacs records and "ATTRIBUTE_VALUE_PRODUCT" contains 11 lacs records.
i want to update PATH_RELATIONSHIP_TEMP table from attribute_value_product column.
node_id,rep.product_type_oid has the indexs.product_type_oid has less distinct values.and rep.product_name_oid has more distinct values.
this query is taking to 6-7 minutes to run.i have analyse both the tables.but again it's taking so much time to run.
so how can we fast this query.

declare
english NUMBER(15,0) := 272;
world_wide NUMBER(15,0) := 245;
attr_name NUMBER(15,0) := 2;
attr_desc NUMBER(15,0) := 5;
attr_sni NUMBER(15,0) := 4;
begin
UPDATE PATH_RELATIONSHIP_TEMP rep
SET
( rep.product_type_name, rep.product_type_snf) =
(SELECT MIN (attr_str), MIN (attr_str)
FROM ATTRIBUTE_VALUE_PRODUCT
WHERE node_id = rep.product_type_oid
AND locale_lang_id = english
AND attr_id = attr_name
AND change_lifecycle_id = 0
AND locale_id = world_wide),
product_type_desc =
(SELECT MIN(attr_str)
FROM ATTRIBUTE_VALUE_PRODUCT
WHERE node_id = rep.product_type_oid
AND locale_lang_id = english
AND attr_id = attr_desc
AND change_lifecycle_id = 0
AND locale_id = world_wide),
( product_name_name,product_name_snf )=
(SELECT MIN(attr_str),MIN(attr_str)
FROM ATTRIBUTE_VALUE_PRODUCT
WHERE node_id = rep.product_name_oid
AND locale_lang_id = english
AND attr_id = attr_name
AND change_lifecycle_id = 0
AND locale_id = world_wide),
product_name_desc =
(SELECT MIN(attr_str)
FROM ATTRIBUTE_VALUE_PRODUCT
WHERE node_id = rep.product_name_oid
AND locale_lang_id = english
AND attr_id = attr_desc
AND change_lifecycle_id = 0
AND locale_id = world_wide);
end;

Pawan
Tom Kyte
June 04, 2008 - 10:13 am UTC

ah, the dreaded EAV, entity attribute value, model. I like to call it the "funky data model", a term I coined many many years ago when I first saw and said "wow, that is funky, why the heck would you want to do that"


You'll have to explain to me the use of the min() aggregate here - why is that NECESSARY.


also, really hard to tell what is

a) a column (your variable names should start with l_ for local variable so as to easily distinguish them from columns)

b) what table that column comes from (use correlation names)

c) the tables look like (no creates)

and it would be hard to suggest a rewrite without

a) creates
b) inserts, interesting inserts that test boundary conditions - so if there is some logic behind the MIN() aggregate, you test that condition with your sample data)



Krishna, June 12, 2008 - 2:43 am UTC

Hi tom,

I faced performance problem with this query.
The tables used in this query has tons of data.
Can you pls, suggest me a better sol. for this query to
perform better.

Query
--------

SELECT sum(nvl(bal.invest_bal, 0) + nvl(bal.acct_bal, 0)) as totalBal
FROM cas_chart_acct acct, cas_acct_bal bal
WHERE acct.case_mgmt_acct_cde = trim('B')
and acct.acct_type = 'L'
and acct.case_acct_num = bal.case_acct_num
and bal.trans_dte = (SELECT max(bal.trans_dte)
FROM cas_acct_bal bal
WHERE
bal.case_acct_num = acct.case_acct_num and
bal.trans_dte <= {transDte})
Tom Kyte
June 12, 2008 - 7:53 am UTC

no create table
no insert intos
no look

if you want me to write a syntactically correct, equivalent query - you'd need to do what was specified on the page you used to input this request.

Right under the 'fair warning' where I say "using Text Speak will get you made fun of", it states:

If your followup requires a response that might include a query, you had better supply very very simple create tables and insert statements. I cannot create a table and populate it for each and every question. The SMALLEST create table possible (no tablespaces, no schema names, just like I do in my examples for you)

SQL Tuning

Krishna, June 16, 2008 - 2:45 am UTC

Hi Tom,

As you mentioned, here i am providing create and inserts,

table cas_chart_acct
--------------------
create table CAS_CHART_ACCT
(
CASE_ACCT_NUM VARCHAR2(15) not null,
CASE_ACCT_NME VARCHAR2(100) not null,
ACCT_TYPE VARCHAR2(1) not null,
REVENUE_IND VARCHAR2(1) not null,
ID_NUM VARCHAR2(20),
ID_TYPE VARCHAR2(1),
OPEN_DTE DATE not null,
LAST_TRANS_DTE DATE,
RECEIPT_AMT NUMBER(13,2),
PAYMENT_AMT NUMBER(13,2),
PAYMENT_FEE_AMT NUMBER(13,2),
RECEIPT_FEE_AMT NUMBER(13,2),
ADJUSTMENT_AMT NUMBER(13,2),
PAYMENT_GST_AMT NUMBER(13,2),
RECEIPT_GST_AMT NUMBER(13,2),
INVEST_LAST_WITHDRAWN_DTE DATE,
CASH_BAL_AMT NUMBER(13,2) not null,
INVEST_BAL_AMT NUMBER(13,2) not null,
CREATED_BY VARCHAR2(12) not null,
CREATED_DTE DATE not null,
LAST_UPDATED_BY VARCHAR2(12) not null,
LAST_UPDATED_DTE DATE not null,
CONV_IND VARCHAR2(1),
CASE_MGMT_ACCT_CDE VARCHAR2(2) not null,
CREATED_SRC_IND VARCHAR2(1) not null,
ACCT_USED_FOR VARCHAR2(1),
INVEST_WORK_AMT NUMBER(13,2)
)

insert stmnts:
-------------
insert into CAS.CAS_CHART_ACCT (CASE_ACCT_NUM, CASE_ACCT_NME, ACCT_TYPE, REVENUE_IND, ID_NUM, ID_TYPE, OPEN_DTE, LAST_TRANS_DTE, RECEIPT_AMT, PAYMENT_AMT, PAYMENT_FEE_AMT, RECEIPT_FEE_AMT, ADJUSTMENT_AMT, PAYMENT_GST_AMT, RECEIPT_GST_AMT, INVEST_LAST_WITHDRAWN_DTE, CASH_BAL_AMT, INVEST_BAL_AMT, CREATED_BY, CREATED_DTE, LAST_UPDATED_BY, LAST_UPDATED_DTE, CONV_IND, CASE_MGMT_ACCT_CDE, CREATED_SRC_IND, ACCT_USED_FOR, INVEST_WORK_AMT)
values ('T 0124612005Y00', 'BACHAN KAUR', 'L', 'N', 'S2077644G', 'S', to_date('19-11-2005', 'dd-mm-yyyy'), to_date('21-11-2005', 'dd-mm-yyyy'), 0, 0, 0, 0, 0, 0, 0, null, 0, 0, 'IPTOBIS_CONV', to_date('15-10-2006 21:32:31', 'dd-mm-yyyy hh24:mi:ss'), 'casedit', to_date('09-11-2007 15:31:53', 'dd-mm-yyyy hh24:mi:ss'), 'Y', 'T', 'C', 'U', null);

insert into CAS.CAS_CHART_ACCT (CASE_ACCT_NUM, CASE_ACCT_NME, ACCT_TYPE, REVENUE_IND, ID_NUM, ID_TYPE, OPEN_DTE, LAST_TRANS_DTE, RECEIPT_AMT, PAYMENT_AMT, PAYMENT_FEE_AMT, RECEIPT_FEE_AMT, ADJUSTMENT_AMT, PAYMENT_GST_AMT, RECEIPT_GST_AMT, INVEST_LAST_WITHDRAWN_DTE, CASH_BAL_AMT, INVEST_BAL_AMT, CREATED_BY, CREATED_DTE, LAST_UPDATED_BY, LAST_UPDATED_DTE, CONV_IND, CASE_MGMT_ACCT_CDE, CREATED_SRC_IND, ACCT_USED_FOR, INVEST_WORK_AMT)
values ('T 0124622005L00', 'MUTHUKRISHNAN S/O G', 'L', 'N', 'S2695417G', 'S', to_date('19-11-2005', 'dd-mm-yyyy'), to_date('09-06-2006', 'dd-mm-yyyy'), 0, 0, 0, 0, 0, 0, 0, null, 0, 0, 'IPTOBIS_CONV', to_date('15-10-2006 21:32:31', 'dd-mm-yyyy hh24:mi:ss'), 'IPTOBIS_CONV', to_date('15-10-2006 21:32:31', 'dd-mm-yyyy hh24:mi:ss'), 'Y', 'T', 'C', null, null);

Table 2: cas_acct_bal create
----------------------------

create table CAS_ACCT_BAL
(
CASE_ACCT_NUM VARCHAR2(15) not null,
TRANS_DTE DATE not null,
ACCT_BAL NUMBER(13,2) not null,
INVEST_BAL NUMBER(13,2) not null
)

inserts
--------

insert into CAS.CAS_ACCT_BAL (CASE_ACCT_NUM, TRANS_DTE, ACCT_BAL, INVEST_BAL)
values ('040000051984E00', to_date('22-06-2005', 'dd-mm-yyyy'), 1286158.46, 0);
insert into CAS.CAS_ACCT_BAL (CASE_ACCT_NUM, TRANS_DTE, ACCT_BAL, INVEST_BAL)
values ('040000051984E00', to_date('13-06-2005', 'dd-mm-yyyy'), 1265465.31, 0);
insert into CAS.CAS_ACCT_BAL (CASE_ACCT_NUM, TRANS_DTE, ACCT_BAL, INVEST_BAL)
values ('040000051984E00', to_date('30-05-2005', 'dd-mm-yyyy'), 1084501.83, 0);
insert into CAS.CAS_ACCT_BAL (CASE_ACCT_NUM, TRANS_DTE, ACCT_BAL, INVEST_BAL)
values ('040000051984E00', to_date('29-04-2005', 'dd-mm-yyyy'), 926790.36, 0);
insert into CAS.CAS_ACCT_BAL (CASE_ACCT_NUM, TRANS_DTE, ACCT_BAL, INVEST_BAL)
values ('040000051984E00', to_date('21-04-2005', 'dd-mm-yyyy'), 833795.84, 0);

Tom as I mentioned earlier both these tables have huge data.


Tom Kyte
June 16, 2008 - 11:54 am UTC


YOU KNOW, you'd think if you were to post an example - it would contain meaningful data.


ops$tkyte%ORA10GR2> select * from cas_chart_acct where case_mgmt_acct_cde = 'B' and acct_type = 'L';

no rows selected


but no, that isn't the case - so you provide a set of data that returns zero rows for your query. It is really sort of hard to tell if what we've does works or not - it is highly uninteresting at best.

Anyway, try the second query - UNDERSTAND the second query - I tried to reverse engineer in my brain what your original queries intent was (because no one seems to ever be able to say what it is they "want", they can only give code that seems to sometimes return a value close to what they need...)

Anyway, give it a go, I just join the two tables using your existing criteria, keep the max trans date by account code and then sum them. I skip the extra access to the account balance table


ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> SELECT sum(nvl(bal.invest_bal, 0) + nvl(bal.acct_bal, 0)) as totalBal
  2    FROM cas_chart_acct acct, cas_acct_bal bal
  3   WHERE acct.case_mgmt_acct_cde = trim('B')
  4     and acct.acct_type = 'L'
  5     and acct.case_acct_num = bal.case_acct_num
  6     and bal.trans_dte = (SELECT max(bal.trans_dte)
  7                            FROM cas_acct_bal bal
  8                           WHERE
  9                           bal.case_acct_num =   acct.case_acct_num       and
 10                           bal.trans_dte <= sysdate)
 11  /

  TOTALBAL
----------


ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select sum(totalBal)
  2    from (
  3  SELECT nvl(bal.invest_bal, 0) + nvl(bal.acct_bal, 0) as totalBal,
  4         bal.trans_dte,
  5         max(case when bal.trans_dte <= SYSDATE then bal.trans_dte end)
  6             over (partition by bal.case_acct_num) max_dt
  7    FROM cas_chart_acct acct, cas_acct_bal bal
  8   WHERE acct.case_mgmt_acct_cde = trim('B')
  9     and acct.acct_type = 'L'
 10     and acct.case_acct_num = bal.case_acct_num
 11         )
 12   where trans_dte = max_dt
 13  /

SUM(TOTALBAL)
-------------


ops$tkyte%ORA10GR2>

SQL Tuning

Krishna, June 16, 2008 - 10:43 pm UTC

Thanks a lot tom. I will keep in mind next time to post some
meaningful info regarding the question.

Filter Predicate Question

Stan, June 18, 2008 - 12:37 pm UTC

Hi Tom,

For the plan below, ID 2 filter:

1) What is the point of the filter? It seems the result set should have already taken into account the range and therefore this is redundant?

2) If there really is work going on here does it happen for each row in the result set?

Thanks in advance!!!


PLAN_TABLE_OUTPUT
---------------------
SQL_ID 4qw4qszm9rkgy, child number 0
-------------------------------------
select max(tr.LEDGER_EFFECTIVE_DATE) SBS_31,
tr.LINK_EVENT_ID from TRADESDBO.TRADE tr where
tr.LEDGER_EFFECTIVE_DATE between :pFYTDBeginDate and :iReportEndDate
and tr.SECURITY_ALIAS = :pCurrSecAlias and
tr.ENTITY_ID = :pCurrEntityId group by tr.LINK_EVENT_ID

Plan hash value: 1509780058

----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | | | 5 |
| 1 | SORT GROUP BY | | 1 | 25 | 5 |
|* 2 | FILTER | | | | |
| 3 | TABLE ACCESS BY INDEX ROWID| TRADE | 1 | 25 | 2 |
|* 4 | INDEX RANGE SCAN | TRADE_IDX4 | 1 | | 1 |
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter(TO_DATE(:PFYTDBEGINDATE)<=TO_DATE(:IREPORTENDDATE))
4 - access("TR"."ENTITY_ID"=:PCURRENTITYID AND
"TR"."SECURITY_ALIAS"=TO_NUMBER(:PCURRSECALIAS) AND
"TR"."LEDGER_EFFECTIVE_DATE">=:PFYTDBEGINDATE AND
"TR"."LEDGER_EFFECTIVE_DATE"<=:IREPORTENDDATE)

Note
-----
- cpu costing is off (consider enabling it)


33 rows selected


CREATE TABLE "TRADESDBO"."TRADE"
( "ACCRUED_INTEREST" NUMBER(28,12),
"BLOOMBERG_PRODUCT" CHAR(8 BYTE),
"BUY_SELL_FLAG" CHAR(4 BYTE),
"CANCEL_DUE_TO_CORRECTION" CHAR(4 BYTE),
"COMMISSION_AMOUNT" NUMBER(28,12),
"COMMISSION_CODE" CHAR(8 BYTE),
"COMMISSION_CURRENCY" CHAR(3 BYTE),
"CUSTOMER_ACCT_NUMB" CHAR(30 BYTE),
"DISCOUNT_RATE" NUMBER(28,12),
"EFFECTIVE_DATE" DATE,
"ENTITY_ID" CHAR(8 BYTE),
"FACTOR" NUMBER(28,12),
"INVERT_FLAG" CHAR(4 BYTE),
"LOT_NUMBER" CHAR(8 BYTE),
"TRADE_ID" NUMBER,
"MASTER_TICKET_NUMBER" VARCHAR2(255 BYTE),
"MORTGAGE_FLAG" CHAR(2 BYTE),
"MUNI_FLAG" CHAR(2 BYTE),
"NUMBER_OF_ACCURED_DAYS" NUMBER(28,12),
"POOL_NUMBER" CHAR(12 BYTE),
"POSITION_ID" NUMBER(38,0),
"PRICE_CURRENCY" CHAR(3 BYTE),
"PRICE" NUMBER(28,12),
"RECORD_TYPE" CHAR(4 BYTE),
"REPO_RATE" NUMBER(28,12),
"SALES_PERSON" CHAR(18 BYTE),
"SEC_FEES" NUMBER(28,12),
"SECURITY_ALIAS" NUMBER,
"SETTLEMENT_AMOUNT" NUMBER(28,12),
"SETTLEMENT_CURRENCY" CHAR(3 BYTE),
"SETTLEMENT_DATE" DATE,
"SETTLEMENT_EXCHANGE_RATE" NUMBER(28,12),
"SRC_INTFC_INST" NUMBER,
"TIME_OF_TRADE" NUMBER(28,12),
"TRADE_AMOUNT" NUMBER(28,12),
"TRADE_CURRENCY" CHAR(3 BYTE),
"TRADE_DATE" DATE,
"TRADE_EXCHANGE_RATE" NUMBER(28,12),
"TRADE_FLAT" CHAR(2 BYTE),
"TRADER" CHAR(30 BYTE),
"TRADERS_LOGIN" CHAR(12 BYTE),
"TRANSACTION_ID" VARCHAR2(255 BYTE),
"UPDATE_DATE" DATE,
"UPDATE_SOURCE" CHAR(8 BYTE),
"YIELD" NUMBER(28,12),
"SHORT_TERM_ID" NUMBER,
"BROKER_CODE" CHAR(12 BYTE),
"SETTLEMENT_LOCATION" CHAR(12 BYTE),
"TRANS_CODE" CHAR(55 BYTE),
"PAR_OR_SHARES" NUMBER(28,12),
"COST_LOCAL" NUMBER(28,12),
"COST_BASE" NUMBER(28,12),
"ACCRUED_INCOME_LOCAL" NUMBER(28,12),
"FX_RATE" NUMBER(28,12),
"LOCAL_COMMISSION_AMOUNT" NUMBER(28,12),
"EXCHANGE_FEE" NUMBER(28,12),
"OTHER_FEE" NUMBER(28,12),
"TAXES" NUMBER(28,12),
"WITHHOLDING_TAX" NUMBER(28,12),
"NET_CASH" NUMBER(28,12),
"PRINCIPAL" NUMBER(28,12),
"TRADE_STATUS" CHAR(8 BYTE),
"PRINCIPAL_FACTOR" NUMBER(28,12),
"EXCHANGE_CODE" CHAR(8 BYTE),
"COMMISSION_TYPE_CODE" CHAR(8 BYTE),
"COMMISSION_REASON_CODE" CHAR(8 BYTE),
"FROM_EFFECTIVE_DATE" DATE,
"ORIGINAL_FACE_VALUE" NUMBER(28,12),
"LEDGER_EFFECTIVE_DATE" DATE,
"SCRUB_ID" NUMBER,
"SCRUB_TYPE" CHAR(2 BYTE),
"TRADE_CHAR1" VARCHAR2(30 BYTE),
"BATCH_INSTANCE" NUMBER,
"BANK_ALIAS" NUMBER,
"CUSTODY_BANK_CODE" CHAR(20 BYTE),
"CUSTODY_BANK_DESC" CHAR(50 BYTE),
"CUSTODY_BANK_ACCT_NUM" VARCHAR2(15 BYTE),
"CUSTODY_BANK_SUB_ACCT" VARCHAR2(10 BYTE),
"SENT_TRADE_STATUS" VARCHAR2(2 BYTE),
"HOLD_TRADE_STATUS" VARCHAR2(2 BYTE),
"TARGET_EVENT_ID" VARCHAR2(255 BYTE),
"POST_DATE" DATE,
"SOURCE_SYSTEM" VARCHAR2(2 BYTE),
"SELL_TO_BUY_FX_RATE" NUMBER(28,12),
"SELL_TO_BASE_FX_RATE" NUMBER(28,12),
"BUY_TO_BASE_FX_RATE" NUMBER(28,12),
"TO_ACCOUNT" CHAR(8 BYTE),
"FROM_ACCOUNT" CHAR(8 BYTE),
"TO_SECURITY_ALIAS" NUMBER,
"FROM_SECURITY_ALIAS" NUMBER,
"TO_LONG_SHORT_INDICATOR" VARCHAR2(2 BYTE),
"FROM_LONG_SHORT_INDICATOR" VARCHAR2(2 BYTE),
"TO_SOURCE_SYSTEM" VARCHAR2(2 BYTE),
"FROM_SOURCE_SYSTEM" VARCHAR2(2 BYTE),
"TO_QUANTITY" NUMBER(28,12),
"FROM_QUANTITY" NUMBER(28,12),
"TO_COST_BASIS_TYPE" VARCHAR2(2 BYTE),
"FROM_COST_BASIS_TYPE" VARCHAR2(2 BYTE),
"TO_AMOUNT_LOCAL" NUMBER(28,12),
"FROM_AMOUNT_LOCAL" NUMBER(28,12),
"TO_CASH_TYPE" VARCHAR2(10 BYTE),
"FROM_CASH_TYPE" VARCHAR2(10 BYTE),
"TO_WASH_SALE_ELGBL_IND" VARCHAR2(2 BYTE),
"FROM_WASH_SALE_ELGBL_IND" VARCHAR2(2 BYTE),
"TRADE_BASE_AMOUNT" NUMBER(28,12),
"COST_BASIS_TYPE" CHAR(2 BYTE),
"MTTYPE" CHAR(8 BYTE),
"WASH_SALE_ELIGIBLE_INDICATOR" CHAR(2 BYTE),
"USER_CHAR1" VARCHAR2(30 BYTE),
"USER_CHAR2" VARCHAR2(30 BYTE),
"USER_CHAR3" VARCHAR2(30 BYTE),
"USER_FLOAT1" NUMBER(28,12),
"USER_FLOAT2" NUMBER(28,12),
"USER_FLOAT3" NUMBER(28,12),
"LOT_SELECTION_METHOD" VARCHAR2(8 BYTE),
"EST_VS_ACT" VARCHAR2(3 BYTE),
"CANCEL_LINKED_EVENT_ID" VARCHAR2(255 BYTE),
"ORIG_ACQ_DATE" DATE,
"HOLDING_PERIOD_DATE" DATE,
"ORIG_SETTLEMENT_DATE" DATE,
"STAR_TAG182" VARCHAR2(255 BYTE),
"NAV_ID" NUMBER(28,0),
"OID_YIELD" NUMBER(38,12),
"CALC_YIELD_INT_INDICATOR" NUMBER,
"TURNAROUND_INDICATOR" VARCHAR2(2 BYTE),
"STAR_TAG151" VARCHAR2(255 BYTE),
"ORIG_ACQ_COST_LOCAL" NUMBER(28,12),
"ORIG_ACQ_COST_BASE" NUMBER(28,12),
"STAR_TAG25" VARCHAR2(255 BYTE),
"STAR_TAG26" VARCHAR2(255 BYTE),
"TARGET_TRADE_TICKET_NUMBER" VARCHAR2(255 BYTE),
"ACCT_BASIS" VARCHAR2(5 BYTE),
"EVENT_SEQUENCE" NUMBER,
"MONTH_END_DATE" DATE,
"STAR_LS_IND" VARCHAR2(1 BYTE),
"BASE_CURRENCY" VARCHAR2(3 BYTE),
"CANCEL_EVENT_ID" VARCHAR2(255 BYTE),
"LINK_EVENT_ID" VARCHAR2(255 BYTE),
"REPLAY_IND" VARCHAR2(1 BYTE),
"COST_METHOD" VARCHAR2(2 BYTE),
"CASH_EVENT_SPAWNED" VARCHAR2(1 BYTE),
"SETTLEMENT_METHOD" CHAR(8 BYTE),
"TO_SETTLEMENT_CURRENCY" CHAR(3 BYTE),
"TO_SETTLE_TO_BASE_FX_RATE" NUMBER(28,12),
"TO_FX_RATE" NUMBER(28,12),
"TO_LOCAL_COMMISSION_AMT" NUMBER(28,12),
"PREMIUM_ALLOCATED_LOCAL" NUMBER(28,12),
"PREMIUM_ALLOCATED" NUMBER(28,12),
"TARGET_QUANTITY" NUMBER(28,12),
"CORP_ACTION_TYPE" VARCHAR2(55 BYTE),
"ORIG_TRADE_PRICE" NUMBER(38,12),
"ORIG_BUILTIN_GL_SEC" NUMBER(38,12),
"ORIG_BUILTIN_GL_CURRENCY" NUMBER(38,12),
"ORIG_BUILTIN_GL_DEFERRED" NUMBER(38,12),
"ORIG_BUILTIN_GL_OID" NUMBER(38,12),
"ORIG_BUILTIN_GL_MKT_DISC" NUMBER(38,12),
"CURR_BUILTIN_GL_SEC" NUMBER(38,12),
"CURR_BUILTIN_GL_CURRENCY" NUMBER(38,12),
"CURR_BUILTIN_GL_DEFERRED" NUMBER(38,12),
"CURR_BUILTIN_GL_OID" NUMBER(38,12),
"CURR_BUILTIN_GL_MKT_DISC" NUMBER(38,12),
"CLIENT_ID" VARCHAR2(20 BYTE),
"PRINCIPAL_BASE" NUMBER(38,12),
"DIRTY_PRINCIPAL" NUMBER(38,12),
"DIRTY_PRINCIPAL_BASE" NUMBER(38,12),
"ACCRUED_INTEREST_TYPE" VARCHAR2(3 BYTE),
"TRADE_YIELD" NUMBER(38,12),
"QTY_WASH_SALE_ELIGIBLE" NUMBER(38,12),
"STRATEGY_ID" VARCHAR2(20 BYTE)
) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;

CREATE INDEX "TRADESDBO"."IND_TRADE_SPD1" ON "TRADESDBO"."TRADE" ("POSITION_ID", "SECURITY_ALIAS", "STAR_LS_IND")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;

CREATE UNIQUE INDEX "TRADESDBO"."PK_TRADE" ON "TRADESDBO"."TRADE" ("TRADE_ID")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;

CREATE INDEX "TRADESDBO"."SENT_HOLD_STAT_IND" ON "TRADESDBO"."TRADE" ("SENT_TRADE_STATUS", "HOLD_TRADE_STATUS")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;

CREATE INDEX "TRADESDBO"."TRADE_IDX1" ON "TRADESDBO"."TRADE" ("MASTER_TICKET_NUMBER")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;

CREATE INDEX "TRADESDBO"."TRADE_IDX3" ON "TRADESDBO"."TRADE" ("ENTITY_ID", "SECURITY_ALIAS", "SRC_INTFC_INST", "EFFECTIVE_DATE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;

CREATE INDEX "TRADESDBO"."TRADE_IDX4" ON "TRADESDBO"."TRADE" ("ENTITY_ID", "SECURITY_ALIAS", "LEDGER_EFFECTIVE_DATE")
PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "TRADES" ;



Tom Kyte
June 18, 2008 - 3:29 pm UTC

While I appreciate that you posted a 'test case', it could have been a HECK OF A LOT SMALLER really - to demonstrate the point.

for example

ops$tkyte%ORA10GR2> create table t
  2  ( id number, eff_date date, security_alias number, entity_id number, data varchar2(100) );

Table created.

ops$tkyte%ORA10GR2> create index t_idx on t(security_alias,entity_id,eff_date);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> variable begindate varchar2(30)
ops$tkyte%ORA10GR2> variable enddate varchar2(30)
ops$tkyte%ORA10GR2> variable sec number
ops$tkyte%ORA10GR2> variable entity_id number
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select max(eff_date), id
  2    from t
  3   where eff_date between to_date(:begindate) and to_date(:enddate)
  4     and security_alias = :sec
  5     and entity_id = :entity_id
  6   group by id
  7  /

Execution Plan
----------------------------------------------------------
Plan hash value: 1235069950

---------------------------------------------------------------------------------------
| Id  | Operation                     | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |       |     1 |    48 |     2  (50)| 00:00:01 |
|   1 |  HASH GROUP BY                |       |     1 |    48 |     2  (50)| 00:00:01 |
|*  2 |   FILTER                      |       |       |       |            |          |
|   3 |    TABLE ACCESS BY INDEX ROWID| T     |     1 |    48 |     1   (0)| 00:00:01 |
|*  4 |     INDEX RANGE SCAN          | T_IDX |     1 |       |     2   (0)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter(TO_DATE(:BEGINDATE)<=TO_DATE(:ENDDATE))
   4 - access("SECURITY_ALIAS"=TO_NUMBER(:SEC) AND
              "ENTITY_ID"=TO_NUMBER(:ENTITY_ID) AND "EFF_DATE">=TO_DATE(:BEGINDATE) AND
              "EFF_DATE"<=TO_DATE(:ENDDATE))

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> set autotrace off


demonstrates it quite nicely. Now, you wrote;


1) What is the point of the filter? It seems the result set should have
already taken into account the range and therefore this is redundant?


that is backwards, the filter on two will ensure that the subsequent steps do not happen - they can be SKIPPED ENTIRELY - if the filter (which is tested once) fails. So, if you input null dates, or a begin that is bigger than the end date - the subsequent work is never performed. It is an optimization to ensure the least work is done.

2) If there really is work going on here does it happen for each row in the
result set?


the filter is used to decide whether to do the other stuff - once.

Filter Predicate question

Stan, June 19, 2008 - 12:23 pm UTC

Thanks Tom, that makes sense. I note I get a simliar filter if I add something like :sec < 5.

My confusion came cause I tend to read plans from the bottom up:

3 get result set based on access values
2 apply filter to result set
1 return results

Perhaps this isn't the best approach.

Better: BITMAP INDEX FULL SCAN or FULL TABLE SCAN ?

Pushkar, July 08, 2008 - 3:35 pm UTC

I have a table that has bitmap index on a column. Whenever i select the table, BITMAP INDEX FULL SCAN is used to access the table even if WHERE clause doesn't use bitmap-indexed column. Please see below test case:

Queries:

SQL> create table table_test_src
  2  as select *
  3  from all_objects ;

Table created.

SQL> create table table_test_trg
  2  as select *
  3  from all_objects
  4  where 1 = 2 ;

Table created.

SQL> create bitmap index table_test_src_b1
  2  on table_test_src(object_type) ;

Index created.

SQL> analyze table table_test_src compute statistics ;

Table analyzed.

SQL> select count(*)
  2  from table_test_src ;

  COUNT(*)                                                                      
----------                                                                      
     29164                                                                      

SQL> select count(*)
  2  from table_test_trg ;

  COUNT(*)                                                                      
----------                                                                      
         0                                                                      

SQL> insert into table_test_trg
  2  select *
  3  from table_test_src ;

29164 rows created.

SQL> rollback ;

Rollback complete.

SQL> insert into table_test_trg
  2  select /*+ NO_INDEX(src) */
  3         *
  4  from   table_test_src src ;

29164 rows created.

SQL> rollback  ;

Rollback complete.

SQL> insert into table_test_trg(owner, object_name, object_id, created, last_ddl_time)
  2  select owner, object_name, object_id, created, last_ddl_time
  3  from table_test_src
  4  where owner = 'SYS' ;

10550 rows created.

SQL> rollback ;

Rollback complete.

SQL>  insert into table_test_trg(owner, object_name, object_id, created, last_ddl_time)
  2   select /*+ NO_INDEX(src)  */
  3          owner, object_name, object_id, created, last_ddl_time
  4   from   table_test_src src
  5  where   owner = 'SYS' ;

10550 rows created.

o/p of tkprof for Insert queries:

insert into table_test_trg
select *
from table_test_src 

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00      41.35          0          0          0           0
Execute      1   2400.00    5583.99        408       1822       1601       29164
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2   2400.00    5625.34        408       1822       1601       29164

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 394  (CSADM)

Rows     Row Source Operation
-------  ---------------------------------------------------
  29164  TABLE ACCESS BY INDEX ROWID TABLE_TEST_SRC 
  29164   BITMAP CONVERSION TO ROWIDS 
     18    BITMAP INDEX FULL SCAN TABLE_TEST_SRC_B1 


Rows     Execution Plan
-------  ---------------------------------------------------
      0  INSERT STATEMENT   GOAL: CHOOSE
  29164   TABLE ACCESS   GOAL: ANALYZED (BY INDEX ROWID) OF 
              'TABLE_TEST_SRC'
  29164    BITMAP CONVERSION (TO ROWIDS)
     18     BITMAP INDEX (FULL SCAN) OF 'TABLE_TEST_SRC_B1'

********************************************************************************

insert into table_test_trg
select /*+ NO_INDEX(src) */
       *
from   table_test_src src 

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00      37.60          0          0          0           0
Execute      1   1700.00    1634.08          0       1224       1601       29164
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2   1700.00    1671.68          0       1224       1601       29164

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 394  (CSADM)

Rows     Row Source Operation
-------  ---------------------------------------------------
  29164  TABLE ACCESS FULL TABLE_TEST_SRC 


Rows     Execution Plan
-------  ---------------------------------------------------
      0  INSERT STATEMENT   GOAL: CHOOSE
  29164   TABLE ACCESS   GOAL: ANALYZED (FULL) OF 'TABLE_TEST_SRC'

********************************************************************************

insert into table_test_trg(owner, object_name, object_id, created, last_ddl_time)
select owner, object_name, object_id, created, last_ddl_time
from table_test_src
where owner = 'SYS' 

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00      38.01          0          0          0           0
Execute      1   1000.00     856.01          0       1184        345       10550
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2   1000.00     894.02          0       1184        345       10550

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 394  (CSADM)

Rows     Row Source Operation
-------  ---------------------------------------------------
  10550  TABLE ACCESS BY INDEX ROWID TABLE_TEST_SRC 
  29164   BITMAP CONVERSION TO ROWIDS 
     18    BITMAP INDEX FULL SCAN TABLE_TEST_SRC_B1 


Rows     Execution Plan
-------  ---------------------------------------------------
      0  INSERT STATEMENT   GOAL: CHOOSE
  10550   TABLE ACCESS   GOAL: ANALYZED (BY INDEX ROWID) OF 
              'TABLE_TEST_SRC'
  29164    BITMAP CONVERSION (TO ROWIDS)
     18     BITMAP INDEX (FULL SCAN) OF 'TABLE_TEST_SRC_B1'

********************************************************************************

 insert into table_test_trg(owner, object_name, object_id, created, last_ddl_time)
 select /*+ NO_INDEX(src)  */
        owner, object_name, object_id, created, last_ddl_time
 from   table_test_src src
where   owner = 'SYS' 

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1    100.00      38.94          0          0          0           0
Execute      1    700.00     838.36          1        589        348       10550
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2    800.00     877.30          1        589        348       10550

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 394  (CSADM)

Rows     Row Source Operation
-------  ---------------------------------------------------
  10550  TABLE ACCESS FULL TABLE_TEST_SRC 


Rows     Execution Plan
-------  ---------------------------------------------------
      0  INSERT STATEMENT   GOAL: CHOOSE
  10550   TABLE ACCESS   GOAL: ANALYZED (FULL) OF 'TABLE_TEST_SRC'

********************************************************************************
As evident from o/p of tkprof for both type of Insert queries, FULL TABLE SCAN is better than BITMAP INDEX FULL SCAN in terms of LIOs to fully access a table. So, my question is why CBO is using BITMAP INDEX ? I did testing with different table with varying number of records, like 100, 1 million, etc. but in every case bitmap index was used. 

Thanks in advance.

Tom Kyte
July 08, 2008 - 5:23 pm UTC

I cannot reproduce that and it doesn't make sense.

post output of this

select name || '=' || value from v$parameter where isdefault = 'FALSE';


and of course your version information.

Better: BITMAP INDEX FULL SCAN or TABLE FULL SCAN ?

Pushkar, July 09, 2008 - 4:46 am UTC

Thanks for reply.

Database I use is Oracle9i Enterprise Edition Release 9.2.0.6.0 - 64bit Production. It is used as Enterprise Data Warehouse (EDW).

Query:

SELECT name || ' = ' || value
FROM v$parameter
WHERE isdefault = 'FALSE';

output:

NAME||'='||VALUE
processes = 3000
timed_statistics = TRUE
resource_limit = TRUE
event = 10499 trace name context forever, level 10, 10262 trace name context forever, level 4096, 12805 trace name errorstack forever, level 3
shared_pool_size = 1610612736
sga_max_size = 7366219800
shared_pool_reserved_size = 53687091
large_pool_size = 218103808
java_pool_size = 218103808
enqueue_resources = 20000
nls_language = AMERICAN
nls_territory = AMERICA
nls_date_format = DD-MON-YYYY
nls_length_semantics = CHAR
_enable_list_io = TRUE
resource_manager_plan = EDW_PLAN
control_files = /dev/vgEDWDEV1/rv50-01, /dev/vgEDWDEV2/rv50-02, /dev/vgEDWDEV3/rv50-03, /dev/vgEDWDEV4/rv50-04
db_block_checksum = TRUE
db_block_size = 8192
_db_block_lru_latches = 1024
db_writer_processes = 6
db_keep_cache_size = 218103808
db_recycle_cache_size = 167772160
db_16k_cache_size = 536870912
db_cache_size = 2097152000
compatible = 9.2.0.6
log_archive_max_processes = 4
log_buffer = 33554432
log_checkpoint_interval = 500000
log_checkpoint_timeout = 7200
_log_simultaneous_copies = 128
db_files = 5000
db_file_multiblock_read_count = 8
log_checkpoints_to_alert = TRUE
recovery_parallelism = 16
control_file_record_keep_time = 0
dml_locks = 10000
_bump_highwater_mark_count = 125
transaction_auditing = FALSE
_cleanup_rollback_entries = 128
undo_management = AUTO
undo_tablespace = UNDOTBS1
undo_retention = 57600
fast_start_parallel_rollback = false
max_enabled_roles = 80
remote_os_authent = FALSE
remote_login_passwordfile = EXCLUSIVE
dblink_encrypt_login = TRUE
db_domain = cisco.com
instance_name = EDWDEV
session_cached_cursors = 1024
utl_file_dir = /usr/tmp/EDWDEV
job_queue_processes = 20
create_bitmap_area_size = 67108864
bitmap_merge_area_size = 67108864
parallel_min_servers = 0
parallel_max_servers = 100
parallel_execution_message_size = 16384
_PX_use_large_pool = TRUE
hash_join_enabled = TRUE
hash_area_size = 67108864
background_dump_dest = /oracle/admin/EDWDEV/bdump
user_dump_dest = /oracle/admin/EDWDEV/udump
max_dump_file_size = 40960
core_dump_dest = /oracle/admin/EDWDEV/cdump
audit_file_dest = /oracle/admin/EDWDEV/audit
hpux_sched_noage = 178
open_links = 50
sort_area_size = 33554432
sort_area_retained_size = 33554432
db_name = EDWDEV
open_cursors = 1024
os_authent_prefix = ops$
optimizer_mode = CHOOSE
blank_trimming = TRUE
partition_view_enabled = TRUE
star_transformation_enabled = TEMP_DISABLE
_complex_view_merging = FALSE
_unnest_subquery = FALSE
_fast_full_scan_enabled = FALSE
parallel_threads_per_cpu = 4
optimizer_max_permutations = 2000
optimizer_index_cost_adj = 10
optimizer_index_caching = 95
query_rewrite_enabled = TRUE
_enable_type_dep_selectivity = FALSE
_sqlexec_progression_cost = 0
pga_aggregate_target = 2097152000
workarea_size_policy = auto
aq_tm_processes = 5

Please let me know in case any further information is needed.

Thanks in advance.
Tom Kyte
July 09, 2008 - 10:38 am UTC

oh that scares me to no end.

do you even know what those _ parameters do.

OH MY WORD

...
_complex_view_merging = FALSE
_unnest_subquery = FALSE
_fast_full_scan_enabled = FALSE
.........

ouch, that has to hurt.

why do you have so so many set, you should have hardly any.

you are a data warehouse, yet you use optimizer_index* parameters????

I would likely blame them - you have said "hey, indexes are so so so very cool, use me all over the place even when it doesn't make sense"


I won't look at this with all of these non-default settings, you got what you asked for. I would suggest an almost empty init.ora - set memory settings, tell us where the control files are.

this is a mess - you really want to consider getting rid of almost every parameter you have set.

SQL with asterick

Selva Muthukumar, July 11, 2008 - 2:40 pm UTC

Tom

I got a question on usage of asterisk on select statements and it's impact

Following are the queries & explain plan

case - 1
SELECT cust_accnt_nbr, NVL (TO_NUMBER (seq_nbr), :"SYS_B_0"),
TO_CHAR (mailed_dt, :"SYS_B_1") mailed_dt
FROM (SELECT *
FROM doc
WHERE doc_file_id = :"SYS_B_2" AND archived_dt > SYSDATE - :"SYS_B_3") doc
JOIN
cust ON cust.cust_id = doc.cust_id
LEFT OUTER JOIN
(SELECT doc_dtl_txt AS seq_nbr, doc_id, seq_nbr AS sub_doc_seq_nbr
FROM doc_dtl
WHERE doc_dtl_type_id = :"SYS_B_4"
AND seq_nbr = :"SYS_B_5"
AND archived_dt > SYSDATE - :"SYS_B_6") seq_nbr
ON seq_nbr.doc_id = doc.doc_id

65980 rows selected.

Elapsed: 00:00:11.27

Execution Plan
----------------------------------------------------------
Plan hash value: 2369295731

-------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 234 | 24570 | 24165 (1)| 00:04:50 | | |
| 1 | NESTED LOOPS | | 234 | 24570 | 24165 (1)| 00:04:50 | | |
| 2 | NESTED LOOPS OUTER | | 232 | 19256 | 23705 (1)| 00:04:45 | | |
| 3 | PARTITION RANGE ITERATOR | | 232 | 7888 | 894 (1)| 00:00:11 | KEY | 49 |
|* 4 | TABLE ACCESS BY LOCAL INDEX ROWID| DOC | 232 | 7888 | 894 (1)| 00:00:11 | KEY | 49 |
|* 5 | INDEX RANGE SCAN | DOC_DOCFILE_OFFSET_NDX | 5123 | | 113 (0)| 00:00:02 | KEY | 49 |
| 6 | PARTITION RANGE ITERATOR | | 1 | 49 | 99 (0)| 00:00:02 | KEY | 49 |
|* 7 | TABLE ACCESS BY LOCAL INDEX ROWID| DOC_DTL | 1 | 49 | 99 (0)| 00:00:02 | KEY | 49 |
|* 8 | INDEX RANGE SCAN | DOC_DTL_DOC_ID_NDX | 1 | | 98 (0)| 00:00:02 | KEY | 49 |
| 9 | TABLE ACCESS BY INDEX ROWID | CUST | 1 | 22 | 2 (0)| 00:00:01 | | |
|* 10 | INDEX UNIQUE SCAN | CUST_PK | 1 | | 1 (0)| 00:00:01 | | |
-------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

4 - filter("ARCHIVED_DT">SYSDATE@!-14)
5 - access("DOC_FILE_ID"=335732)
7 - filter("DOC_DTL_TYPE_ID"(+)=18 AND "ARCHIVED_DT"(+)>SYSDATE@!-14 AND "SEQ_NBR"(+)=0)
8 - access("DOC_ID"(+)="DOC"."DOC_ID")
10 - access("CUST"."CUST_ID"="DOC"."CUST_ID")


Statistics
----------------------------------------------------------
67 recursive calls
0 db block gets
1489709 consistent gets
1 physical reads
0 redo size
3166911 bytes sent via SQL*Net to client
48866 bytes received via SQL*Net from client
4400 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
65980 rows processed

Here i tried replacing asterisk in the from clause with columns (actually doc table has 36 columns and this query need only 3 columns),
the changed query & it's explain plan

case - 2
SELECT cust_accnt_nbr, NVL (TO_NUMBER (seq_nbr), :"SYS_B_0"),
TO_CHAR (mailed_dt, :"SYS_B_1") mailed_dt
FROM (SELECT doc_id, cust_id, mailed_dt
FROM doc
WHERE doc_file_id = :"SYS_B_2" AND archived_dt > SYSDATE - :"SYS_B_3") doc
JOIN
cust ON cust.cust_id = doc.cust_id
LEFT OUTER JOIN
(SELECT doc_dtl_txt AS seq_nbr, doc_id, seq_nbr AS sub_doc_seq_nbr
FROM doc_dtl
WHERE doc_dtl_type_id = :"SYS_B_4"
AND seq_nbr = :"SYS_B_5"
AND archived_dt > SYSDATE - :"SYS_B_6") seq_nbr
ON seq_nbr.doc_id = doc.doc_id

65980 rows selected.

Elapsed: 00:00:11.93

Execution Plan
----------------------------------------------------------
Plan hash value: 2369295731

-------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 234 | 24570 | 24165 (1)| 00:04:50 | | |
| 1 | NESTED LOOPS | | 234 | 24570 | 24165 (1)| 00:04:50 | | |
| 2 | NESTED LOOPS OUTER | | 232 | 19256 | 23705 (1)| 00:04:45 | | |
| 3 | PARTITION RANGE ITERATOR | | 232 | 7888 | 894 (1)| 00:00:11 | KEY | 49 |
|* 4 | TABLE ACCESS BY LOCAL INDEX ROWID| DOC | 232 | 7888 | 894 (1)| 00:00:11 | KEY | 49 |
|* 5 | INDEX RANGE SCAN | DOC_DOCFILE_OFFSET_NDX | 5123 | | 113 (0)| 00:00:02 | KEY | 49 |
| 6 | PARTITION RANGE ITERATOR | | 1 | 49 | 99 (0)| 00:00:02 | KEY | 49 |
|* 7 | TABLE ACCESS BY LOCAL INDEX ROWID| DOC_DTL | 1 | 49 | 99 (0)| 00:00:02 | KEY | 49 |
|* 8 | INDEX RANGE SCAN | DOC_DTL_DOC_ID_NDX | 1 | | 98 (0)| 00:00:02 | KEY | 49 |
| 9 | TABLE ACCESS BY INDEX ROWID | CUST | 1 | 22 | 2 (0)| 00:00:01 | | |
|* 10 | INDEX UNIQUE SCAN | CUST_PK | 1 | | 1 (0)| 00:00:01 | | |
-------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

4 - filter("ARCHIVED_DT">SYSDATE@!-14)
5 - access("DOC_FILE_ID"=335732)
7 - filter("DOC_DTL_TYPE_ID"(+)=18 AND "ARCHIVED_DT"(+)>SYSDATE@!-14 AND "SEQ_NBR"(+)=0)
8 - access("DOC_ID"(+)="DOC_ID")
10 - access("CUST"."CUST_ID"="CUST_ID")


Statistics
----------------------------------------------------------
69 recursive calls
0 db block gets
1489800 consistent gets
154 physical reads
0 redo size
3166911 bytes sent via SQL*Net to client
48866 bytes received via SQL*Net from client
4400 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
65980 rows processed



My understanding is the changed query might be more efficient in terms of system resources (less i/o as we select 3 columns instead of 36 columns, less
cpu,...) but i could not get it proved.

Can you see through and let me know your thoughts. If possible i would love to see you prove this with a example.


Thanks

Selva
Tom Kyte
July 15, 2008 - 8:29 am UTC

if you ask for only that which you need you will

a) process less data
b) cache in memory less data, transmit over network less data
c) possibly avoid going to a segment to fetch data you don't need

c) is the big one. If you have a query such as:

create table t ( x, y, z );
create index t_idx on t(x,y);

select * from t where x = 5;

that'll (probably) use the index, find x=5, and then for each row it finds in the index - hit the table. On the other hand, the very similar query:


select x, y from t where x = 5;

will only have to hit the index, possibly resulting in far fewer IO's than the prior query.



There need be no proof for this particular one, if you do less work, it takes less resources.

Update stmt

balakrishna, July 21, 2008 - 8:22 am UTC

Hi Tom,

Can you pls help me out in tuning this update stmt.



explain plan for UPDATE xxcont_shipping_hd x
SET (x.rma_number, x.rma_date) =
(SELECT y.order_number, y.rma_date
FROM xxcont_shipping_hd y
WHERE y.receipt_number = x.so_line_id
AND y.order_category_code = 'RETURN')
-- AND y.receipt_number IS NOT NULL
WHERE x.order_category_code = 'ORDER' AND (decode(x.rma_number,null,1,1)=1);



PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------

---------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
---------------------------------------------------------------------------------
| 0 | UPDATE STATEMENT | | 108K| 1689K| 4048 (18)|
| 1 | UPDATE | XXCONT_SHIPPING_HD | | | |
|* 2 | TABLE ACCESS FULL | XXCONT_SHIPPING_HD | 108K| 1689K| 4048 (18)|
|* 3 | TABLE ACCESS FULL | XXCONT_SHIPPING_HD | 1 | 17 | 4038 (18)|
---------------------------------------------------------------------------------



Tom Kyte
July 22, 2008 - 10:39 am UTC

no creates
no indexes
nothing to look at - as far as what you have.

no explanation of what you are trying to do (you expect us to reverse engineer your update, figure out what you are trying to do, and rewrite it?)


I can say this confused me :)

(decode(x.rma_number,null,1,1)=1);


that seems like a hard way to say:

[this space left intentionally blank]

decode( X, null, 1, 1 ) = 1

is the same as:

case when x is null then 1 else 1 end = 1

which is the same as

1 = 1

which is the same as

[blank]

ops$tkyte%ORA10GR2> insert into t values ( null );

1 row created.

ops$tkyte%ORA10GR2> insert into t values ( 1 );

1 row created.

ops$tkyte%ORA10GR2> insert into t values ( 2 );

1 row created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select x, decode( x, null, 1, 1 ) dc
  2    from t
  3   where decode( x, null, 1, 1 ) = 1
  4  /

         X         DC
---------- ----------
                    1
         1          1
         2          1




Now, in looking at this query:

explain plan for UPDATE xxcont_shipping_hd x
   SET (x.rma_number, x.rma_date) =
          (SELECT y.order_number, y.rma_date
             FROM xxcont_shipping_hd y
            WHERE y.receipt_number = x.so_line_id
              AND y.order_category_code = 'RETURN')
             -- AND y.receipt_number IS NOT NULL
 WHERE x.order_category_code = 'ORDER' AND (decode(x.rma_number,null,1,1)=1);


there are too many assumptions we have to make there.... in order to rewrite... you would have to be very very specific.

For example, this updates every row in your table such that order_category_code is ORDER - even if there is no match by receipt_number for a RETURN. Is that what you really meant? (probably not, but that is what it does)

This *might* work for you - if it a) does what you need (since we don't know what you need for real, hard to say), b) you are in 10.2


ops$tkyte%ORA10GR2> merge into t
  2  using ( select * from t where order_category_code = 'RETURN' ) t2
  3  on (t.so_line_id = t2.receipt_number and t.order_category_code = 'ORDER')
  4  when matched then update set t.rma_number = t2.order_number, t.rma_date = t2.rma_date;



Autotrace

A reader, July 23, 2008 - 11:17 am UTC

Tom on page 95 of your book Effective Oracle By Design, you speak about the two parts of Autotrace output.

My assumption is that the execution plan that is shown is what Oracle actually used.
True or False?

If so Im just wondering why it did not show the actual row count instead of the cardinality estimate.

I realize that you feel that the purpose of Autotrace is the stats section.

So in short
Explain Plan - What Oracle MAY do if the SQL were to be executed?

Autotrace - What Oracle DID do WITHOUT true row counts?

Tkprof - What Oracle DID WITH true row counts?

Thanks
Tom Kyte
July 24, 2008 - 10:27 am UTC

... My assumption is that the execution plan that is shown is what Oracle actually
used.
True or False?
.....


false


explain plan - what might happen
autotrace - uses explain plan

tkprof and dbms_xplan.display_cursor/display - what actually happened.

about sql_id

Yan, August 05, 2008 - 2:12 pm UTC

hey Tom;

   have a question about sql_id. I have a very simple table.

SQL> select * from test;

no rows selected

SQL> select sql_id from v$sql where sql_text like '%select * from test';

SQL_ID
-------------
c99yw1xkb4f1u



SQL> truncate table test;

Table truncated.

SQL>  select sql_id from v$sql where sql_text like '%select * from test';

no rows selected

SQL> select * from test;

no rows selected

SQL> select sql_id from v$sql where sql_text like '%select * from test';

SQL_ID
-------------
c99yw1xkb4f1u



so after I truncated the table, the sql_id was gone, not in the memory again. When I executed it again, and select query from v$sql, the query with the same sql_id showed up. why when query re-entered memeory, it was assigned the same sql_id. Were this query and plan been stored in some place after it was cleaned out of memory, so next time when it run, it was still be recoganized, then assigned the same sql_id?


another question, I run one query. I get a time. If I run it again, the time is less than the first time because the plan and the data are cached. Then I truncate the table, and reinsert the same data. when I run the same query to the table again, is the time I get is the really time? I mean ths point, is there anything still being cached?


Thank you very much!

Tom Kyte
August 05, 2008 - 6:37 pm UTC

sql_id is a function of the text of the query itself, the same string will always result in the same sql_id (it better, else we'd never be able to find the shared sql again!!!)



as for the last paragraph, you will get rather randomly distributed response times form a query like "select * from t" all of the time, every time.

you might have to parse (or not) - even if you do not truncate, the plan might be flushed you might have to parse.

you might have to soft parse, you might not, depending on the application

you might have to read blocks in from disk, you might not - depending on the state of the cache.

you might have loaded the table with "insert into t select ...", in which case many of the blocks might be in the cache, or you might have loaded with insert /*+ append */ into t..." which bypasses the cache.


basically - it doesn't matter, you want to run the query "many times" along with the other queries that will be executing at that time - if you desire to see what real life might result in.

Execution Plan Changes

Raja, August 06, 2008 - 7:37 am UTC

Hi Tom,

I am with Some interesting issue. The query some time is returning more rows than expected. And infact there is a change in explain plan. When its returning more than expected rows, its not using the "Index". But when the query returns perfect output its using the "Index".

How to analyze this.

Thanks
Tom Kyte
August 06, 2008 - 9:03 am UTC

if you believe you have a query returning the wrong results, you should be on the phone with support - no if and or buts about it.

contiued on last question

Yan, August 12, 2008 - 10:59 am UTC

Hey Tom:

last time you said "sql_id is a function of the text of the query itself, the same string will always result in the same sql_id". Are that possible the queries executed from different users get the same sql_id?

I heard that different query can share the same hash plan, which means there is the same hash plan value for these queries, is that correct?

If the only thing different on two queries are the tables they are based on, (these two tables have exactly the same information), will they share the same hash plan?
for example:

Q1: select * from t1 where blur blur blur.....

Q2: select * from t2 where blur blur blur.....

Tom Kyte
August 13, 2008 - 8:16 am UTC

...
Are that possible the
queries executed from different users get the same sql_id?
....

absolutely, in fact - not only possible - but assured if the users issue two identical queries.

ops$tkyte%ORA11GR1> connect /
Connected.
ops$tkyte%ORA11GR1> drop table t;

Table dropped.

ops$tkyte%ORA11GR1> create table t ( x int );

Table created.

ops$tkyte%ORA11GR1> select * from t look_for_me_please;

no rows selected

ops$tkyte%ORA11GR1> connect scott/tiger
Connected.
scott%ORA11GR1> drop table t;

Table dropped.

scott%ORA11GR1> create table t ( x int );

Table created.

scott%ORA11GR1> select * from t look_for_me_please;

no rows selected

scott%ORA11GR1> connect /
Connected.
ops$tkyte%ORA11GR1> select sql_id, sql_text, parsing_user_id from v$sql where sql_text
  2  like 'select * from t look_for_me_please%';

SQL_ID
-------------
SQL_TEXT
-------------------------------------------------------------------------------
PARSING_USER_ID
---------------
dkafg4pg8ch8g
select * from t look_for_me_please
             81

dkafg4pg8ch8g
select * from t look_for_me_please
             83



... I heard that different query can share the same hash plan, which means
there is the same hash plan value for these queries, is that correct?
...

that is also true, yes. There are an infinite number of queries, the sql_id is a finite namespace. hashing involves taking an infinite universe of things and "hashing" them in to a finite universe - the chances of a duplicate EXIST but are extremely unlikely (and OK - we'd handle it just fine)

format resultset

Krishna, August 13, 2008 - 11:16 pm UTC

Hi Tom,

can we format the resultset into a single string?

Ex: select distinct dept_no from dept;

The above query actually returns morethan 1 record. So, my question is, is it possiable to show all the records retrieved as a single string instead of resultset like '10','20','30','40'. The final output should be string.

Thanks in Advance
Krishna

query tuning

Yan, August 25, 2008 - 2:29 pm UTC

Hey Tom:

thank you for your response, they are very helpful! more questions here about the indexes.

Hello, Tom:

We know the index on a table works fine on the where clauses like ¿A.C1=value¿. Can the join conditions take the advantage of the index?
Like¿A.C1=B. C3¿. If I build a composite index on table A¿s C1 and C2 column, and C1 is the leading column. Can the index work in the following way?

1. index on table A (C1, C2)
Select *********
From A, B
Where A.C1=B.C3
AND A.C2 =¿X¿
After the first join condition, can the index still work for the next equal condition?

2. index on table A (C2, C1)
Select *********
From A, B
Where A.C2 =¿X¿
AND A.C1=B.C3
After the first equal condition, can the index still work for the next join condition?

And which way is more efficient.


Thanks a lot!
Tom Kyte
August 26, 2008 - 8:56 pm UTC

...
1. index on table A (C1, C2)
Select *********
From A, B
Where A.C1=B.C3
AND A.C2 ='X'
After the first join condition, can the index still work for the next equal
condition?
...



if we decided to full scan b, we would find possible rows in A (maybe) thru the index on a.c1, and then evaluate a.c2 = 'X' using that index entry (we are there already) before going to the table.

so the answer is "sort of, but not really", it would be using the index instead of going to the table, the index would help us avoid a table access by index rowid, but we would not be using the index really to find the 'x' values.


2) no, we need to find a row in b, not in a, the index on A would be useful only for finding rows in A.

we would use the index to find the x values, then go to b and find a join row.

query tuning

Yan, August 25, 2008 - 2:35 pm UTC

sorry I don't know what is wrong with that, all the quotes became the upside down question marks.


My question is about the index. We know the index on a table works fine on the where clauses like 'A.C1=value'. Can the join conditions take the advantage of the index?
Like' A.C1=B. C3 '. If I build a composite index on table A's C1 and C2 column, Can the index work in the following way?

1. index on table A (C1, C2)
Select *********
From A, B
Where A.C1=B.C3
AND A.C2 ='X'
After the first join condition, can the index still work for the next equal condition?

2. index on table A (C2, C1)
Select *********
From A, B
Where A.C2 ='X'
AND A.C1=B.C3
After the first equal condition, can the index still work for the next join condition?

And which way is more efficient.
Tom Kyte
August 26, 2008 - 8:57 pm UTC

microsoft "smart" quotes...

how I despise them, entirely...

Yan, August 25, 2008 - 2:41 pm UTC

and also does that matter which column is the leading column?

for the above example, will choosing C1 as leading column be better than C2, or vise versa?
Tom Kyte
August 26, 2008 - 9:00 pm UTC

think about how the data is organized.....


think about how the data is stored....

seriously - try to visualize it - that is what I do.


in the following:

2. index on table A (C2, C1)
Select *********
From A, B
Where A.C2 ='X'
AND A.C1=B.C3
After the first equal condition, can the index still work for the next join condition?



I would be asking:

is "a.c2='x'" going to return a very small set of rows? If so, an index on

a(c2)
b(c3)

might be called for, a(c2) to find the A rows, and then b(c3) to find the mates.

If "a.c2='x'" returns "a lot" (more than a very small) set of rows - then no indexes, just full scan, hash join....

Sql tunning

Biswaranjan, August 26, 2008 - 9:41 am UTC

Hi tom,
If the large table contains thousands of records and the application is accessing 35% of the table which method to use: index searching or full table scan.
I have asked some person, some of them are telling index and some of them arte telling full scan.
Please suggest me to which i should take.(with description).
Tom Kyte
August 26, 2008 - 9:31 pm UTC

...
If the large table contains thousands of records and the application is
accessing 35% of the table which method to use: index searching or full table
scan.
...

it depends, but probably - almost certainly - a full scan.

I can show you an example where accessing less than 2.5% of the rows is better via a full scan, and another where much larger %'s are better via an index.

It depends on how the data in the table is organized on disk.



query tuning

A reader, August 27, 2008 - 10:12 am UTC

Hey Tom:

Thanks for your reply, I summaries what you replied here, can you help to make sure I understand it right.

2. index on table A (C2, C1)
Select *********
From A, B
Where A.C2 ='X'
AND A.C1=B.C3

For this situation,

If a.c2='x' is going to return a very small set of rows, an index on
a(c2)
b(c3)
might be called for, a(c2) to find the A rows, and then b(c3) to find the mates.
(if the query is to pull all other column in a, index on (c2, c1) can not cover all
the columns involved in the query, then index on (c2,c1) is the same with (c2). No use to put c1 in the index.

ElseIf a.c2='x' returns "a lot" (more than a very small) set of rows - then
no indexes, just full scan, hash join....on both a and b.

And after using a.c2='X', the index will not be used further. We have already used that index to find the row with a.c2='X'. Now, we need to find a row in b, and find a join row from b. The index on A would be useful only for finding rows in A.




1. index on table A (C1, C2)
Select *********
From A, B
Where A.C1=B.C3
AND A.C2 ='X'
After the first join condition, can the index still work for the next equal
condition?
...

if we decided to full scan b, then
We would find possible rows in A (maybe) thru the index on a.c1,
and then evaluate a.c2 = 'X' using that index entry (we are there already y)
before going to the table.
so the answer is "sort of, but not really", it would be using the index instead of going to the table, the index would help us avoid a table access by index rowid, but we would not be using the index really to find the 'x' values.


In conclusion, if the index is being used in condition like this:
A.C1=B.C3
AND A.C2 ='X'

if c2 is leading column, only the index entries with c2='X' are pulled from table,
if c1 is leading column, then all the index entries will be pulled, and only the entry with with c2='X' will be used to pulled data from table. So extra step is taken and more entries are pulled in here.


Thank you very much!
Tom Kyte
August 28, 2008 - 9:04 am UTC

ahh, for #2, another case could enter in.

1. index on table A (C1, C2)
Select *********
From A, B
Where A.C1=B.C3
AND A.C2 ='X'

if select count(distinct c1) from a returns a small number, we might index skip scan to resolve a.c2 = 'x' assuming a.c2 = 'x' returned a small set of rows.

http://asktom.oracle.com/pls/ask/search?p_string=%27index+skip+scan%27

and then an index on b(c3) to find the mates.

query tuning

Yan, August 28, 2008 - 11:37 am UTC

Hey Tom:

Thanks for your feedback!

Yes I know index skip scan. Since oracle 9i, the skip scan was introduced to improved the existing index performance.

That is good to know this case. However this brings up another issue that confused me for a long time. what is the distinct doing? Does it make it easy for query to do the full table scan? Is it a thing that we need to try to avoid?

Thank you so much!




Tom Kyte
August 29, 2008 - 10:34 pm UTC

1. index on table A (C1, C2)
Select *********
From A, B
Where A.C1=B.C3
AND A.C2 ='X'

if select count(distinct c1) from a returns a small number, we might index skip scan to resolve a.c2 = 'x' assuming a.c2 = 'x' returned a small set of rows.



the index is on (c1,c2), the where clause on c2.

If C1 has few distinct values, we can treat the index as a series of small indexes - one each for each distinct c1 value. We'll range scan it N times where N = count(distinct c1).

If count(distinct c1) gets large, that doesn't make sense anymore and it'll stop doing that, that is why the count(distinct c1) is relevant - we have statistics, we know what count(distinct c1) is more or less and we'll use that to decide whether to range scan N times or just full scan.

How to tune this query?

peter, August 28, 2008 - 4:46 pm UTC

CREATE TABLE m AS
SELECT level m_ID,
       SYSDATE - dbms_random.value(1, 100) timestamp,
       CAST(RPAD('x', 250, 'x') AS VARCHAR2(250)) char_col,
       rownum int_col1,
       rownum int_col2,
       rownum int_col3,
       DECODE(MOD(level, 3), 0, 'TYPE 1', 'TYPE 2') type
FROM   dual
CONNECT BY level <= 1500000;

ALTER TABLE m ADD CONSTRAINT m_pk PRIMARY KEY (m_ID);
CREATE INDEX m_type_idx ON m(type);

CREATE SEQUENCE i_s;

CREATE TABLE i AS
SELECT i_s.NEXTVAL i_ID,
       m_ID,
       TRUNC(MOD(dbms_random.VALUE(1, 100), 4)) code,
       rownum int_col1,
       rownum int_col2,
       rownum int_col3,
       rownum int_col4,
       rownum int_col5,
       rownum int_col6,
       rownum int_col7,
       SYSDATE timestamp
FROM   m;

INSERT INTO i
SELECT i_s.NEXTVAL i_ID,
       m_ID,
       TRUNC(MOD(dbms_random.VALUE(1, 100), 4)) code,
       rownum int_col1,
       rownum int_col2,
       rownum int_col3,
       rownum int_col4,
       rownum int_col5,
       rownum int_col6,
       rownum int_col7,
       SYSDATE timestamp
FROM   m
WHERE  type = 'TYPE 1' AND
       rownum <= 100000;

INSERT INTO i
SELECT i_s.NEXTVAL i_ID,
       m_ID,
       TRUNC(MOD(dbms_random.VALUE(1, 100), 4)) code,
       rownum int_col1,
       rownum int_col2,
       rownum int_col3,
       rownum int_col4,
       rownum int_col5,
       rownum int_col6,
       rownum int_col7,
       SYSDATE timestamp
FROM   m
WHERE  type = 'TYPE 2' AND
       rownum <= 500000;

ALTER TABLE i ADD CONSTRAINT i_pk PRIMARY KEY (i_ID);

ALTER TABLE i ADD CONSTRAINT i_fk FOREIGN KEY (m_ID) REFERENCES m(m_ID);
CREATE INDEX i_fk ON i(m_ID);

BEGIN
  DBMS_STATS.GATHER_TABLE_STATS(
    ownname          => user,
    tabname          => 'M',
    estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE,
    method_opt       => 'FOR ALL COLUMNS SIZE SKEWONLY',
    cascade          => TRUE);

  DBMS_STATS.GATHER_TABLE_STATS(
    ownname          => user,
    tabname          => 'I',
    estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE,
    method_opt       => 'FOR ALL COLUMNS SIZE SKEWONLY',
    cascade          => TRUE);
END;
/

SELECT Type, COUNT(*) FROM m GROUP BY Type;

TYPE     COUNT(*)
------ ----------
TYPE 1     500000
TYPE 2    1000000

SELECT Type, COUNT(*)
FROM   m, i
WHERE  m.m_ID = i.m_ID
GROUP  BY Type;

TYPE     COUNT(*)
------ ----------
TYPE 1     600000
TYPE 2    1500000




It appears that the optimizer does not come up with the most efficient execution plan for SQL #1 below. Why is it using NESTED LOOPS in this case? I tried to use SQL Profiles to see if there'd be a recommendation for a different plan, but it did not have any suggestions.

If I hinted the optimizer to use a hash join (see SQL #2), the new execution plan is much more efficient in terms of the amount of logical I/O's used.

How do I tune this query without using the hint to make the optimizer come up with the optimal plan?



SELECT * FROM v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Prod
PL/SQL Release 10.2.0.3.0 - Production
CORE    10.2.0.3.0      Production
TNS for 32-bit Windows: Version 10.2.0.3.0 - Production
NLSRTL Version 10.2.0.3.0 - Production


set timing on
set autotrace traceonly

-- =============================================================================
-- SQL #1
-- =============================================================================
SELECT COUNT(*)
FROM   i, m
WHERE  i.m_ID = m.m_ID AND
       m.Type = 'TYPE 1';

Elapsed: 00:00:02.40

Execution Plan
----------------------------------------------------------
Plan hash value: 2118171370

---------------------------------------------------------------------------------------------
| Id  | Operation                | Name             | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT         |                  |     1 |    19 |  4085   (3)| 00:00:50 |
|   1 |  SORT AGGREGATE          |                  |     1 |    19 |            |          |
|   2 |   NESTED LOOPS           |                  |   707K|    12M|  4085   (3)| 00:00:50 |
|*  3 |    VIEW                  | index$_join$_002 |   505K|  6413K|  4065   (2)| 00:00:49 |
|*  4 |     HASH JOIN            |                  |       |       |            |          |
|*  5 |      INDEX RANGE SCAN    | M_TYPE_IDX       |   505K|  6413K|   329   (4)| 00:00:04 |
|   6 |      INDEX FAST FULL SCAN| M_PK             |   505K|  6413K|  1012   (2)| 00:00:13 |
|*  7 |    INDEX RANGE SCAN      | I_FK             |     1 |     6 |     1   (0)| 00:00:01 |
---------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   3 - filter("M"."TYPE"='TYPE 1')
   4 - access(ROWID=ROWID)
   5 - access("M"."TYPE"='TYPE 1')
   7 - access("I"."M_ID"="M"."M_ID")

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
    1005836  consistent gets
          0  physical reads


-- =============================================================================
-- SQL #2
-- =============================================================================
SELECT /*+ USE_HASH(i, m) */
       COUNT(*)
FROM   i, m
WHERE  i.m_ID = m.m_ID AND
       m.Type = 'TYPE 1';

Elapsed: 00:00:01.26

Execution Plan
----------------------------------------------------------
Plan hash value: 427071714

----------------------------------------------------------------------------------------------------
| Id  | Operation                | Name             | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT         |                  |     1 |    19 |       |  7587   (3)| 00:01:32 |
|   1 |  SORT AGGREGATE          |                  |     1 |    19 |       |            |          |
|*  2 |   HASH JOIN              |                  |   707K|    12M|    12M|  7587   (3)| 00:01:32 |
|*  3 |    VIEW                  | index$_join$_002 |   505K|  6413K|       |  4065   (2)| 00:00:49 |
|*  4 |     HASH JOIN            |                  |       |       |       |            |          |
|*  5 |      INDEX RANGE SCAN    | M_TYPE_IDX       |   505K|  6413K|       |   329   (4)| 00:00:04 |
|   6 |      INDEX FAST FULL SCAN| M_PK             |   505K|  6413K|       |  1012   (2)| 00:00:13 |
|   7 |    INDEX FAST FULL SCAN  | I_FK             |  2100K|    12M|       |  1077   (4)| 00:00:13 |
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   2 - access("I"."M_ID"="M"."M_ID")
   3 - filter("M"."TYPE"='TYPE 1')
   4 - access(ROWID=ROWID)
   5 - access("M"."TYPE"='TYPE 1')

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       9243  consistent gets
          0  physical reads





Tom Kyte
August 29, 2008 - 11:05 pm UTC

I want to see tkprofs, not explain plains in this case.

*in general* the goal is reduced logical IO - but not always.

Followup from peter

peter, September 02, 2008 - 12:35 pm UTC

Here's the tkprof output. I ran each query twice.

SELECT COUNT(*)
FROM   i, m
WHERE  i.m_ID = m.m_ID AND
       m.Type = 'TYPE 1'

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.00       0.03          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch        4      8.96       8.97          0    2011672          0           2
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      8.96       9.01          0    2011672          0           2

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47  

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=1005836 pr=0 pw=0 time=4502091 us)
 600000   NESTED LOOPS  (cr=1005836 pr=0 pw=0 time=5683402 us)
 500000    VIEW  index$_join$_002 (cr=4474 pr=0 pw=0 time=2783383 us)
 500000     HASH JOIN  (cr=4474 pr=0 pw=0 time=2293038 us)
 500000      INDEX RANGE SCAN M_TYPE_IDX (cr=1256 pr=0 pw=0 time=26 us)(object id 98061)
1500000      INDEX FAST FULL SCAN M_PK (cr=3218 pr=0 pw=0 time=2466 us)(object id 98052)
 600000    INDEX RANGE SCAN I_FK (cr=1001362 pr=0 pw=0 time=2374699 us)(object id 98064)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  SQL*Net message from client                     4        0.01          0.01
********************************************************************************

SELECT /*+ USE_HASH(i, m) */
       COUNT(*)
FROM   i, m
WHERE  i.m_ID = m.m_ID AND
       m.Type = 'TYPE 1'

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        2      0.00       0.00          0          0          0           0
Execute      2      0.00       0.00          0          0          0           0
Fetch        4      4.20       4.20          0      18486          0           2
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        8      4.20       4.20          0      18486          0           2

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 47  

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=9243 pr=0 pw=0 time=2114239 us)
 600000   HASH JOIN  (cr=9243 pr=0 pw=0 time=3080421 us)
 500000    VIEW  index$_join$_002 (cr=4474 pr=0 pw=0 time=2290426 us)
 500000     HASH JOIN  (cr=4474 pr=0 pw=0 time=1790421 us)
 500000      INDEX RANGE SCAN M_TYPE_IDX (cr=1256 pr=0 pw=0 time=29 us)(object id 98061)
1500000      INDEX FAST FULL SCAN M_PK (cr=3218 pr=0 pw=0 time=64 us)(object id 98052)
2100000    INDEX FAST FULL SCAN I_FK (cr=4769 pr=0 pw=0 time=87 us)(object id 98064)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       4        0.00          0.00
  SQL*Net message from client                     4        0.01          0.02
********************************************************************************


Tom Kyte
September 02, 2008 - 1:37 pm UTC

going back to the explain, it was guessing that it would have to use temp - which it did not - for the hash join, that added considerably to the estimated run time, which is why the nested loops was chosen. If you ran more concurrent sessions - whereby you would not get a full allocation of pga memory - the runtimes likely would be 'reversed' in this particular case.

SQL tuning

Yan, September 02, 2008 - 2:06 pm UTC

Hey Tom:

Thank you very much! You reply is very helpful!

I have another question, do you have a figure that shows how the B-tree composite index looks like? for example, a b-tree index on c1 and c2. I found many pictures about single b-tree index, but no one for index on multiple columns.

Thank you very much!


Tom Kyte
September 02, 2008 - 2:19 pm UTC

it looks just like one with one column, they are basically the same.

a b*tree index has:

a) key components
b) non-key components


Just think of it as a comma separated list, like an index on emp(ename,sal) might look like:

king,1000,<rowid>
smith,2000,<rowid>


don't over complicate it, whether you have one or 32 columns in the index, it is just "key" and "rowid" really.

Can you tell me what happens in the query you gave ..

Kiran, September 03, 2008 - 12:39 pm UTC

Hi Tom,

This is regarding the query you discussed long time before....

Followup November 9, 2003 - 7am US/Eastern:

what happens to the autotrace if you change:

A.CHANGEDDT= (Select max(CHANGEDDT) from Address_h
where Address_IDX = PA.Address_Key and
(CHANGEDDT-to_date('10/22/2003 18:02:30','mm/dd/yyyy
hh24:mi:ss'))<=0.001 )

to

A.CHANGEDDT=
(Select max(CHANGEDDT)
from Address_h
where Address_IDX = PA.Address_Key
and CHANGEDDT <= to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss')+0.001 )

which seems like a "strange" constraint in the first place, why not just use 18:03:56 for the time
and lose the 0.001?
..........

Can you tell me .. what makes the difference in the above two queries that improves the performance of the query !?
Tom Kyte
September 03, 2008 - 4:10 pm UTC

we went from:

(CHANGEDDT-to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss'))<=0.001 )
to
CHANGEDDT <= to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss')+0.001 )


Now, say on the address_h table there was an index on (address_key,changedt)

In the first case, we would/could use the index to find the address_key values - but would have to evaluate "CHANGEDDT-to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss')" for each index entry.

In the latter case, we would/could use the index to instantly find the max(changedt) for that address_key such that it was greater than or equal to "to_date('10/22/2003 18:02:30','mm/dd/yyyy hh24:mi:ss')+0.001"


In general, anytime you can get a database column "by itself", you are better off - you open up opportunities to use indexes more often (not talking about function based indexes here, they can be useful in some limited cases - but not in this one) and reduce the work needed to be performed.

Consider, even if there wasn't an index on (address_key, changedt) - just on address_key, which is easier to evaluate:


changedt - CONSTANT1 <= CONSTANT2

or

changedt <= CONSTANT1+CONSTANT1 which is really just changedt <= CONSTANT3

in the former case, you have to perform 'math' on every changedt you hit and then compare.

in the latter case, you just compare.


And if we indexed (address_key,changedt), we can instantly find the "max" value for a given address_key using the index - even less work.



2nd Followup From peter

peter, September 04, 2008 - 8:17 pm UTC

Hi Tom, I'm following up on my previous posting (September 2, 2008 - 12pm US/Eastern). It seems that the Optimizer has the wrong data regarding the cardinality of foreign key on the table i. Please see below. The estimated cardinality for Operation# 7 is completely off (1 v. 600K)! How do I fix this? It's nothing that can be fixed by creating the histograms, right?

SELECT /*+ gather_plan_statistics */ COUNT(*)
FROM   i, m
WHERE  i.m_ID = m.m_ID AND
       m.Type = 'TYPE 1';

SELECT * FROM TABLE(dbms_xplan.display_cursor(NULL, NULL, 'iostats last'));


PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------
SQL_ID  gwmu738zpdumy, child number 0
-------------------------------------
SELECT /*+ gather_plan_statistics */ COUNT(*) FROM   i, m WHERE  i.m_ID = m.m_ID AND
m.Type = 'TYPE 1'

Plan hash value: 2118171370

----------------------------------------------------------------------------------------------------
| Id  | Operation                | Name             | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
----------------------------------------------------------------------------------------------------
|   1 |  SORT AGGREGATE          |                  |      1 |      1 |      1 |00:00:04.49 |    1005K|
|   2 |   NESTED LOOPS           |                  |      1 |    707K|    600K|00:00:05.69 |    1005K|
|*  3 |    VIEW                  | index$_join$_002 |      1 |    505K|    500K|00:00:02.79 |    4474 |
|*  4 |     HASH JOIN            |                  |      1 |        |    500K|00:00:02.30 |    4474 |
|*  5 |      INDEX RANGE SCAN    | M_TYPE_IDX       |      1 |    505K|    500K|00:00:00.01 |    1256 |
|   6 |      INDEX FAST FULL SCAN| M_PK             |      1 |    505K|   1500K|00:00:00.01 |    3218 |
|*  7 |    INDEX RANGE SCAN      | I_FK             |    500K|      1 |    600K|00:00:02.36 |    1001K|
----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter("M"."TYPE"='TYPE 1')
   4 - access(ROWID=ROWID)
   5 - access("M"."TYPE"='TYPE 1')
   7 - access("I"."M_ID"="M"."M_ID")

Tom Kyte
September 05, 2008 - 8:55 am UTC

it is in a nested loop - it is estimating a row per loop - it is not wrong.

SQL Query Tuning

Rohit, September 05, 2008 - 1:48 am UTC

Hi Tom,

I do have 2 tables DEPT and EMP

SQL> desc dept
 Name           Null?    Type
 -------------- -------- -----------------
 DEPTNO                  NUMBER 
 DNAME                   VARCHAR2(20)

This table has unique 8000 rows and is indexed on DEPTNO and DNAME.

SQL> desc emp
 Name                 Null?    Type
 -------------------- -------- ----------------------------
 EMPNO                         NUMBER
 DEPTNO                        NUMBER
 ENAME                         VARCHAR2(100)

This table has 400000 rows and is indexed on DEPTNO.

Below are 2 select queries along with their plan


select /*+ ordered */ e.EMPNO,d.DNAME
from  dept d, emp e 
where d.dname = 'DEPT_30'
and   e.deptno = d.deptno;

Plan
SELECT STATEMENT  ALL_ROWSCost: 5  Bytes: 950  Cardinality: 50      
 5 TABLE ACCESS BY INDEX ROWID TABLE DEVUSER.EMP Cost: 3  Bytes: 350  Cardinality: 50     
  4 NESTED LOOPS  Cost: 5  Bytes: 950  Cardinality: 50    
   2 TABLE ACCESS BY INDEX ROWID TABLE DEVUSER.DEPT Cost: 2  Bytes: 12  Cardinality: 1   
    1 INDEX RANGE SCAN INDEX DEVUSER.DNAME_IDX Cost: 1  Cardinality: 1  
   3 INDEX RANGE SCAN INDEX DEVUSER.EMP_IDX Cost: 2  Cardinality: 50   

select /*+ ordered */ e.EMPNO,d.DNAME
from  dept d, emp e 
where d.deptno = 30
and   e.deptno = d.deptno;

Plan
SELECT STATEMENT  ALL_ROWSCost: 5  Bytes: 950  Cardinality: 50      
 6 MERGE JOIN CARTESIAN  Cost: 5  Bytes: 950  Cardinality: 50     
  2 TABLE ACCESS BY INDEX ROWID TABLE DEVUSER.DEPT Cost: 2  Bytes: 12  Cardinality: 1    
   1 INDEX RANGE SCAN INDEX DEVUSER.DEPT_IDX Cost: 1  Cardinality: 1   
  5 BUFFER SORT  Cost: 3  Bytes: 350  Cardinality: 50    
   4 TABLE ACCESS BY INDEX ROWID TABLE DEVUSER.EMP Cost: 3  Bytes: 350  Cardinality: 50   
    3 INDEX RANGE SCAN INDEX DEVUSER.EMP_IDX Cost: 2  Cardinality: 50  
   
Why in 2nd case, it is having MERGE JOIN CARTESIAN and How it can be avoided?


Regards,

Tom Kyte
September 05, 2008 - 9:01 am UTC

why avoid it.

you are getting 1 row from dept, it knows that.

a cartesian join would be the efficient way to accomplish that join.



query with hint

reader, September 05, 2008 - 3:02 pm UTC

Dear Tom:

I have a problem query, it has high gets and long running time. when I put in the hint /*+ ordered */, I found the gets is much low, so is the time. but what confused me is they are using the same plan. So I wonder if it is the hint that save the optimizer some time, so it doesn't need to spend a lot of effort to figure out the plan. But the gets is less, which should not have any connection to the plan.

Does this make sense to you?
Tom Kyte
September 05, 2008 - 5:08 pm UTC

got tkprofs?

with and without - we'd want to see the row source operation lines as well (NOT explain plans, row source operation lines)

IN condition tuning

A reader, September 07, 2008 - 3:39 pm UTC

Tom,

1. I have this query that I was trying to rewrite however result set of the second query 30% smaller than the first. I thought that my second query semantically identical to the first. What condition did I miss?

2. So my second question would be if it is possible to convert this also to hierarchical query as another way to look at the data.

Using 10g R2

As always grateful for your time.

1.
select ...., count(*)
from d
where id in ( select d_id
from nd
where n_id in (select n_id
from nd
where d_id in ( select id
from d
where d_no like '%XWB%'
)
)
)
and os in ('LINUX', 'WIN')
group by ....

2.
select ..., count(*)
from nd nd1, d d1, nd nd2, d d2
where d1.id = nd1.d_id
and nd1.n_id = nd2.n_id
and nd2.d_id = d2.id
and d2.d_no like '%XWB%'
and d1.os in ('LINUX', 'WIN')
group by ....
Tom Kyte
September 08, 2008 - 3:58 pm UTC

if you have "duplicates" - an in will not "repeat them", a join would

eg:

select dept.* from dept, emp where dept.deptno = emp.deptno;

that returns.... 14 rows - the dept records are repeated over and over.


select dept.* from dept where dept.deptno in (select emp.deptno from emp)

returns.... 3 rows - because we don't explode out the dept table joining it to the emp table

so, if any of your join keys are not unique - you cannot replace a join by an in, it changes the answer.

but you say the in is larger, which would be "strange"

well, strange goes back to query 1 having:
where d_no like '%XWB%'

and query 2 having:
and d1.os in ('LINUX', 'WIN')

these queries are not even remotely comparable.


where is the query stats from in grid control?

Yan, September 08, 2008 - 1:36 pm UTC

Hello Tom:

when I am checking a query in the performance page of Grid control,
there are four tabs for each query:
Statistics,Activity,Plan,Tuning Information.
In the statistics page, there is a form named "
Execution Statistics". Couple of info are listed there, including the buffer gets and the disk read and writes....

My question is where these info are from, especially the buffer gets. I know it might come from some dynamic performance view, but not sure what exactly it is.

Thank you very much!
Tom Kyte
September 08, 2008 - 4:28 pm UTC

v$sql

more question

Yan, September 08, 2008 - 5:39 pm UTC

thank you for your reply!

more questions:

select sql_id, child_number, PLAN_HASH_VALUE from v$sql where sql_id='9s8twg621bcdx';

SQL_ID CHILD_NUMBER PLAN_HASH_VALUE
------------- ------------ ---------------
9s8twg621bcdx 0 4276105648

select version_count from v$sqlarea where sql_id='9s8twg621bcdx';

VERSION_COUNT
-------------
7

select sql_id, child_number, PLAN_HASH_VALUE,LAST_CR_BUFFER_GETS,CR_BUFFER_GETS from V$SQL_PLAN_STATISTICS where sql_id='9s8twg621bcdx';


no rows selected

question:
1. why there are 7 version of this query, which means this query has 7 child cursors, but only one in the v$sql. Where are the other child cursor? They are still in the memory, or they have already aged out?

2. why there is nothing in the v$sql_plan_statistics for this query?

3. when will a sql parent cursor age out the shared pool, and when will a child cursor age out the shared pool?
when they age out, will the associate information of this query go to the dba_hist_* tables?

when I truncate a table, or drop a table, the associated query will be cleaned out of the memory?

4. and for the last question, I found almost all the info in the statistics page in the v$sql, except for the "Total Parses ", and "Hard Parses". so where this two stats are from?


Thank you very much!


Tom Kyte
September 09, 2008 - 7:27 am UTC

1) they are gone, they are not in the shared pool right now.

2) see #1, they are gone.

3) whenever they need to, want to, can.

they may or may not appear in the dba_hist tables, depends on whether they were around long enough to be sampled or not.

when you truncate or perform DDL in general, the associated cursors are invalidated - and will be flushed as needed.

4) I don't know what you mean

continued on more questions

Yan, September 09, 2008 - 10:05 am UTC

Thank you Tom:

Q2: so it is possible for a plan still stay in the v$sql_plan, but not in the v$sql_plan_statistics, which means we still have the plan, but not hte stats?
And in the grid control, the plan tab for a query is from v$sql_plan_statistics or some other v$views?

Q4: I mean in the grid control performance tab, down to the stats area, there are two stats "Total Parses", and "Hard Parses". Where these two stats are from?
Tom Kyte
September 10, 2008 - 9:14 am UTC

the statistics never "need" to be there - they are optional.

the total parses comes from v$sql, it is there.

v$view question

YAN, September 10, 2008 - 1:16 pm UTC

Tom:

Thank you for your reply, I found them.
And one more question.

column module format a40
column action format a5

select sql_id, plan_hash_value, child_number,PARSING_USER_ID user_id,module,action,OPTIMIZER_MODE,OPTIMIZER_COST,
2 END_OF_FETCH_COUNT totalparsed, LOADS hardparsed,buffer_gets, EXECUTIONS, buffer_gets/executions per_gets, sorts,
3 ELAPSED_TIME/1000000 elapsedtime, cpu_time/1000000 cputime, PERSISTENT_MEM, RUNTIME_MEM,
4 INVALIDATIONS,FIRST_LOAD_TIME fltime,LAST_LOAD_TIME lltime
5 from v$sql
6 where sql_id='5vnubf1bys7zc' and plan_hash_value='1918181022';

SQL_ID PLAN_HASH_VALUE CHILD_NUMBER USER_ID MODULE ACTION OPTIMIZER_
------------- --------------- ------------ ---------- ---------------------------------------------------------------- ---------------------------------------------------------------- ----------
OPTIMIZER_COST TOTALPARSED HARDPARSED BUFFER_GETS EXECUTIONS PER_GETS SORTS ELAPSEDTIME CPUTIME PERSISTENT_MEM RUNTIME_MEM INVALIDATIONS FLTIME LLTIME
-------------- ----------- ---------- ----------- ---------- ---------- ---------- ----------- ---------- -------------- ----------- ------------- ------------------- -------------------
5vnubf1bys7zc 1918181022 2 155 httpd@axweb03b.traderpub.net (TNS V1-V3) FIRST_ROWS
18 5 534 748 7 106.857143 0 .287157 .053958 7376 5224 579 2008-07-10/07:53:25 2008-09-10/12:28:58

5vnubf1bys7zc 1918181022 5 155 httpd@axweb03b.traderpub.net (TNS V1-V3) FIRST_ROWS
0 557 74 39393 558 70.5967742 0 262.939176 5.583209 7376 5224 49 2008-07-10/07:53:25 2008-09-10/12:09:54





Why there are more than one child using the same plan for a the same query? they are the same sql statement, they are picking up the same plan, they are from the same schmema and from the the same webserver. The only thing different is their OPTIMIZER_COST, one is 18, the other one is 0. But I found the other time, there are 3 child cursors:

SQL_ID PLAN_HASH_VALUE CHILD_NUMBER OPTIMIZER_ OPTIMIZER_COST
------------- --------------- ------------ ---------- --------------
5vnubf1bys7zc 1918181022 0 FIRST_ROWS 18
5vnubf1bys7zc 1918181022 3 FIRST_ROWS 0
5vnubf1bys7zc 1918181022 5 FIRST_ROWS 0

see here the child 3 and 5 have the same optimizor_cost.

Thank you!


Tom Kyte
September 11, 2008 - 11:16 am UTC

...
Why there are more than one child using the same plan for a the same query?
.....

query v$sql_shared_cursor to see why the sql was not shared.

say you have "create table t( x int )" - no indexes, nothing else

and I log in and using first rows optimization set at the session level issue "select * from t" - that'll be one query plan - a full scan obviously.

you log in and use all rows optimization - you issue "select * from t" - that'll be ANOTHER query plan, still a full scan since that is the only possible plan - but it'll be a separate child cursor since we had different optimization goals set.

it would not be at all unusual for them to have the same plans, that is expected and normal. There was something different in the SESSIONS that causes them to not reuse an existing child cursor in the shared pool - bind mismatch (you bind a number, I bind a varchar2 - you cannot share that sql plan, different datatypes), different optimizer settings, many things - v$sql_shared_cursor will help you figure out "what"

Query Tunning

Mohammed Ali, September 11, 2008 - 2:56 am UTC

Hi, I am new in sql tunning techniques. Here is my below query,
SELECT SEC_ALIAS,EFF_DATE,Min(PAY_DATE) over(PARTITION BY SEC_ALIAS) MIN_PD
FROM (
SELECT DISTINCT SEC_ALIAS,EFF_DATE,PAY_DATE,Min(PAY_DATE) over(PARTITION BY SEC_ALIAS) MIN_PD
FROM temp_npd
WHERE PAY_DATE >= Trunc(SYSDATE)
AND PAY_DATE IS NOT NULL
AND EFF_DATE = (SELECT Trunc(Max(EFF_DATE)) FROM temp_npd)
);

In the above query, the table which i am using is "temp_npd". This is a very big table. and the explain plan of the above query is,


SELECT SEC_ALIAS,EFF_DATE,Min(PAY_DATE) over(PARTITION BY SEC_ALIAS) MIN_PD
FROM (
SELECT DISTINCT SEC_ALIAS,EFF_DATE,PAY_DATE,Min(PAY_DATE) over(PARTITION BY SEC_ALIAS) MIN_PD
FROM temp_npd
WHERE PAY_DATE >= Trunc(SYSDATE)
AND PAY_DATE IS NOT NULL
AND EFF_DATE = (SELECT Trunc(Max(EFF_DATE)) FROM temp_npd)
)
--------------------------------------------------------------------------------

SELECT STATEMENT Optimizer=ALL_ROWS (Cost=50 Card=1 bytes=31)
WINDOW (BUFFER) (Cost=50 Card=1 bytes=31)
VIEW (Cost=50 Card=1 bytes=31)
SORT (UNIQUE) (Cost=50 Card=1 bytes=31)
WINDOW (SORT) (Cost=50 Card=1 bytes=31)
TABLE ACCESS (FULL) of "TEMP_NPD" #2 TABLE (Cost=1 Card=1 bytes=31)
SORT (AGGREGATE)
TABLE ACCESS (FULL) of "TEMP_NPD" #3 TABLE (Cost=1 Card=82 bytes=738)
--------------------------------------------------------------------------------

Please suggest me how to restructure the above query.

Thanks in advance.
Tom Kyte
September 16, 2008 - 12:10 pm UTC

forget query tuning for a moment, what is the meaning of this bit:

AND EFF_DATE = (SELECT Trunc(Max(EFF_DATE)) FROM temp_npd)


If the trunc is needed, then it is highly unlikely to return any rows isn't it? If the EFF_DATE field actually has a time component??

Why would you use that construct?

also, if pay_date >= trunc(sysdate), then by definition PAY_DATE is not null.......... so, why have that?

And why would you do min(pay_date) over (partition by sec_alias) TWICE like that??!?!?!?! what was the point of the inline view?




An index on eff_date might be useful to avoid a full scan of temp_ndp to get the max(eff_date)


v$view question

Yan, September 11, 2008 - 2:53 pm UTC

Hey Tom:

according to your guidance, I pulled all the information in the v$sql_shared_cursor table, and found this:

select sql_id, plan_hash_value, child_number,sql_text from v$sql where sql_id='2bh2pau40qp86';

2bh2pau40qp86 3203698291 0
select /*+ first_rows */ dbms_random.value(:"SYS_B_00",:"SYS_B_01") random, a.ad_id, pk.nickname as package_nickname, p.nickname as product_nickname, dv.vehicle_type, dv.make_list from
package pk, deliverable dv, ad a, product_package pp, product p where pk.status = :"SYS_B_02" and pk.package_id = dv.package_id and pp.package_id = pk.package_id and pk.status =
:"SYS_B_03" and pp.product_id = p.product_id and p.status = :"SYS_B_04" and dv.status = :"SYS_B_05" and dv.type_code = :"SYS_B_06" and pk.nickname != :"SYS_B_07" and a.ad_id
= dv.some_id and a.ad_id in (:"SYS_B_08",:"SYS_B_09",:"SYS_B_10",:"SYS_B_11",:"SYS_B_12",:"SYS_B_13",:"SYS_B_14",:"SYS_B_15")

2bh2pau40qp86 3203698291 1
select /*+ first_rows */ dbms_random.value(:"SYS_B_00",:"SYS_B_01") random, a.ad_id, pk.nickname as package_nickname, p.nickname as product_nickname, dv.vehicle_type, dv.make_list from
package pk, deliverable dv, ad a, product_package pp, product p where pk.status = :"SYS_B_02" and pk.package_id = dv.package_id and pp.package_id = pk.package_id and pk.status =
:"SYS_B_03" and pp.product_id = p.product_id and p.status = :"SYS_B_04" and dv.status = :"SYS_B_05" and dv.type_code = :"SYS_B_06" and pk.nickname != :"SYS_B_07" and a.ad_id
= dv.some_id and a.ad_id in (:"SYS_B_08",:"SYS_B_09",:"SYS_B_10",:"SYS_B_11",:"SYS_B_12",:"SYS_B_13",:"SYS_B_14",:"SYS_B_15")

2bh2pau40qp86 3203698291 2
select /*+ first_rows */ dbms_random.value(:"SYS_B_00",:"SYS_B_01") random, a.ad_id, pk.nickname as package_nickname, p.nickname as product_nickname, dv.vehicle_type, dv.make_list from
package pk, deliverable dv, ad a, product_package pp, product p where pk.status = :"SYS_B_02" and pk.package_id = dv.package_id and pp.package_id = pk.package_id and pk.status =
:"SYS_B_03" and pp.product_id = p.product_id and p.status = :"SYS_B_04" and dv.status = :"SYS_B_05" and dv.type_code = :"SYS_B_06" and pk.nickname != :"SYS_B_07" and a.ad_id
= dv.some_id and a.ad_id in (:"SYS_B_08",:"SYS_B_09",:"SYS_B_10",:"SYS_B_11",:"SYS_B_12",:"SYS_B_13",:"SYS_B_14",:"SYS_B_15")




select * from v$sql_shared_cursor where sql_id = '2bh2pau40qp86'
2 ;

SQL_ID ADDRESS CHILD_ADDRESS CHILD_NUMBER U S O O S L S E B P I S T A B D L T R I I R L I O S M U T N F A I T D L D B P C S R P T M B M R O P M F L
2bh2pau40qp86 00000003D4D8CFD8 00000003D4AB3A88 0 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N
2bh2pau40qp86 00000003D4D8CFD8 00000003D48FFC88 1 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N
2bh2pau40qp86 00000003D4D8CFD8 00000003D49DFC18 2 N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N N


Sounds like they don't have mismatch. Can you help me to explain that?

Thank you!


My query

Tajinder, October 06, 2008 - 4:10 am UTC

hi
i have a query ,i want to tune this .
this taling 2 min.
please reply me.

select distinct a.vc_ordersheet_no,substr(a.vc_ordersheet_no,3) ord_no,a.vc_client_code,b.vc_client_name
from hd_yarn_req a,sales.mst_client b
where a.vc_comp_code=b.vc_comp_code
and a.vc_client_code=b.vc_client_code
order by a.vc_ordersheet_no desc


Thanks & Regards
Tajinder Singh
Tom Kyte
October 06, 2008 - 2:54 pm UTC

if you replace references to your tables with dual, it'll go much faster.

or add "and 1=0", it'll go very very fast.

It is impossible to answer this, think about it for a moment, we know *nothing* about your stuff, *nothing*

for all we know, that distinct is utterly not necessary.

I'd really question the application that needs the output of this - why is the application executing this in the first place. If it takes two minutes - that must be a TON of data, so this had better be a batch application.


In order to suggest anything, you need to be really verbose - supply as much information as you can think of.

Tune Big tables & small tables

DM, October 07, 2008 - 10:49 pm UTC

Hi Tom,
Below is my original query and TKPROF output.

********************************************************************************

SELECT DISTINCT C.CLI_NUM,
d.BIRTH_DT,
d.CLI_NM,
d.CLI_NM,
'1',
'C'
FROM TAGT_ACPL b, TAGT_ACCL c, TCLIENT_DETAILS d, TAGT_ACAL f
WHERE f.unit_head_agt_key = '1234567812'
AND B.AGT_KEY = F.AGT_KEY
AND c.CLI_NUM = d.CLI_NUM
AND b.POL_NUM = c.POL_NUM
AND B.LOB = C.LOB
AND B.SUB_GRP_NUM = C.SUB_GRP_NUM
AND B.CERT_NUM = C.CERT_NUM
AND (UPPER(c.SURNAME) LIKE '%' OR
UPPER(c.SURNAME) LIKE '%')

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 414 2.87 4.85 6838 46398 0 6188
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 416 2.89 4.86 6838 46398 0 6188

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 300

Rows Row Source Operation
------- ---------------------------------------------------
6188 SORT UNIQUE
17994 NESTED LOOPS
17994 HASH JOIN
8985 NESTED LOOPS
15 TABLE ACCESS BY INDEX ROWID TAGT_ACAL
15 INDEX RANGE SCAN IX11_TAGT_ACAL (object id 160326)
8985 INDEX RANGE SCAN PK1_TAGT_ACPL (object id 149463)
912162 TABLE ACCESS FULL TAGT_ACCL
17994 TABLE ACCESS BY INDEX ROWID TCLIENT_DETAILS
17994 INDEX UNIQUE SCAN CDT_PK (object id 152916)

********************************************************************************
Then I have modify the query as below.

********************************************************************************

SELECT d.CLI_NUM,
d.BIRTH_DT,
d.CLI_NM,
d.CLI_NM,
'1',
'C'
FROM TCLIENT_DETAILS d
where exists
( select distinct C.CLI_NUM
from TAGT_ACCL c
where exists
(select 'x'
from TAGT_ACPL b
where exists (select 'x'
from TAGT_ACAL a
where a.unit_head_agt_key = '1234567812'
and b.agt_key = a.agt_key)
and b.pol_num = c.pol_num
and b.sub_grp_num = c.sub_grp_num
and b.cert_num = c.cert_num
and b.lob = c.lob)
AND (UPPER(c.SURNAME) LIKE '%' OR UPPER(c.SURNAME) LIKE '%')
and d.cli_num = c.cli_num)

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 414 2.79 4.76 7355 23198 0 6188
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 416 2.79 4.77 7355 23198 0 6188

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 300

Rows Row Source Operation
------- ---------------------------------------------------
6188 NESTED LOOPS
6188 VIEW
6188 SORT UNIQUE
17994 HASH JOIN
8985 NESTED LOOPS
15 TABLE ACCESS BY INDEX ROWID TAGT_ACAL
15 INDEX RANGE SCAN IX11_TAGT_ACAL (object id 160326)
8985 INDEX RANGE SCAN PK1_TAGT_ACPL (object id 149463)
912162 TABLE ACCESS FULL TAGT_ACCL
6188 TABLE ACCESS BY INDEX ROWID TCLIENT_DETAILS
6188 INDEX UNIQUE SCAN CDT_PK (object id 152916)

********************************************************************************

cpu and elapsed time reduce by little and query reduce by half.
Is there better way to write the orignal query?

Thank you.

Self Join

Akshay, October 27, 2008 - 7:29 am UTC

All,
I am firing self join on a table which has 70 millons records present. It takes around 10 mins to get the output for 125 records.

Sceneario -> desc t1;
id number, -- Index
status varchar2(10), functional Index
start_dt date,
end_dt date

query

select id, status from t1 a, t2 b
where a.id = b.id
and a.start_dt <= nvl(a.end_dt,a.start_dt)
and b.start_dt <= nvl(b.end_dt,b.start_dt)
and substr(a.status,02) = 12
and substr(b.status,02) <> 12;

It is using Index on column id, but doing full table scan.

Please can any one modify the query to get the result quickly.



Tom Kyte
October 27, 2008 - 8:20 am UTC

well, I have lots of problems with this query :)

substr() - returns a string
12 - is a number

substr() operator number

BAD - stop doing that. Is status a string? substr definitely is, you have implicit conversions going there.

Is "substr(a.status,2) = '12'" very selective? returns very very few records? If so, consider indexing that function.

Maybe even given and a.start_dt <= nvl(a.end_dt,a.start_dt) index

(substr(status,2), case when start_dt <= nvl(end_dt,start_dt) then 1 end)

and where:

substr(status,2) = 12 and case when start_dt <= nvl(end_dt,start_dt) then 1 end = 1




and in the future always provide table creates and create indexes as well as the plan as shown by the database....

Sql tuning on Text index

Slavko Brkic, October 28, 2008 - 4:14 am UTC

Hi Tom,
We have a a materialized view containing about 7 million records at the moment with song artist and album information. We hava a column in the materialized wiev which contains the song name concateneted with the artistname concateneted with the album name. We have a textindex on this column. Searching on 'Elvis' or 'Elvis Presley' and similiar is very fast. However doing a search on 'in the ghettto' or 'on in the'. will produce a slow result (more than 10 seconds). I understand that there are a lot of hits with words like 'in' and 'the' but need to be able to search on these words aas well. I have provided the autotrace information as well as the tkprof. Do you have any suggestions to speed this up.

Sql:
SELECT sub2.*
FROM (
SELECT ROWNUM rad, sub1.*
FROM (
SELECT songId, title, songArtist, albumId,
popularity, genreId, genre, explicit, offerId, priceCategoryId,
offerStartDate, offerEndDate, mountPointId, drmProtected, releaseDate
FROM MV_Song_batman
WHERE CATSEARCH(searchText, :vSearchString, :vCriterion) > 0) sub1
WHERE ROWNUM <= :vEnd) sub2
WHERE sub2.rad >= :vStart;

Autotrace:
SQL> @catsearch

PL/SQL procedure successfully completed.

30 rows selected.

Execution Plan
----------------------------------------------------------
Plan hash value: 2829723679

--------------------------------------------------------------------------------
-----------------------

| Id | Operation | Name | Rows | Bytes |
Cost (%CPU)| Time |

--------------------------------------------------------------------------------
-----------------------

| 0 | SELECT STATEMENT | | 150K| 84M|
25900 (1)| 00:05:11 |

|* 1 | VIEW | | 150K| 84M|
25900 (1)| 00:05:11 |

|* 2 | COUNT STOPKEY | | | |
| |

| 3 | MAT_VIEW ACCESS BY INDEX ROWID| MV_SONG_BATMAN | 150K| 27M|
25900 (1)| 00:05:11 |

|* 4 | DOMAIN INDEX | MV_SONG_BATMAN_IND | | |
| |

--------------------------------------------------------------------------------
-----------------------


Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("SUB2"."RAD">=TO_NUMBER(:VSTART))
2 - filter(ROWNUM<=TO_NUMBER(:VEND))
4 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)


Statistics
----------------------------------------------------------
872 recursive calls
0 db block gets
86385 consistent gets
12 physical reads
0 redo size
3839 bytes sent via SQL*Net to client
392 bytes received via SQL*Net from client
3 SQL*Net roundtrips to/from client
158 sorts (memory)
0 sorts (disk)
30 rows processed


TKProf:

TKPROF: Release 10.2.0.1.0 - Production on Tue Oct 28 08:30:25 2008

Copyright (c) 1982, 2005, Oracle. All rights reserved.

Trace file: orcl_ora_4668.trc
Sort options: default

********************************************************************************
count = number of times OCI procedure was executed
cpu = cpu time in seconds executing
elapsed = elapsed time in seconds executing
disk = number of physical reads of buffers from disk
query = number of buffers gotten for consistent read
current = number of buffers gotten in current mode (usually for update)
rows = number of rows processed by the fetch or execute call
********************************************************************************

alter session set events '10046 trace name context forever, level 12'


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 1 0.00 0.00 0 0 0 0

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 1 0.00 0.00
SQL*Net message from client 1 0.00 0.00
********************************************************************************

begin
:vend := 30;
:vStart := 1;
:vSearchstring := 'in the ghetto';
:vCriterion := 'countrycode = ''SE'' order by sortorder';
end;

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.39 0 0 0 1
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.00 0.39 0 0 0 1

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 1 0.00 0.00
SQL*Net message from client 1 0.00 0.00
********************************************************************************

SELECT sub2.*
FROM (
SELECT ROWNUM rad, sub1.*
FROM (
SELECT songId, title, songArtist, albumId,
popularity, genreId, genre, explicit, offerId, priceCategoryId,
offerStartDate, offerEndDate, mountPointId, drmProtected, releaseDate
FROM MV_Song_batman
WHERE CATSEARCH(searchText, :vSearchString, :vCriterion) > 0) sub1
WHERE ROWNUM <= :vEnd) sub2
WHERE sub2.rad >= :vStart

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.01 0.25 0 18 0 0
Fetch 3 0.09 0.16 0 18 0 30
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 5 0.10 0.41 0 36 0 30

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244

Rows Row Source Operation
------- ---------------------------------------------------
30 VIEW (cr=86072 pr=0 pw=0 time=14336154 us)
30 COUNT STOPKEY (cr=86072 pr=0 pw=0 time=14336124 us)
30 MAT_VIEW ACCESS BY INDEX ROWID MV_SONG_BATMAN (cr=86072 pr=0 pw=0 time=14336103 us)
30 DOMAIN INDEX MV_SONG_BATMAN_IND (cr=86054 pr=0 pw=0 time=14336280 us)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 3 0.00 0.00
SQL*Net message from client 3 0.37 0.67
********************************************************************************

select metadata
from
kopm$ where name='DB_FDO'


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 0.00 0.00 0 2 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 0.00 0.00 0 2 0 1

Misses in library cache during parse: 0
Optimizer mode: CHOOSE
Parsing user id: SYS (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
1 TABLE ACCESS BY INDEX ROWID KOPM$ (cr=2 pr=0 pw=0 time=47 us)
1 INDEX UNIQUE SCAN I_KOPM1 (cr=1 pr=0 pw=0 time=20 us)(object id 365)

********************************************************************************

select /*+ NO_EXPAND INDEX_ASC(i "DR$MV_SONG_BATMAN_IND03") */ dr$rowid ,
SORTORDER
from
"MEDIA_CORE"."DR$MV_SONG_BATMAN_IND$I" i where dr$token = :token and
dr$token_type = :ttype and COUNTRYCODE = 'SE' order by dr$token ASC,
dr$token_type ASC, SORTORDER ASC, dr$rowid ASC


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.04 0 0 0 0
Fetch 4 0.35 0.25 0 2485 0 396
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 6 0.35 0.30 0 2485 0 396

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244 (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
396 SORT ORDER BY (cr=2485 pr=0 pw=0 time=257922 us)
65277 TABLE ACCESS BY INDEX ROWID DR$MV_SONG_BATMAN_IND$I (cr=2485 pr=0 pw=0 time=486792 us)
261491 INDEX RANGE SCAN DR$MV_SONG_BATMAN_IND03 (cr=978 pr=0 pw=0 time=1054100 us)(object id 63590)

********************************************************************************

select /*+ NO_EXPAND INDEX_ASC(i "DR$MV_SONG_BATMAN_IND03") */ dr$rowid ,
SORTORDER
from
"MEDIA_CORE"."DR$MV_SONG_BATMAN_IND$I" i where dr$token = :token and
dr$token_type = :ttype and COUNTRYCODE = 'SE' and SORTORDER >= :r01 and
(SORTORDER > :r01 or DR$ROWID >= :r02) order by dr$token ASC,
dr$token_type ASC, SORTORDER ASC, dr$rowid ASC


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 157 0.00 0.00 0 0 0 0
Execute 157 0.01 0.21 0 0 0 0
Fetch 439 16.48 13.60 0 83549 0 43460
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 753 16.50 13.82 0 83549 0 43460

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244 (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
198 SORT ORDER BY (cr=2058 pr=0 pw=0 time=331363 us)
210971 TABLE ACCESS BY INDEX ROWID DR$MV_SONG_BATMAN_IND$I (cr=2058 pr=0 pw=0 time=3375647 us)
210971 INDEX RANGE SCAN DR$MV_SONG_BATMAN_IND03 (cr=799 pr=0 pw=0 time=850588 us)(object id 63590)




********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 0 0 0
Execute 3 0.01 0.65 0 18 0 1
Fetch 3 0.09 0.16 0 18 0 30
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 8 0.10 0.81 0 36 0 31

Misses in library cache during parse: 0

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 8 0.00 0.00
SQL*Net message from client 8 17.24 25.54


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 159 0.00 0.00 0 0 0 0
Execute 159 0.01 0.26 0 0 0 0
Fetch 444 16.84 13.86 0 86036 0 43857
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 762 16.85 14.13 0 86036 0 43857

Misses in library cache during parse: 0

161 user SQL statements in session.
1 internal SQL statements in session.
162 SQL statements in session.
********************************************************************************
Trace file: orcl_ora_4668.trc
Trace file compatibility: 10.01.00
Sort options: default

1 session in tracefile.
161 user SQL statements in trace file.
1 internal SQL statements in trace file.
162 SQL statements in trace file.
6 unique SQL statements in trace file.
5777 lines in trace file.
23 elapsed seconds in trace file.
Tom Kyte
October 28, 2008 - 7:54 am UTC

do you still have those words in your stoplist? Are they indexed or not.

Sql tuning on Text index

Slavko Brkic, October 28, 2008 - 8:39 am UTC

Hi Tom.

I might have misunderstood the usage of stoplist. We are using CREATE INDEX ... STOPLIST CTXSYS.EMPTY_STOPLIST ...
We are using this as we (I) thought that using i.e. an English stoplist would ignore these words in the the search result.
Is this wrong? Does the stoplist actually tell oracle that these words are so common not to use them with the index?

Thanks,
Tom Kyte
October 28, 2008 - 10:45 am UTC

well, the problem is likely that the result set for those words is in fact HUGE (they are very common). The reason they would normally be in the stoplist is because virtually every document has them.

Tell you what post a tkprof of a 'fast' one and a tkprof of a 'slow' one. Make sure the row source operation section is there (looks like a query plan)

Sql tuning oracle text

Slavko Brkic, October 28, 2008 - 1:02 pm UTC

Here comes the rest of the tkprof as it has been cut of.

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.01 0.00 0 0 0 0
Fetch 1 0.01 0.01 0 86 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 0.03 0.01 0 86 0 1

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 244 (recursive depth: 2)

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE (cr=86 pr=0 pw=0 time=16786 us)
12056 TABLE ACCESS SAMPLE DR$MV_SONG_BATMAN_IND$I (cr=86 pr=0 pw=0 time=60315 us)




********************************************************************************

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 2 0.00 0.00 0 0 0 0
Execute 3 0.00 0.57 0 57 0 1
Fetch 3 0.03 0.06 0 18 0 30
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 8 0.03 0.63 0 75 0 31

Misses in library cache during parse: 1
Misses in library cache during execute: 1

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 8 0.00 0.00
SQL*Net message from client 8 21.40 32.74


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 171 0.01 0.01 0 2 0 0
Execute 171 0.03 0.22 0 10 0 0
Fetch 463 12.56 11.90 0 86370 0 43870
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 805 12.60 12.14 0 86382 0 43870

Misses in library cache during parse: 6
Misses in library cache during execute: 5

165 user SQL statements in session.
9 internal SQL statements in session.
174 SQL statements in session.
********************************************************************************
Trace file: orcl_ora_4664.trc
Trace file compatibility: 10.01.00
Sort options: default

1 session in tracefile.
165 user SQL statements in trace file.
9 internal SQL statements in trace file.
174 SQL statements in trace file.
13 unique SQL statements in trace file.
6246 lines in trace file.
36 elapsed seconds in trace file.

Tom Kyte
October 28, 2008 - 1:36 pm UTC

ok, let me rephrase

just show the relevant bit of the tkprof (the two queries from their text down to their row source operation)

and make sure to enclose the text in the CODE button, so we can read it.

Sql tuning oracle text

Slavko Brkic, October 29, 2008 - 3:51 am UTC

Hi,
The tkprof provided is what is generated from oracle from this select only. I thought everything was needed. Anyway below I have provided the select down to the row source operation.

Fast:
SELECT sub2.*
    FROM (
    SELECT ROWNUM rad, sub1.*
      FROM (
      SELECT songId, title, songArtist, albumId,
           popularity, genreId, genre, explicit, offerId, priceCategoryId,
           offerStartDate, offerEndDate, mountPointId, drmProtected, releaseDate
        FROM MV_Song_batman
        WHERE CATSEARCH(searchText, :vSearchString, :vCriterion) > 0) sub1
     WHERE ROWNUM <= :vEnd) sub2
   WHERE sub2.rad >= :vStart

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.01       0.25          0         18          0           0
Fetch        3      0.00       0.09          0         19          0          30
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      0.01       0.34          0         37          0          30

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244  

Rows     Row Source Operation
-------  ---------------------------------------------------
     30  VIEW  (cr=124 pr=0 pw=0 time=172964 us)
     30   COUNT STOPKEY (cr=124 pr=0 pw=0 time=172940 us)
     30    MAT_VIEW ACCESS BY INDEX ROWID MV_SONG_BATMAN (cr=124 pr=0 pw=0 time=172919 us)
     30     DOMAIN INDEX  MV_SONG_BATMAN_IND (cr=105 pr=0 pw=0 time=173146 us)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  SQL*Net message from client                     3        2.02          3.81


And here is the slow one:
SELECT sub2.*
    FROM (
    SELECT ROWNUM rad, sub1.*
      FROM (
      SELECT songId, title, songArtist, albumId,
           popularity, genreId, genre, explicit, offerId, priceCategoryId,
           offerStartDate, offerEndDate, mountPointId, drmProtected, releaseDate
        FROM MV_Song_batman
        WHERE CATSEARCH(searchText, :vSearchString, :vCriterion) > 0) sub1
     WHERE ROWNUM <= :vEnd) sub2
   WHERE sub2.rad >= :vStart

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.36          0         57          0           0
Fetch        3      0.03       0.06          0         18          0          30
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      0.03       0.43          0         75          0          30

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 244  

Rows     Row Source Operation
-------  ---------------------------------------------------
     30  VIEW  (cr=86457 pr=0 pw=0 time=12409257 us)
     30   COUNT STOPKEY (cr=86457 pr=0 pw=0 time=12409235 us)
     30    MAT_VIEW ACCESS BY INDEX ROWID MV_SONG_BATMAN (cr=86457 pr=0 pw=0 time=12409214 us)
     30     DOMAIN INDEX  MV_SONG_BATMAN_IND (cr=86439 pr=0 pw=0 time=12409392 us)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       3        0.00          0.00
  SQL*Net message from client                     3        1.95          3.68

Tom Kyte
October 29, 2008 - 7:55 am UTC

both of those are fast?

that is why I asked you to whittle it way way down to fit. I could not find a "fast" and a "slow"

Sql tuning oracle text

Slavko Brkic, October 29, 2008 - 8:53 am UTC

You have to excuse me if I do not understand you properly. The first one I copied in is fast and the second one is slow.
Tom Kyte
October 29, 2008 - 1:19 pm UTC

<b>Fast:</b>

...
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
...
total        5      0.01       0.34          0         37          0          30

<b>And here is the slow one:</b>
....

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        5      0.03       0.43          0         75          0          30



excuse me, but to me they look about the same.

about the same IO's, about the same cpu, about the same elapsed time. I don't see a huge difference between the two.

SQL tuning oracle text

Slavko Brkic, October 29, 2008 - 9:21 am UTC

Both the fast and slow query generate a lot of Oracle self generated SQL:s and for the slow query there is one that takes a lot of time namely:

select /*+ NO_EXPAND INDEX_ASC(i "DR$MV_SONG_BATMAN_ADVTTLIND03") */ dr$rowid 
  , SORTORDER    
from
 "MEDIA_CORE"."DR$MV_SONG_BATMAN_ADVTTLIND$I" i  where dr$token = :token    
  and dr$token_type = :ttype and COUNTRYCODE = 'SE'  and SORTORDER >= :r01  
  and (SORTORDER > :r01 or DR$ROWID >= :r02)  order by dr$token ASC, 
  dr$token_type ASC, SORTORDER ASC,  dr$rowid ASC 


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse      118      0.00       0.00          0          1          0           0
Execute    118      0.01       0.03          0          1          0           0
Fetch      253      4.98       5.15         13      36241          0       24983
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      489      5.00       5.19         13      36243          0       24983

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 244     (recursive depth: 1)

Rows     Row Source Operation
-------  ---------------------------------------------------
    198  SORT ORDER BY (cr=747 pr=0 pw=0 time=105302 us)
  76576   TABLE ACCESS BY INDEX ROWID DR$MV_SONG_BATMAN_ADVTTLIND$I (cr=747 pr=0 pw=0 time=765799 us)
  76576    INDEX RANGE SCAN DR$MV_SONG_BATMAN_ADVTTLIND03 (cr=292 pr=0 pw=0 time=306331 us)(object id 63606)


for the fast query it looks like this:

select /*+ NO_EXPAND INDEX_ASC(i "DR$MV_SONG_BATMAN_ADVTTLIND03") */ dr$rowid 
  , SORTORDER    
from
 "MEDIA_CORE"."DR$MV_SONG_BATMAN_ADVTTLIND$I" i  where dr$token = :token    
  and dr$token_type = :ttype and COUNTRYCODE = 'SE'  and SORTORDER >= :r01  
  and (SORTORDER > :r01 or DR$ROWID >= :r02)  order by dr$token ASC, 
  dr$token_type ASC, SORTORDER ASC,  dr$rowid ASC 


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          1          0           0
Execute      1      0.01       0.00          0          5          0           0
Fetch        1      0.00       0.00          0         13          0          80
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3      0.01       0.00          0         19          0          80

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 244     (recursive depth: 1)

Rows     Row Source Operation
-------  ---------------------------------------------------
     80  SORT ORDER BY (cr=13 pr=0 pw=0 time=551 us)
     80   TABLE ACCESS BY INDEX ROWID DR$MV_SONG_BATMAN_ADVTTLIND$I (cr=13 pr=0 pw=0 time=994 us)
     80    INDEX RANGE SCAN DR$MV_SONG_BATMAN_ADVTTLIND03 (cr=4 pr=0 pw=0 time=424 us)(object id 63606)


I assume these are the internal text index tables which contains the indexing of the tokens. However I am nut sure and I do not know how to improve performance on them.

Tom Kyte
October 29, 2008 - 1:28 pm UTC

you would want to NOT index the stop terms - the really popular stuff, you see what it is doing here, they are getting the hits and have to score them.

But it is chicken and egg problem. if someone searches for "in the as" - that'll basically be "look at every single row"

if I followed you - you are indexing all terms, that is resulting in huge scans here to find the documents and then go to the documents after sorting by score. You'll probably not want to index those particular terms.

SQL tuning of oracle text

Slavko Brkic, October 30, 2008 - 4:32 am UTC

I did create the index with the default stoplist which contains the words 'in' 'the' and so on. I made sure as I tried to add these stopwords and got an oracle error saying that these words already exists in the stoplist. It did however not improve the performance. Anyway this is not a valid solution as the customer has said that they absolutely want to include these words in the search. Is there no way of doing this faster? With faster I mean response times less than a second. We are not searching documents but in a VARCHAR2(840) field.

I have 2 questions:

a, Is there something I can do to improve performance with no stopwords?
b, Will the workaround below return the correct results

Workaround:
We have another idea if we cannot resolve the issue "properly". (I know order by needs to be all the way out to be sure to get the results sorted properly, but so far it has worked).

All these searches as I said in my original post are being done on materialized views. Our idea is to create another 2 (maybe more) materialized views.

mv_song_00_02
mv_song_02_end

The first one contains the first 2 percent sorted by sortorder.
The second one contains the rest sorted by sortorder.

The select would look something like (no binds as it is an example. Stopkeys will be added as well.):
select * from mv_song_00_02
where catsearch(searchText, 'in the ghetto', 'countryCode = ''SE'' order by sortOrder') > 0
union all
select * from mv_song_02_end
where catsearch(searchText, 'in the ghetto', 'countryCode = ''SE'' order by sortOrder') > 0;


If we have words which contain a lot of results we will only use the 2 percent (until the user paginates far forward, and then we are willing to let them wait for those results). We think it will be faster as the materialized view is much smaller.

If the result contain few results the select on the mv_song_02_end will be fast anyway.

With this solution we can add more partitions of materialized views as well as change the sizes of them until the result is good.

Now for the question. Can one be sure that Oracle returns the results from the first union first and then the second union? (My test shows that but is it a fact). The test also shows that Oracle does not perform the second union search until I paginate forward until there are no more results from the first union.

p.s. The reason I provided the full tkprof is that it was the Oracle internal SQL that took so long and not the "original" select.
Tom Kyte
October 30, 2008 - 8:36 am UTC

if there are thousands of hits with those stopwords - in, the, and the like - well, you'll have a ton of data to sift through. So, if you have a ton of data to sift through, score/sort - and then get the first couple - it'll take "work"

question for you - should in the ghetto be surrounded by {} - did you mean to do a phrase search there - or individual keywords in any order - so that "in the city" would be returned as well as "ghetto building in the dark"

Sql tuning Oracle text

Slavko Brkic, October 30, 2008 - 12:09 pm UTC

Hi,

It does not have to be in the right order but all words need to exist i.e:
'in the ghetto'

would return

'ghetto in the suburbs'
'The ghetto was bubbling with people in a hurry'
'in the ghetto'

but not
'The ghetto'

I did the search for the whole phrase as well but it did not improve the search.

Is the workaround I described anything we should consider?



Tom Kyte
November 02, 2008 - 3:23 pm UTC

does "the workaround" work for you?

If so, sure, it should be considered.


the problem you have is that almost everything has "in" and "the" in it - right? So, in order to find "in the ghetto" using not a phrase search but a word search (any order) involves processing a ton of data.

Sql tuning Oracle text

Slavko Brkic, November 03, 2008 - 5:23 am UTC

Hi Tom,

I have done quite a few tests and the workaround seems to work for us. My question for the workaround is: Can one be sure that Oracle returns the results from the first union first and then the second union? My test shows that but is it a fact?. The test also shows that Oracle does not perform the second union search until I paginate forward until there are no more results from the first union.

I have now changed the materialized view mv_song so that it now contains approximately 750.000 records. We have 'the' in 210.000 records and 'in' in 65.000 records and 'ghetto' in 593 records.

Doing the test with splitting up in several tables shows me that I am also getting the whole resultset back much quicker than with just one table (running both selects in sqlplus with 'set autotrace traceonly' and without stopkeys). Is this something that surprises you. It certainly did surprise me. I never thought that:

select x from y where <condition>;

would be slower than

select x from y/2 where <condition>
union
select x from y/2 where <condition>;


Here are the figures from my tests:

PL/SQL procedure successfully completed.


73 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 3125318639

--------------------------------------------------------------------------------
-----------------------

| Id  | Operation                      | Name                 | Rows  | Bytes |
Cost (%CPU)| Time     |

--------------------------------------------------------------------------------
-----------------------

|   0 | SELECT STATEMENT               |                      | 36318 |  6951K|
    2   (0)| 00:00:01 |

|   1 |  MAT_VIEW ACCESS BY INDEX ROWID| MV_SONG_SE_ROBIN     | 36318 |  6951K|
    2   (0)| 00:00:01 |

|*  2 |   DOMAIN INDEX                 | MV_SONG_SE_ROBIN_IND |       |       |
           |          |

--------------------------------------------------------------------------------
-----------------------


Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)


Statistics
----------------------------------------------------------
        749  recursive calls
          0  db block gets
      31367  consistent gets
          0  physical reads
          0  redo size
       7675  bytes sent via SQL*Net to client
        425  bytes received via SQL*Net from client
          6  SQL*Net roundtrips to/from client
        154  sorts (memory)
          0  sorts (disk)
         73  rows processed


PL/SQL procedure successfully completed.


73 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 2879147283

--------------------------------------------------------------------------------
---------------------------

| Id  | Operation                    | Name                       | Rows  | Byte
s | Cost (%CPU)| Time     |

--------------------------------------------------------------------------------
---------------------------

|   0 | SELECT STATEMENT             |                            | 37551 |  725
3K|    10  (80)| 00:00:01 |

|   1 |  UNION-ALL                   |                            |       |
  |            |          |

|   2 |   TABLE ACCESS BY INDEX ROWID| MV_SONG_SE_ROBIN_0K_50K    |  2500 |   47
1K|     2   (0)| 00:00:01 |

|*  3 |    DOMAIN INDEX              | MV_SONG_SE_R_PART1_IND     |       |
  |            |          |

|   4 |   TABLE ACCESS BY INDEX ROWID| MV_SONG_SE_ROBIN_50K_200K  |  7500 |  142
8K|     2   (0)| 00:00:01 |

|*  5 |    DOMAIN INDEX              | MV_SONG_SE_R_PART2_IND     |       |
  |            |          |

|   6 |   TABLE ACCESS BY INDEX ROWID| MV_SONG_SE_ROBIN_200K_400K | 10000 |  203
1K|     2   (0)| 00:00:01 |

|*  7 |    DOMAIN INDEX              | MV_SONG_SE_R_PART3_IND     |       |
  |            |          |

|   8 |   TABLE ACCESS BY INDEX ROWID| MV_SONG_SE_ROBIN_400K_600K | 10000 |  191
4K|     2   (0)| 00:00:01 |

|*  9 |    DOMAIN INDEX              | MV_SONG_SE_R_PART4_IND     |       |
  |            |          |

|  10 |   TABLE ACCESS BY INDEX ROWID| MV_SONG_SE_ROBIN_TOP       |  7551 |  140
8K|     2   (0)| 00:00:01 |

|* 11 |    DOMAIN INDEX              | MV_SONG_SE_R_PART5_IND     |       |
  |            |          |

--------------------------------------------------------------------------------
---------------------------


Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)
   5 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)
   7 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)
   9 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)
  11 - access("CTXSYS"."CATSEARCH"("SEARCHTEXT",:VSEARCHSTRING,:VCRITERION)>0)


Statistics
----------------------------------------------------------
        769  recursive calls
          0  db block gets
       8134  consistent gets
          0  physical reads
          0  redo size
       7675  bytes sent via SQL*Net to client
        625  bytes received via SQL*Net from client
          6  SQL*Net roundtrips to/from client
        167  sorts (memory)
          0  sorts (disk)
         73  rows processed

Run1 ran in 534 hsecs
Run2 ran in 148 hsecs
run 1 ran in 360.81% of the time
        
Name                                  Run1        Run2        Diff
STAT...user calls                       30          31           1
STAT...index fetch by key               38          39           1
STAT...rows fetched via callba          38          39           1
STAT...table fetch by rowid            111         112           1
LATCH.OS process allocation              2           1          -1
LATCH.ksuosstats global area             0           1           1
STAT...SQL*Net roundtrips to/f          22          23           1
STAT...workarea executions - o         162         161          -1
LATCH.Shared B-Tree                      1           0          -1
LATCH.library cache pin alloca           8           9           1
LATCH.library cache lock               208         209           1
LATCH.kwqbsn:qsga                        1           0          -1
LATCH.session timer                      2           1          -1
LATCH.active checkpoint queue            2           0          -2
STAT...cleanout - number of kt           4           6           2
STAT...active txn count during           4           6           2
STAT...calls to kcmgcs                   4           6           2
LATCH.KMG MMAN ready and start           2           0          -2
LATCH.library cache lock alloc          11           9          -2
LATCH.object queue header oper           8           6          -2
LATCH.undo global data                   7           4          -3
LATCH.compile environment latc           2           5           3
LATCH.qmn task queue latch               4           0          -4
STAT...buffer is pinned count           84          89           5
LATCH.session allocation                 4          10           6
STAT...buffer is not pinned co         141         147           6
LATCH.redo allocation                    9           3          -6
LATCH.redo writing                       9           3          -6
LATCH.active service list               10           2          -8
LATCH.In memory undo latch               8           0          -8
STAT...sorts (memory)                  156         169          13
LATCH.session idle bit                  80          95          15
LATCH.dml lock allocation               16           0         -16
STAT...redo entries                     15          34          19
STAT...db block gets                    37          60          23
STAT...db block gets from cach          37          60          23
STAT...consistent changes               27          50          23
STAT...opened cursors current          -12          12          24
LATCH.messages                          36           8         -28
STAT...consistent gets - exami         426         457          31
LATCH.channel operations paren          34           1         -33
LATCH.JS queue state obj latch          36           0         -36
STAT...table scan rows gotten          162         198          36
LATCH.checkpoint queue latch            41           1         -40
STAT...db block changes                 43          85          42
STAT...session cursor cache hi         159         206          47
STAT...opened cursors cumulati         176         229          53
STAT...parse count (total)             176         229          53
STAT...index scans kdiixs1             164         217          53
STAT...shared hash latch upgra         164         217          53
STAT...calls to get snapshot s         252         306          54
STAT...execute count                   181         243          62
LATCH.shared pool                      156         230          74
LATCH.enqueues                          86           9         -77
LATCH.enqueue hash chains              101           4         -97
LATCH.SQL memory manager worka         445         305        -140
LATCH.library cache pin                563         809         246
STAT...Elapsed Time                    536         150        -386
STAT...CPU used by this sessio         530         136        -394
STAT...recursive cpu usage             530         135        -395
STAT...CPU used when call star         532         136        -396
STAT...DB time                         544         137        -407
LATCH.library cache                    782       1,232         450
STAT...recursive calls                 984       1,742         758
STAT...bytes sent via SQL*Net       10,249      11,716       1,467
LATCH.simulator lru latch            1,985         491      -1,494
LATCH.simulator hash latch           1,985         491      -1,494
STAT...bytes received via SQL*       2,719       4,312       1,593
STAT...workarea memory allocat        -883         843       1,726
LATCH.row cache objects              1,183       3,755       2,572
STAT...undo change vector size       4,164      10,588       6,424
STAT...redo size                     5,340      13,116       7,776
STAT...session logical reads        31,568       8,404     -23,164
STAT...consistent gets              31,531       8,344     -23,187
STAT...consistent gets from ca      31,531       8,344     -23,187
STAT...no work - consistent re      30,906       7,634     -23,272
LATCH.cache buffers chains          62,873      16,476     -46,397
STAT...session uga memory max      196,392           0    -196,392
STAT...session pga memory max      327,680           0    -327,680
STAT...session pga memory         -458,752     327,680     786,432
STAT...sorts (rows)              8,490,680   2,082,128  -6,408,552
        
Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
70,719      24,189     -46,530    292.36%

PL/SQL procedure successfully completed.


Tom Kyte
November 10, 2008 - 2:53 pm UTC

... Can one be sure that Oracle returns the results from the first union first and then the second union? My test shows that but is it a fact? ...

in a word

NO, you cannot


you could use a pipelined function that would run query 1 and then run query 2 if and only if you wanted to.

trouble query tuning

sky, November 07, 2008 - 10:34 am UTC

Hey Tom:

We have a query that runs a little werid. Normally it takes about 2-3 seconds, but sometimes it runs over 15 seconds. And even 2-3 seconds is still longer than what we expect. But I don't know what the problem is. It is the main query of a search page. we want it to run as fast as possible.

here is the stats from the trace:(our system has cursor_sharing = force.)

SELECT
av.ad_id, av.year, av.make_name, av.model_name, av.price, av.color, av.body_type, av.doors,
av.cylinder_quantity, av.trans_type, av.drive_type, ai.ad_id, path, ai.file_name
FROM book_results1 av, ad_image ai
WHERE av.dealer_id = :"SYS_B_0"
and av.ad_id != :"SYS_B_1"
and ai.type = :"SYS_B_2"
and av.ad_id = ai.ad_id

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 44 0.10 3.47 461 2695 0 638
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 46 0.10 3.48 461 2695 0 638

Misses in library cache during parse: 1
Misses in library cache during execute: 1
Optimizer mode: ALL_ROWS
Parsing user id: 192 (BOOK)

Rows Row Source Operation
------- ---------------------------------------------------
638 NESTED LOOPS (cr=2695 pr=461 pw=0 time=269902 us)
638 TABLE ACCESS BY INDEX ROWID BOOK_RESULTS1 (cr=687 pr=0 pw=0 time=7679 us)
638 INDEX RANGE SCAN BOOK_R1_DLRIDADMM_IDX (cr=49 pr=0 pw=0 time=1938 us)(object id 1287697)
638 INDEX RANGE SCAN ADIMGAE_ADTYPEPATHFILE_IDX (cr=2008 pr=461 pw=0 time=3467181 us)(object id 1293978)


Rows Execution Plan
------- ---------------------------------------------------
0 SELECT STATEMENT MODE: ALL_ROWS
638 NESTED LOOPS
638 TABLE ACCESS MODE: ANALYZED (BY INDEX ROWID) OF 'BOOK_RESULTS1' (TABLE)
638 INDEX MODE: ANALYZED (RANGE SCAN) OF 'BOOK_R1_DLRIDADMM_IDX' (INDEX)
638 INDEX MODE: ANALYZED (RANGE SCAN) OF 'ADIMGAE_ADTYPEPATHFILE_IDX' (INDEX)


Here is the stats from autotrace. I changed the value and run in the sqlplus.


SELECT
av.ad_id, av.year, av.make_name, av.model_name, av.price, av.color, av.body_type,
av.doors, av.cylinder_quantity, av.trans_type, av.drive_type, ai.ad_id, path, ai.file_name
FROM book_results1 av, ad_image ai
WHERE av.dealer_id = 1347
and av.ad_id != 2387282
and ai.type = 'PRIMARY'
and av.ad_id = ai.ad_id

Elapsed: 00:00:02.03


| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |

-----------------------------------------------------------------------------------------------------------

| 0 | SELECT STATEMENT | | 248 | 38688 | 361 (1)| 00:00:05 |
| 1 | NESTED LOOPS | | 248 | 38688 | 361 (1)| 00:00:05 |
| 2 | TABLE ACCESS BY INDEX ROWID| BOOK_RESULTS1 | 161 | 13846 | 196 (1)| 00:00:03 |
|* 3 | INDEX RANGE SCAN | BOOK_R1_DLRIDADMM_IDX | 192 | | 3 (0)| 00:00:01 |
|* 4 | INDEX RANGE SCAN | ADIMGAE_ADTYPEPATHFILE_IDX | 2 | 140 | 3 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

3 - access("DEALER_ID"=1347)
filter("AD_ID"<>2387282)
4 - access("AD_ID"="AI"."AD_ID" AND "AI"."TYPE"='PRIMARY')
filter("AI"."AD_ID"<>2387282)

Statistics
----------------------------------------------------------
16 recursive calls
0 db block gets
1328 consistent gets
470 physical reads
0 redo size
32360 bytes sent via SQL*Net to client
686 bytes received via SQL*Net from client
20 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
283 rows processed


and I check the query from ASH too, the top wait for this is db sequencial read. And a high percentage of the time is spent on waiting for user I/O. I have checked the tablespace too. Those two tables are staying in their own tablespace and the tablespaces is not fragmented. So what the problem is and what shall I do.


Tom Kyte
November 11, 2008 - 2:46 pm UTC

run it with wait events enabled - big difference between cpu and elapsed time, see what you are waiting on.


it does physical IO, and....

ops$tkyte%ORA10GR2> select 3.38/461 from dual;

  3.38/461
----------
.007331887


so, if the cpu was 0.10 and the elapsed what 3.48 - we'd need to find out why we waited 3.38 seconds - but since I see 461 physical IO's in there - I can sort of guess why - and 0.007 per physical IO sounds right.

and we can see right where they are:


Rows     Row Source Operation
-------  ---------------------------------------------------
    638  NESTED LOOPS  (cr=2695 pr=461 pw=0 time=269902 us)
    638   TABLE ACCESS BY INDEX ROWID BOOK_RESULTS1 (cr=687 pr=0 pw=0 time=7679 
us)
    638    INDEX RANGE SCAN BOOK_R1_DLRIDADMM_IDX (cr=49 pr=0 pw=0 time=1938 
us)(object id 1287697)
    638   INDEX RANGE SCAN ADIMGAE_ADTYPEPATHFILE_IDX <b>(cr=2008 pr=461</b> pw=0 
time=3467181 us)(object id 1293978)



so, we hit that index 638 times, doing 638 index range scans.


but you know, without knowing

a) what is indexed
b) how it is indexed
c) what the tables are

I'm not going to look much harder. We know why it is slow (physical IO), can it be faster? Don't know, I don't know your schema.


sort of stinks you have to use cursor sharing force/similar. Hope this isn't a widely used application - it is of course subject to sql injection attacks - forget performance, this is a security nightmare.


and I don't have any idea what a 'fragmented' tablespace would look like or why it would matter since all you are doing is 100% single block IO (all reads by rowids basically, all instructions to read "this file, that block", the number of extents would not ever be relevant for that).

and you only hit one table - not two - so reviewing the other table doesn't make sense, it isn't being used

Urgent

Sumon, November 07, 2008 - 11:51 pm UTC

Hi Tom,
Thanks for your support.
I am urgently need your help.
Please help with the query.

scripts:

create table users
(id number(2),
name varchar2(10));

create table userip
(id number(2),
ip varchar2(10));

create table sup_cost
(ip varchar2(10),
sup_ip varchar2(10),
bill_amt number);

insert into users values (11,'name-11');
insert into users values (22,'name-22');
insert into users values (33,'name-33');
insert into userip values (11,'ip-111');
insert into userip values (11,'ip-112');
insert into userip values (11,'ip-113');
insert into userip values (22,'ip-1111');
insert into userip values (22,'ip-1112');
insert into userip values (22,'ip-1115');
insert into userip values (22,'ip-1117');
insert into userip values (33,'ip-1113');
insert into userip values (33,'ip-1114');
insert into userip values (33,'ip-1116');
insert into sup_cost values ('ip-111','ip-1111',4);
insert into sup_cost values ('ip-111','ip-1112',5);
insert into sup_cost values ('ip-111','ip-1111',3);
insert into sup_cost values ('ip-111','ip-1112',7);
insert into sup_cost values ('ip-112','ip-1113',8);
insert into sup_cost values ('ip-112','ip-1114',6);
insert into sup_cost values ('ip-112','ip-1114',2);
insert into sup_cost values ('ip-112','ip-1115',4);
insert into sup_cost values ('ip-113','ip-1115',7);
insert into sup_cost values ('ip-113','ip-1116',2);
insert into sup_cost values ('ip-113','ip-1117',9);
insert into sup_cost values ('ip-113','ip-1117',8);
insert into sup_cost values ('ip-113','ip-1113',6);
commit;
/

/*

Relations:
------------------------------
usres.id = userip.id
userip.ip = sup_cost.ip
also
sup_cost.sup_ip = userip.ip

*/

Output required as follows:

users.id user_ip.id tot_bill_amt
-------- ---------- ------------
11 22 47
11 33 24

Thanks in advance.

Tom Kyte
November 11, 2008 - 2:48 pm UTC

.... I am urgently need your help. ...

and now you know you cannot rely on me for timely answers - it is rather "catch as catch can". I was really busy for a while.... :)

this looks like just a join and aggregate - not sure why this is 'hard'? this looks pretty basic actually?

join users to userip, userip to sup_cost - group by users.id, userip.id and sum(sup_cost.bill_amount)

Internals of CBO

A reader, November 11, 2008 - 5:55 am UTC

Tom,
This is regarding your comments on Dan Tow's book "SQL Tuning" which in my opinion is a very good book doing a decent job helping sql developers.
I understand that knowing how to arrive at a optimal execution plan for a sql is the job of the software(CBO) but i feel it is good to know the optimal plan beforehand when you start writing a sql and expect the same to be delivered by the software. Many advantages i see here:
1)You get to know the entities and relationships; data structures you want to access
2)you get to know what filter conditions you have for your sql
3)you get to know what join order you want to see
Above all it helps in getting the sql right during development mode.
So if you take the book as a aid during development it is worth reading it.
Even for a existing sql it helps to see what should have been the optimal plan. I feel there is no harm in knowing it if you have the patience and time to remember the logic/heuristics.
Regards

trouble query tuning

sky, November 12, 2008 - 4:45 pm UTC

Hey Tom:

This database has not been hitting very often yet. Is that possible once it states being accessed a lot, then the table and indexes will be cached in the memory, then there will not be a lot of physical gets?


thank you very much!
Tom Kyte
November 13, 2008 - 4:56 pm UTC

just run the query twice and it'll go down, yes.


I cannot say "yes definitely", but "maybe" - it depends on whether the users access the same bits of data obviously.

touble query tuning

sky, November 13, 2008 - 7:27 pm UTC

Hey Tom:


My query hits two tables, one is the BOOK_RESULTS1, which is accessed by rowid from index BOOK_R1_DLRIDADMM_IDX. And for table ad_image, I created index ADIMGAE_ADTYPEPATHFILE_IDX to cover all the columns included in the query. So the ad_image table is not involved. only this index is being range_scaned.
So where is the 461 physical reads from? Should be from range scanning the ADIMGAE_ADTYPEPATHFILE_IDX right? since we have this in the plan:

638 INDEX RANGE SCAN ADIMGAE_ADTYPEPATHFILE_IDX (cr=2008 pr=461 pw=0 time=3467181 us)(object id 1293978)


Does this mean it is the ADIMGAE_ADTYPEPATHFILE_IDX that caused the problem? or it is from range scan BOOK_R1_DLRIDADMM_IDX index, or it is from accessing BOOK_RESULTS1 table by rowid.

And you mentioned "so, we hit that index 638 times, doing 638 index range scans. " Which index you are talking about here, BOOK_R1_DLRIDADMM_IDX or ADIMGAE_ADTYPEPATHFILE_IDX?

Will the index range scan create the physical gets? (from reading the index blocks)


Tom Kyte
November 14, 2008 - 5:25 pm UTC


Rows     Row Source Operation
-------  ---------------------------------------------------
    638  NESTED LOOPS  (cr=2695 pr=461 pw=0 time=269902 us)
    638   TABLE ACCESS BY INDEX ROWID BOOK_RESULTS1 (cr=687 pr=0 pw=0 time=7679 
    638    INDEX RANGE SCAN BOOK_R1_DLRIDADMM_IDX (cr=49 pr=0 pw=0 time=1938 
    638   INDEX RANGE SCAN ADIMGAE_ADTYPEPATHFILE_IDX (cr=2008 pr=461 pw=0 



Your query found 638 rows in the index BOOK_R1_DLRIDADMM_IDX

It then found 638 rows in the table BOOK_RESULTS1 for the same.

Then, 638 times it had to index range scan ADIMGAE_ADTYPEPATHFILE_IDX - that causes 2008 IO's

It took 3, sometimes 4, IO's to do that:

ops$tkyte%ORA10GR2> select 2008/638 from dual;

  2008/638
----------
3.14733542




Do you sort of see how the query:

SELECT ....
FROM book_results1 av, ad_image ai
WHERE av.dealer_id = 1347
and av.ad_id != 2387282
and ai.type = 'PRIMARY'
and av.ad_id = ai.ad_id

is processed by that nested loops join?

sort of like this in psuedo code:

for x in ( select ... 
             from book_results1 
            where av.dealer_id = 1347
              and av.ad_id != 2387282 )
loop
    for y in (select ... 
                from ad_image
               where type = 'PRIMARY' 
                 and ad_id = X.AD_ID )
    loop    
        output record
    end loop
end loop



so, the index range scan happens against ad_image for every row in book results1 that you find....



Any access to Any block that is NOT in the buffer cache will incur a physical IO.


trouble query tuning

sky, November 15, 2008 - 5:52 pm UTC

Hey Tom:

    you mentioned:

it does physical IO, and....

ops$tkyte%ORA10GR2> select 3.38/461 from dual;

  3.38/461
----------
.007331887

>>> I can understand this, but not the following:

Then, 638 times it had to index range scan ADIMGAE_ADTYPEPATHFILE_IDX - that causes 2008 IO's

It took 3, sometimes 4, IO's to do that:

ops$tkyte%ORA10GR2> select 2008/638 from dual;

  2008/638
----------
3.14733542

>>> I know there is 461 physical I/O, but why here you said 2008 IO? And why you use the 2008 which is the number of the IO to divide 638? Can you elaborate on this a little.

    Thank you very much!

 

Tom Kyte
November 18, 2008 - 7:07 pm UTC

    638   INDEX RANGE SCAN ADIMGAE_ADTYPEPATHFILE_IDX (cr=2008 pr=461 pw=0 
                                                       ^^^^^^^


it did 2008 IO's from the buffer cache, 461 of them were PHYSICAL IO'S to disk

On average, that lookup took 3-4 IO's

(think about an index range scan, the first one would have read the index ROOT BLOCK into the cache - you never needed to read it again, so the others would just be consistent reads (cr) - IO's to the buffer cache - they are logical IO's)

question on cr= values

Chris, December 29, 2008 - 6:19 pm UTC

Tom,

Hope you and your family had a wonderful Christmas! Thanks again for all the help you dedicate to the Oracle community. I have a quick question about your previous comment:


Then, 638 times it had to index range scan ADIMGAE_ADTYPEPATHFILE_IDX - that causes 2008 IO's

It took 3, sometimes 4, IO's to do that:

ops$tkyte%ORA10GR2> select 2008/638 from dual;

2008/638
----------
3.14733542






Are the cr= values cumulative? If so, to determine the actual value for this particular step, would we need to subtract the current value from the child step (e.g. for this step, cr= 2008 - 687 == 1321)?

If so, that would make the logical i/o's:

select (2008 - 687) / 638 from dual;

(2008-687)/638
--------------
    2.07053292




Thanks,
Chris
Tom Kyte
January 05, 2009 - 8:30 am UTC

they are cumulative, to their parent. So in this case:

Rows     Row Source Operation
-------  ---------------------------------------------------
    638  NESTED LOOPS  (cr=2695 pr=461 pw=0 time=269902 us)
    638   TABLE ACCESS BY INDEX ROWID BOOK_RESULTS1 (cr=687 pr=0 pw=0 time=7679 
    638    INDEX RANGE SCAN BOOK_R1_DLRIDADMM_IDX (cr=49 pr=0 pw=0 time=1938 
    638   INDEX RANGE SCAN ADIMGAE_ADTYPEPATHFILE_IDX (cr=2008 pr=461 pw=0 



2008 plus 687 = 2695. 2008 is a "peer" of 687. We did 49 IO's against the index BOOK_R1_DLRIDADMM_IDX, and then 687-49 IO's against the table BOOK_RESULTS1. That caused us to range scan ADIMGAE_ADTYPEPATHFILE_IDX and we did 2008 IO's against that index.

We did a total of 2008 + 687 IO's - 2,695.

Latches vs Time

Slavko Brkic, January 07, 2009 - 3:04 am UTC

Hi Tom,

I have a question regarding latches and sql tuning.

We are having some problems with response times using the catsearch index when using frequently occuring words such as the, in, of etc. Using the contains index on these searches produces much faster response times. However when we do not have these frequently occuring words in the where clause the catsearch is faster and using catsearch usually produces much less latching as well.


Some words results in somewhat better response times but more latching for the contains index. These are the cases where I am not sure what to do. Time is something that is easy to get a feel for e.g. 1 sec response time vs 2 sec. response time. However I do not have the same understanding with latches.

If the contains produces 12000 latches and the catsearch produces 3000 but the contains is twice as fast (0.4 sec vs 0.8 s) what should one use?

With regards,
Slavko



Tom Kyte
January 07, 2009 - 9:25 am UTC

...
If the contains produces 12000 latches and the catsearch produces 3000 but the
contains is twice as fast (0.4 sec vs 0.8 s) what should one use?
......


it is a matter of scaling. In isolation - it takes 0.4 seconds. But what happens when you do it under load with as many concurrent users as you anticipate having?


A latch is a serialization device, the more people that request the same latch at the some time necessarily implies "longer runtimes" - as the number of concurrent users go up, so will the observed run times and cpu times (as you spin on the latch trying to get it)

So, measure this under load before determining "which is better". If you are a single user system - go with the lower run time in isolation. If you are a multi-user system, you have to test under load.

Latches vs time

Slavko Brkic, January 08, 2009 - 1:44 am UTC

Hi Tom and thanks for your answer,

What is a lot of latches?. When should one get concerned i.e. when should the alarm bells start ringing and saying mybe we should take a look at this. Is 1000, 10.000, 100.000 or 1.000.000 a lot? I understand this depends on what we are trying to do but when would you get concerned for a somewhat simple select (whith time this is very easy to understand).

Thanks,

Tom Kyte
January 08, 2009 - 9:19 am UTC

that is like asking "how long is a piece of string"

the only answer is "it depends"

Here is the only ROT (rule of thumb) I have

If your goal is scalability, use approaches that minimize the number of latches required by the database. Realize that you cannot *remove* the need for latches, but you can choose an approach that minimizes them. Realize that latching will inhibit scalability so you want to attempt to reduce them in general. But always, always remember the tradeoffs. What if a latch intensive method runs 100 times faster than a non latch intensive method in single user mode (say latch intensive uses 1,000,000 latch gets and the other uses 1,000). Now, as we increase the number of concurrent users - the amount of CPU used by each individual in the latch intensive method will increase as we spin on latches, as we experience contention. But what if the CPU only doubles and the runtime only triples? Now, instead of running 100 times faster, it only runs 33 times faster.




There is no number N such that "if you use more than N, it is bad". Rather, look at what you are doing and see if there is a *sensible*, *efficient* way to do it that would require less latching.

Consider this tiny example. We all know that a logical IO (consistent get) requires lots of latching - we access the buffer cache and we have to do that safely. So, in general, when tuning a query, we want to reduce the logical IO to increase the scalability.


ops$tkyte%ORA10GR2> /*
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> drop table t;
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create table t
ops$tkyte%ORA10GR2> as
ops$tkyte%ORA10GR2> select * from all_objects;
ops$tkyte%ORA10GR2> */
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly statistics;
ops$tkyte%ORA10GR2> select * from t;

50206 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       3988  consistent gets
          0  physical reads
          0  redo size
    2541203  bytes sent via SQL*Net to client
      37217  bytes received via SQL*Net from client
       3349  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      50206  rows processed


our goal - tune that query. which of the two following approaches do you think would best achieve our goal? (hint, it is NOT the one with the least amount of latching :) )

ops$tkyte%ORA10GR2> select * from t order by object_name;

50206 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        697  consistent gets
          0  physical reads
          0  redo size
    2871059  bytes sent via SQL*Net to client
      37217  bytes received via SQL*Net from client
       3349  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      50206  rows processed

ops$tkyte%ORA10GR2> set arraysize 500
ops$tkyte%ORA10GR2> select * from t;

50206 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        797  consistent gets
          0  physical reads
          0  redo size
    2128865  bytes sent via SQL*Net to client
       1500  bytes received via SQL*Net from client
        102  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      50206  rows processed

ops$tkyte%ORA10GR2> set autotrace off

SQL Profile vs OUTLINES

Shivdeep Modi, January 12, 2009 - 6:48 am UTC

Hi,
What is the difference in using SQL Profiles against stored OUTLINES?
Tom Kyte
January 12, 2009 - 9:08 pm UTC

that is like comparing an apply to a flying toaster oven.


a stored outline is asking Oracle to save a series of hints that say "use this index, then access this table, use a next loops join to put t1 and t2 together and then hash join to t3". A stored outline says "execute the query this way"


a sql profile says "you know, we looked and when you execute this where clause - you get 5 rows (I know, without the profile you thought 5000 rows, but it is really 5). When you execute this part of the where clause - you will get 1,000 rows (I know, without the profile you thought 10 rows, but it is really 1,000)"


a sql profile gives the optimizer information - better cardinalities.
an outline says "use this plan, period"

OR Clause

Vinny, January 16, 2009 - 5:02 pm UTC

Tom,
This is related to OR clause which was discussed early in the thread.

I have a query (which executes repeatedly in a loop) that searches a table on a few columns one of which is a date column. I have to search based on a few different combinations of DATE (column F in query below) - so the query is something like:

--First case
For X in(select D,E,F from sometable) loop
SELECT A, B, C FROM TABLEA INTO ...
WHERE
D = <X.D> AND
E = <X.E> AND
F = <X.F>;
do something...
END LOOP;

--Second case
For X in(select D,E,F from sometable) loop
SELECT A, B, C FROM TABLEA INTO ...
WHERE
D = <X.D> AND
E = <X.E> AND
(F = <X.F> OR TO_CHAR(F,'YYYYMM') = TO_CHAR(X.F,'YYYYMM') OR TO_CHAR(F,'YYYYDD') = TO_CHAR(X.F,'YYYYDD')OR TO_CHAR(F,'YYYYMM') = TO_CHAR(X.F,'MMDD'))
do something...
END LOOP;

columns D and E are indexed and have good selectivity so the access is always via an Index in both cases. The first query is very fast and I get about a thousand rows processed per second. The second case is very slow - it starts out fast enough but as it passes through the loop it slows down - eventually to a crawl. I checked the access path/TKPROF and the access path is via the index in both cases. My question is why is the second query so slow even though the plan is the same? How else can I rewrite the query with the OR clauses to perform well? I tried function based indexes on TO_CHAR(F) and that did not help.

Any insight is greatly appreciated.
Tom Kyte
January 16, 2009 - 6:28 pm UTC

why are you doing

TO_CHAR(F,'YYYYMM') = TO_CHAR(X.F,'YYYYMM')

and not

trunc( f, 'mm' ) = trunc( x.f, 'mm' )

one approach chews up CPU like mad, and the other doesn't...

and this doesn't make sense:

TO_CHAR(F,'YYYYMM') = TO_CHAR(X.F,'MMDD'))

I don't see how they could ever be the same.

is this 'real' or 'made up', if made up, I need to see REAL


OR Clause

Vinny, January 16, 2009 - 6:23 pm UTC

Some further information.

The access path is

Index Range Scan Followed by a Table Access by Index Rowid in both queries and the cost is the same for both cases. So it seems strange that one performs so much better than the other...
Tom Kyte
January 16, 2009 - 6:29 pm UTC

not really, one of them does a simple equals

the other has to perform millions of cpu operations to compare each one.

Thanks for the quick response

Vinny, January 16, 2009 - 6:50 pm UTC

Tom,
Sorry about the TO_CHAR(F,'YYYYMM') = TO_CHAR(X.F,'MMDD'))

It was a typo. It should have been TO_CHAR(F,'MMDD') = TO_CHAR(X.F,'MMDD')). This is a real example and not a made up one. I just typed a simple example to illustrate my situation rather than copying and pasting my very long code. Thanks for the pointer on using TRUNC. I did not think about the CPU impact of using TO_CHAR. I will try the trunc approach and post the results back here.

Thanks again for the pointer.

Vinny, January 16, 2009 - 8:16 pm UTC

Tom,
I can replace TO_CHAR(F,'YYYYMM') with TRUNC(F,'MM').

However TRUNC does not work for TO_CHAR(F,'YYYYDD') or TO_CHAR(F,'MMDD'). Are there solutions other than TO_CHAR or am I stuck with that?

Thanks



Tom Kyte
January 16, 2009 - 8:35 pm UTC

you are stuck with that

Explain please

A reader, January 17, 2009 - 10:36 am UTC

Tom- How is TRUNC different from TO_CHAR - since they are both in-built functions how will one cause millions of cpu operations while the other does not? Please explain. Thank you.

Tom Kyte
January 17, 2009 - 11:03 am UTC

to_char( dt, 'arbitrary format that must be evaluated using massive NLS library')

versus

trunc( dt, 'mm' ) - just zero out the last couple of bytes.


A date is stored in 7 bytes

Century
Year
Month
Day
Hour
Min
Second

to trunc(dt,'mm') just set last 4 bytes "off"

to format dt as a string, lots of generic code.



just because a function is builtin doesn't mean it costs the same to execute as every other builtin function.

A reader, January 17, 2009 - 11:29 am UTC

Very good explanation. Thank you.

Could the poster use EXTRACT function to compare? Would that be any better?

To compare YYYYDD you would use extract(YEAR FROM column1)||extract(DAY from column1) = extract(YEAR FROM column2)||extract(DAY from column2)

Would that be any better compared to TO_CHAR? Just a thought that might help...
Tom Kyte
January 17, 2009 - 11:54 am UTC


create table t
as
select created from all_objects;
insert into t select * from t;
/
/
exec dbms_stats.gather_table_stats( user, 'T' )
commit;

@trace

begin
    for x in ( select to_char(created,'yyyydd') dt from t )
    loop
        null;
    end loop;
    for x in ( select to_char(extract(year from created),'fm0000') || to_char(extract(day from created),'fm00') dt from t )
    loop
        null;
    end loop;
end;
/



SELECT TO_CHAR(CREATED,'yyyydd') DT
FROM
 T


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch     3986      0.63       0.62          0       4734          0      398520
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     3988      0.63       0.62          0       4734          0      398520

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 492     (recursive depth: 1)

Rows     Row Source Operation
-------  ---------------------------------------------------
 398520  TABLE ACCESS FULL T (cr=4734 pr=0 pw=0 time=398843 us)

********************************************************************************

SELECT TO_CHAR(EXTRACT(YEAR
FROM
 CREATED),'fm0000') || TO_CHAR(EXTRACT(DAY FROM CREATED),'fm00') DT FROM T


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch     3986      0.94       0.89          0       4734          0      398520
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total     3988      0.94       0.89          0       4734          0      398520



extract seems to take a bit more cpu and you'd probably want to use explicit formats when comparing numbers (extract returns a number - avoid implicit conversions). Don't let the to char with extract distract you - yours had a to_char there as well, only it was invisible.

Regular Expressions possibly??

A reader, January 18, 2009 - 12:51 pm UTC

Tom,
Could you convert the date to a text field and then use regular expressions to find the variations - YYYYMM/YYYYDD/MMDD?

It seems like you should be able to do this with regular expressions. I know you hate storing dates in text fields but you could keep the original date field and add a new text field where you keep the date - just for search/match purposes. Any thoughts on that?


dynamic_sampling

A Reader, January 19, 2009 - 4:50 am UTC

Hi Tom,
Could you please help me in this. I have a select statement(DWS, 9i) on two tables, statistics were gathered a long time back, unfortunately i dont have access to gather new statistics(prod). I am sure that not having statistics is very dangerous but i could not collect them as i dont have access. So can I use dynamic_sampling here?

Kindly suggest if you notice something


SELECT /*+ dynamic_sampling(a 5) */
COUNT(1)
AS p_type_3
FROM cris.stp a, cris.acc b
WHERE a.stp_sit_id = 'TE'
AND b.acc_sit_id = 'TE'
AND a.stp_sit_id = acc_sit_id
AND b.ACC_ID='100973369225'
AND CASE WHEN LENGTH (a.stp_orig_safe_acc) = 12 THEN a.stp_orig_safe_acc ELSE a.stp_new_safe_acc END = b.acc_id
AND a.stp_function = 'NEWM'
AND a.stp_bic_send NOT LIKE 'XXXXX%'
AND LENGTH
(CASE
WHEN LENGTH (a.stp_orig_safe_acc) = 12
THEN a.stp_orig_safe_acc
ELSE a.stp_new_safe_acc
END
) = 12
AND b.acc_status != 'C'
AND SUBSTR (b.acc_serv_officer_key, 4, 1) != '0'
AND a.stp_send_ts BETWEEN TO_DATE ('01122008' || '00:00:00',
'ddmmyyyy HH24:MI:SS'
)
AND TO_DATE ('31122008' || '23:59:59',
'ddmmyyyy HH24:MI:SS'
)
AND a.stp_db_tkt_code <> 'XE';



PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------

------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 71 | 27 |
| 1 | SORT AGGREGATE | | 1 | 71 | |
|* 2 | FILTER | | | | |
| 3 | NESTED LOOPS | | 1 | 71 | 27 |
|* 4 | TABLE ACCESS BY INDEX ROWID| ACC | 1 | 19 | 2 |
|* 5 | INDEX UNIQUE SCAN | ACC_PK | 1 | | 2 |
|* 6 | TABLE ACCESS BY INDEX ROWID| STP | 1 | 52 | 25 |
|* 7 | INDEX RANGE SCAN | STP_IND01 | 698K| | 5 |
------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter(TO_DATE('0112200800:00:00','ddmmyyyy
HH24:MI:SS')<=TO_DATE('3112200823:59:59','ddmmyyyy HH24:MI:SS'))
4 - filter("B"."ACC_STATUS"<>'C' AND
SUBSTR("B"."ACC_SERV_OFFICER_KEY",4,1)<>'0')

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------
5 - access("B"."ACC_ID"='100973369225' AND "B"."ACC_SIT_ID"='TE')
6 - filter(CASE LENGTH("A"."STP_ORIG_SAFE_ACC") WHEN 12 THEN
"A"."STP_ORIG_SAFE_ACC" ELSE "A"."STP_NEW_SAFE_ACC" END ='10097336
9225' AND

LENGTH(CASE LENGTH("A"."STP_ORIG_SAFE_ACC") WHEN 12 THEN
"A"."STP_ORIG_SAFE_ACC" ELSE "A"."STP_NEW_SAFE_ACC" END )=12 AND
"A"."STP_SEND_TS">=TO_DATE('0112200800:00:00','ddmmyyyy HH24:MI:SS
') AND

"A"."STP_SEND_TS"<=TO_DATE('3112200823:59:59','ddmmyyyy HH24:MI:SS
') AND

"A"."STP_DB_TKT_CODE"<>'XE')
7 - access("A"."STP_SIT_ID"="B"."ACC_SIT_ID" AND "A"."STP_FUNCTION"='NEWM')
filter("A"."STP_SIT_ID"='TE' AND "A"."STP_BIC_SEND" NOT LIKE 'XXXXX%')

Note: cpu costing is off

33 rows selected.

Could you also clarify this?
If i don't have statistics on a table but know the access path of a statement based on that table and i hinted the path, then will be running fine? or oracle must have statistics all the time?

Thank you very much for your time.


Tom Kyte
January 19, 2009 - 9:24 pm UTC

dynamic sampling cannot be used as a way to force us to gather statistics if they already exist.

this:
https://www.oracle.com/technetwork/issue-archive/2009/09-jan/o19asktom-086775.html
describes dynamic sampling. If you have statistics that are "bad", we'll use them by design. We assume they are "good"

You can use level 5 in your query, whether it will change *a thing* is not know. Compare plans with and without level 5 and you can then answer the question.


... If i don't have statistics on a table but know the access path of a statement
based on that table and i hinted the path, then will be running fine? or oracle
must have statistics all the time?
...

are you that smart? I'm not, I don't know what new feature they'll add next month to the database - you must though, because you know how to hint to get it.

why would you program the optimizer like that?

Regular Expressions Rule!!!

Vinny, January 19, 2009 - 5:32 pm UTC

I solved the Date matching problem (where I needed to match many variations of a date) using the REGEXP_INSTR function and it is so much more efficient compared to the multiple OR clauses in my original solution.

--Original solution

For X in(select D,E,F from sometable) loop
SELECT A, B, C FROM TABLEA INTO ...
WHERE
D = <X.D> AND
E = <X.E> AND
(F = <X.F> OR TO_CHAR(F,'YYYYMM') = TO_CHAR(X.F,'YYYYMM') OR TO_CHAR(F,'YYYYDD') =
TO_CHAR(X.F,'YYYYDD')OR TO_CHAR(F,'MMDD') = TO_CHAR(X.F,'MMDD'))
do something...
END LOOP;

--New solution using REGEXP_INSTR

For X in(select D,E,TO_CHAR(F,'YYYYMMDD') F_YYYYMMDD, TO_CHAR(F,'YYYYMM') F_YYYYMM, TO_CHAR(F,'YYYYDD') F_YYYYDD, TO_CHAR(F,'MMDD') F_MMDD from sometable) loop
SELECT A, B, C FROM TABLEA INTO ...
WHERE
D = <X.D> AND
E = <X.E> AND
REGEXP_INSTR (X.F_YYYYMMDD||X.F_YYYYMM||X.F_YYYYDD||X.F_MMDD, F_YYYYMMDD||'|'||F_YYYYMM||'|'||F_YYYYDD||'|'||F_MMDD) > 0;
do something...
END LOOP;

I am basically creating a string with all the date variations (YYYYMMDD, YYYYMM, YYYYDD, and MMDD) and am using REGEXP_INSTR to match one of those variations.

As Tom says Analytics rock and roll and so do regular expressions :-)




dynamic_sampling

A Reader, January 21, 2009 - 1:15 am UTC

Hi Tam,
This is regarding dynamic sampling question which i asked two days before. I have read your article on which actually dynamic_sampling is used and how to use. It is really a brilliant article ..
thank you very much for your reply...

----------
are you that smart? I'm not, I don't know what new feature they'll add next month to the database - you must though, because you know how to hint to get it...
----------

hmm.. i am definitely NOT.. no comparison also .. but i should have framed my words properly.. I wanted to ask "If I have a query which joins two tables and I don't have statistics on both the tables , then if I force the access path( I meant by using hints, after analyzing the data ) will my query work for me better?"

Problem is that I don't have access to gather stats on production.. if I have to do that i need to go through a change request and a big process .. i have a small query using two tables only..both the tables were analyzed a long time back..don't know what to do actually .. then i thought I would use dynamic sampling..but anyhow that not useful ..

Could you also clarify this "Can I entirely base the reason for bad performance on stale stats (in my case )?"

Thank you very much for your time


Tom Kyte
January 21, 2009 - 12:15 pm UTC

You will get a constant plan (probably). It will never take advantage of new features.

The real solution here is to have valid statistics in place, since the only optimizer in town is the cost based one and it relies on statistics, I cannot imagine the dba's wouldn't have them.

the problem with your hints - will that be the right plan six months from now? what if you had hinted when the stats were first gathered - the plan for those tables when small must be different from now - so the hints you used back then are not correct today.

I cannot clarify that last bit, I'm not sure what it refers to.


sorry misspelled your name in the above post !!!!!!!!!!!!!!!!!!!

A Reader, January 21, 2009 - 1:17 am UTC


Why cost is differing hugely? -- kindly help (urgent)

A Reader, January 22, 2009 - 1:56 am UTC

Hi Tom,
Thank you very much for your help in clarifying the things about cost and dynamic sampling. After some struggle i finally got a replica environment of prod and took access and gathered statistics on the tables which I am using. It made hade a HUGE difference in the executing time after gathering stats. Queries are just as fast they could be (for me).. but I am stuck at one another query. Here I have a join on tra_acc_id column for which I am passing constant values. If i pass '1009733718' to this column in the join query is very quick but if I pass '100973371800'
(appending 00 at the end) query hangs. Dont know what is happening actually. Kindly suggest.

This is the exact statement I used to gather stats.

BEGIN
DBMS_STATS.GATHER_TABLE_STATS(OWNNAME=>USER,TABNAME=>'TRA',METHOD_OPT=>'FOR ALL INDEXED COLUMNS', DEGREE=>4,CASCADE=>TRUE);
END;

This is the index
CREATE INDEX TRA_NU11 ON TRA (TRA_SIT_ID, TRA_ACC_ID, TRA_ACT_VALUE_DAT)

Here are the two statement and explain plan


SET PAGES 1000
SET LINES 1000
EXPLAIN PLAN FOR
SELECT tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind,
tra_text_block, tra_swr_trans_proc, tra_trt_trans_type
FROM cris.TRA
WHERE 1=1
AND tra_sit_id = 'TE'
AND tra_acc_id ='1009733718'
AND tra_entry_dat BETWEEN TO_DATE ('01112008' || '00:00:00',
'ddmmyyyy HH24:MI:SS'
)
AND TO_DATE ('30112008' || '23:59:59',
'ddmmyyyy HH24:MI:SS'
);
Explain complete.

SELECT * FROM TABLE (DBMS_XPLAN.DISPLAY);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1436049237

----------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
----------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 391 | 17204 | 3143 (1)| 00:00:35 | | |
|* 1 | FILTER | | | | | | | |
|* 2 | TABLE ACCESS BY GLOBAL INDEX ROWID| TRA | 391 | 17204 | 3143 (1)| 00:00:35 | ROWID | ROWID |
|* 3 | INDEX RANGE SCAN | TRA_NU02 | 10333 | | 58 (0)| 00:00:01 | | |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter(TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS')<=TO_DATE('3011200823:59:59','ddmmyyyy
HH24:MI:SS'))
2 - filter("TRA_ENTRY_DAT">=TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS') AND
"TRA_ENTRY_DAT"<=TO_DATE('3011200823:59:59','ddmmyyyy HH24:MI:SS'))
3 - access("TRA_SIT_ID"='TE' AND "TRA_ACC_ID"='1009733718')

19 rows selected.

EXPLAIN PLAN FOR
SELECT tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind,
tra_text_block, tra_swr_trans_proc, tra_trt_trans_type
FROM cris.TRA
WHERE 1=1
AND tra_sit_id = 'TE'
AND tra_acc_id ='100973371800'
AND tra_entry_dat BETWEEN TO_DATE ('01112008' || '00:00:00',
'ddmmyyyy HH24:MI:SS'
)
AND TO_DATE ('30112008' || '23:59:59',
'ddmmyyyy HH24:MI:SS'
);

Explain complete.
SELECT * FROM TABLE (DBMS_XPLAN.DISPLAY);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 843326483

-------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop | TQ |IN-OUT| PQ Distrib |
-------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 42361 | 1820K| 249K (1)| 00:45:50 | | | | | |
|* 1 | PX COORDINATOR | | | | | | | | | | |
| 2 | PX SEND QC (RANDOM) | :TQ10000 | 42361 | 1820K| 249K (1)| 00:45:50 | | | Q1,00 | P->S | QC (RAND) |
|* 3 | FILTER | | | | | | | | Q1,00 | PCWC | |
| 4 | PX BLOCK ITERATOR | | 42361 | 1820K| 249K (1)| 00:45:50 | 1 | 1 | Q1,00 | PCWC | |
|* 5 | TABLE ACCESS FULL| TRA | 42361 | 1820K| 249K (1)| 00:45:50 | | | Q1,00 | PCWP | |
-------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter(TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS')<=TO_DATE('3011200823:59:59','ddmmyyyy HH24:MI:SS'))
3 - filter(TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS')<=TO_DATE('3011200823:59:59','ddmmyyyy HH24:MI:SS'))
5 - filter("TRA_ACC_ID"='100973371800' AND "TRA_SIT_ID"='TE' AND
"TRA_ENTRY_DAT">=TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS') AND
"TRA_ENTRY_DAT"<=TO_DATE('3011200823:59:59','ddmmyyyy HH24:MI:SS'))

21 rows selected.


I am sorry I could not get the right format. Thank you for your time



Tom Kyte
January 22, 2009 - 9:00 am UTC

why couldn't you get the right format? Just use the code button to enclose the fixed width text in code tags....

Anyway, see the estimate cardinalities?

|* 2 |  TABLE ACCESS BY GLOBAL INDEX ROWID| TRA    |  391 | 17204 | 3143  (1)| 
|* 3 |  INDEX RANGE SCAN          | TRA_NU02 | 10333 |    |  58  (0)| 00:00:01 
   
|* 5 |    TABLE ACCESS FULL| TRA    | 42361 | 1820K|  249K (1)| 



one where clause is estimated to return 10,333 rows from the index, reduced to 391 rows when you get to the table.

the other where clause is estimated to return 42,361


One query is estimated to return 391 rows, the other 42,361. That is the reason for the different plans - and it isn't that the query never returns, the query is NOT HANGING - it is not. It is estimated to take 45 minutes to complete.

Now, question for you, why is the index on those three columns - why isn't tra_entry_dat the third column in that index. That would make the first query incredibly fast (instead of 10,333 table access by index rowids to find 391 hits, we would only do 391 table access by index rowids - the index would be able to answer the where clause much better)

And it might make the index more appealing for the second query - for what I think is the optimizer is thinking:

if I use the index, I'll find over 1,000,000 matches in the index and will have to do 1,000,000 single block IO's against the table in order to find 43,000 stinking records. Instead of doing over a 1,000,000 IO's using single block IO against the table - I'll just full scan it.


Do you see that your index in case 1 found 10k records, but when we go to the table - we only really find 391 that match the full predicate. Using extrapolation - if we multiply 43k by 26 times (10k/391) - we can guess that is what is happening.

The optimizer is making the right choice given those numbers.

Did you make the right index choice though?

Why cost is differing hugely? -- kindly help (urgent)

A Reader, January 22, 2009 - 11:17 am UTC

Hi Tom,
Thank you very much for the reply!. Yes, I did not notice that, i thought it hung.
I just counted the number of rows from the second query
SELECT COUNT(1) FROM
(
 SELECT tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind, tra_text_block,
                tra_swr_trans_proc, tra_trt_trans_type
           FROM TRA
          WHERE tra_sit_id = 'TE'
            AND tra_acc_id = '100973371800'
            AND tra_entry_dat BETWEEN TO_DATE ('01112008' || '00:00:00',
                                                'ddmmyyyy HH24:MI:SS'
                                               )
                                   AND TO_DATE ('30112008' || '23:59:59',
                                                'ddmmyyyy HH24:MI:SS'
                                               )
)

  COUNT(1)
----------
     75037
But the optimizer estimated it as 42361, do I have to look at stats?

Actaully i didnot create that index, but just listed because the plan referred it. Now I created index on the three columns referred, like 
CREATE INDEX CRIS.TRA_NU13 ON CRIS.TRA ( TRA_SIT_ID,TRA_ACC_ID,tra_entry_dat) tablespace indx nologging;

Now the plans are much better.
<code>
EXPLAIN PLAN FOR
SELECT   tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind,
             tra_text_block, tra_swr_trans_proc, tra_trt_trans_type
             FROM cris.TRA
    WHERE 1=1
    AND tra_sit_id = 'TE'
    AND tra_acc_id ='1009733718'
    AND tra_entry_dat BETWEEN TO_DATE ('01112008' || '00:00:00',
                                                'ddmmyyyy HH24:MI:SS'
                                               )
                                   AND TO_DATE ('30112008' || '23:59:59',
                                                'ddmmyyyy HH24:MI:SS'
                                               );

----------------------------------------------------------------------------------------------------------------                                      
| Id  | Operation                           | Name     | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |                                      
----------------------------------------------------------------------------------------------------------------                                      
|   0 | SELECT STATEMENT                    |          |   391 | 17204 |   118   (0)| 00:00:02 |       |       |                                      
|*  1 |  FILTER                             |          |       |       |            |          |       |       |                                      
|   2 |   TABLE ACCESS BY GLOBAL INDEX ROWID| TRA      |   391 | 17204 |   118   (0)| 00:00:02 | ROWID | ROWID |                                      
|*  3 |    INDEX RANGE SCAN                 | TRA_NU13 |   391 |       |     4   (0)| 00:00:01 |       |       |                                      
----------------------------------------------------------------------------------------------------------------      
EXPLAIN PLAN FOR
SELECT   tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind,
             tra_text_block, tra_swr_trans_proc, tra_trt_trans_type
             FROM cris.TRA
    WHERE 1=1
    AND tra_sit_id = 'TE'
    AND tra_acc_id ='100973371800'
    AND tra_entry_dat BETWEEN TO_DATE ('01112008' || '00:00:00',
                                                'ddmmyyyy HH24:MI:SS'
                                               )
                                   AND TO_DATE ('30112008' || '23:59:59',
                                                'ddmmyyyy HH24:MI:SS'
                                               );

Explain complete.

SELECT * FROM TABLE (DBMS_XPLAN.DISPLAY);
Explain complete.

PLAN_TABLE_OUTPUT                                                                                                       
------------------------------------------------------------------------------------------------------------------------
Plan hash value: 2032403238                                                                                             
                                                                                                                        
----------------------------------------------------------------------------------------------------------------        
| Id  | Operation                           | Name     | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |        
----------------------------------------------------------------------------------------------------------------        
|   0 | SELECT STATEMENT                    |          | 42361 |  1820K| 12543   (1)| 00:02:18 |       |       |        
|*  1 |  FILTER                             |          |       |       |            |          |       |       |        
|   2 |   TABLE ACCESS BY GLOBAL INDEX ROWID| TRA      | 42361 |  1820K| 12543   (1)| 00:02:18 | ROWID | ROWID |        
|*  3 |    INDEX RANGE SCAN                 | TRA_NU13 | 42361 |       |   236   (0)| 00:00:03 |       |       |        
----------------------------------------------------------------------------------------------------------------        
19 rows selected.

But here optimizer says it will take 2 Min 18 Sec, but the query actually taking lot more time than that,taking nearly 60 Minutes. Again stats problem?, I really dont know.I just could not proceed futher, could you please tell me what else I could look at? I dont know if I have to satisfy with that 60 minutes. 

TRA is table is the transactions table in my database which has 35635100 rows, and partitioned on a columns TRA_CRE_TS (Range) and Subpartitioned on TRA_SIT_ID(hash) but I noticed that there is only one subpartition for all the TRA_SIT_ID values under one partitions. 
I think this subpartition is not usefull as everything is dumped again into single subpartition(correct??).I even noticed that TRA_CRE_TS column(main partition column) is not joined(atleast 98% queries dont join this column) in many queries at all. Will it be of some help if I change the partition mechanism to partition by TRA_SIT_ID (no composite) and create all Local Indexes(TRA_SIT_ID is part of primary key). Could you please tell me whether it will be helpful in this query?

If not changing parition mechanism, what else I could look at. Thank you very much for your valuable suggestions. I observed in my production that ALL queries (almost all) which run slowly, are joined on this table. Could you please advice?

Thank you for your time




Tom Kyte
January 22, 2009 - 11:40 am UTC

... COUNT(1)
----------
75037
But the optimizer estimated it as 42361, do I have to look at stats?
....

you counted the wrong stuff.

that is coming from the index:

WHERE tra_sit_id = 'TE'
AND tra_acc_id = '100973371800'

the date predicate comes later. So, it looks like it did under-estimate that, but no harm.


...But here optimizer says it will take 2 Min 18 Sec, but the query actually
taking lot more time than that,taking nearly 60 Minutes. Again stats problem?, ...

no, remember - these are all ESTIMATES. Run a tkprof, see what you are waiting on. Probably, you are doing a ton of physical IO and that takes time.

Why cost is differing hugely? -- kindly help (urgent)

A Reader, January 22, 2009 - 1:35 pm UTC

Hi Tom,
Thanks for the suggestion. I will try to get the tkprof for this. I am actually only one user on the entire server(as this is a replica of prod, and users not started testing on this), I thought server may not be the issue, anyhow I will pull the tkprof as you suggested.
-------
you counted the wrong stuff.

that is coming from the index:

WHERE tra_sit_id = 'TE'
AND tra_acc_id = '100973371800'

the date predicate comes later. So, it looks like it did under-estimate that,
--------

I could not understand that,could you please clarify? I actually counted after creating new index?

Any comments on my change in partition mechanism approach? ( I forgot to tell you that sit_id='TE' is occupying nearly 80% of total rows)


Thank you very much for your time


Tom Kyte
January 22, 2009 - 3:46 pm UTC

reader - everything is "urgent", it is generally a bad practice to label things "urgent" as if your problem/question is more relevant than others....


Your index is on tra_sit_id,tra_acc_id,something_else

the optimizer guess the index would return 10,333 rows from the index range scan (step 3) and step 3's predicate is right there for you


----------------------------------------------------------------------------------------------------------------                                                                                                                           
| Id | Operation                  | Name  | Rows | Bytes | Cost (%CPU)| Time  | Pstart| Pstop |                                                                                                                           
----------------------------------------------------------------------------------------------------------------                                                                                                                           
|  0 | SELECT STATEMENT                  |      |  391 |
|* 1 | FILTER                 
|* 2 |  TABLE ACCESS BY GLOBAL INDEX ROWID| TRA      |   391 |
|* 3 |  INDEX RANGE SCAN                  | TRA_NU02 | 10333 |                                                              
----------------------------------------------------------------------------------------------------------------                                                                                                                           
                                                                                                                                                                                                       
Predicate Information (identified by operation id):                                                                                                                                                                     
---------------------------------------------------                                                                                                                                                                     
                                                                                                                                                                                                       
  1 - filter(TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS')<=TO_DATE('3011200823:59:59','ddmmyyyy                                                                                                                                   
        HH24:MI:SS'))                                                                                                                                                                                     
  2 - filter("TRA_ENTRY_DAT">=TO_DATE('0111200800:00:00','ddmmyyyy HH24:MI:SS') AND                                                                                                                                               
        "TRA_ENTRY_DAT"<=TO_DATE('3011200823:59:59','ddmmyyyy HH24:MI:SS'))                                                                                                                                                 
  3 - access("TRA_SIT_ID"='TE' AND "TRA_ACC_ID"='1009733718')       



I did not follow your partition information, I didn't understand what you were trying to say

Why cost is differing hugely?

A Reader, January 22, 2009 - 9:02 pm UTC

Sorry, I will not name the post with "Urgent" next time. As it is production issue i was in a hurry to get some solution. thank you

Why cost is differing hugely .. some difference

A Reader, January 23, 2009 - 1:59 am UTC

Hi Tom,
Surprisingly my process, procedure,(not the query) is incredibly fast now. In my process i have cursor defined on the query and have further processing.

When I run the query outside(bare select statement, without placing in subprogram) it is actually talking over 60 min, but when I execute the procedure (which has same cursor) it is just as quick as it could be , 5 seconds

I have procedure like ..

DECLARE
CURSOR transaction_cursor
IS
SELECT tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind, tra_text_block,
tra_swr_trans_proc, tra_trt_trans_type
FROM tra
WHERE tra_sit_id = p_sit_id
AND tra_acc_id = p_acc_id
AND tra_entry_dat BETWEEN TO_DATE (p_fromdate || '00:00:00',
'ddmmyyyy HH24:MI:SS'
)
AND TO_DATE (p_todate || '23:59:59',
'ddmmyyyy HH24:MI:SS'
);
..other declarations ...
BEGIN
Open cursor ..
.. PROCESSING
End cursor..
..END;

I have execute with the same parameters
p_fromdate varchar2(100):='01112008';
p_TODATE varchar2(100):='30112008';
p_acc_id VARCHAR2(20) :='100973371800';
P_SIT_ID VARCHAR2(2):='TE';

it is executed in just 5 Seconds.

But when I run query outside as

SELECT tra_acc_id, tra_db_tkt_code, tra_swr_stp_ind, tra_text_block,
tra_swr_trans_proc, tra_trt_trans_type
FROM tra
WHERE tra_sit_id = 'TE'
AND tra_acc_id = '100973371800'
AND tra_entry_dat BETWEEN TO_DATE ('01112008' || '00:00:00',
'ddmmyyyy HH24:MI:SS'
)
AND TO_DATE ('30112008' || '23:59:59',
'ddmmyyyy HH24:MI:SS'
);

this is taking over 60 Minutes.

Sir, I am totally confused now. I have been always thinking that I should tune the individual queries outside before placing them into the subprogram, and under that impression i am struggling to execute this query outside, and doomed.

Could you please tell me what is happening inside the procedure, why it running so fast and outside it so slow?

Thank you very much for your suggestions.

Tom Kyte
January 23, 2009 - 8:51 am UTC

it will totally depend on what values you bind with the first time.
http://www.google.com/search?q=site%3Atkyte.blogspot.com+bind+peeking

SQL Tuning

Prasad, March 22, 2009 - 10:56 pm UTC

Hello Tom,
The following SQL taking 1 hour 10 minutes. Basically we are trying to see if the same address is defined in two different tables. I am trying to tune this query. I would really appreciate your help.


SELECT DISTINCT pa.address_line1, pa.address_line2, pa.address_line3,
pa.town_or_city, pa.region_2, pa.postal_code, pa.person_id,
papf.current_employee_flag, avs.vendor_site_code,
avs.vendor_id, avs.address_line1, avs.address_line2,
avs.address_line3, avs.address_line4, avs.city, avs.state,
avs.zip, avs.pay_group_lookup_code, pv.vendor_name
FROM per_addresses pa,
per_all_people_f papf,
apps.ap_vendor_sites_v avs, -- apps.ap_vendor_sites_v avs,
po_vendors pv
WHERE papf.current_employee_flag = 'Y'
AND avs.inactive_date IS NULL
AND avs.pay_group_lookup_code NOT LIKE 'EMPLOYEES'
AND pa.address_line1 LIKE avs.address_line1||'%'
AND papf.person_id = pa.person_id
AND pv.vendor_id = avs.vendor_id;
Tom Kyte
March 24, 2009 - 11:13 am UTC

please verify your joins

do that by explaining in english the relationships between the tables and how the joins satisfy those relations (I question the joins here, a quick glance - they don't look right)


(papf+pa) are joined

(pv+avs) are joined

and then they are cartesian joined and we keep only the rows where the pa.address is "like" the avs.address...

SQL Tuning

Prasad, March 24, 2009 - 2:07 pm UTC

Hello Tom, Thank you very much for your time and appreciate your help
Join1> (papf+pa) are joined
Join2> (pv+avs) are joined
Join3> PA.address_line1 and AVS.address_line1 (where address line1 matches in the both PA and AVS tables)

There is no join between 1 and 2 but we are only interested on the records what ever join 3 matches.

I have created indexes on the address line on the both the columns in join3 still the result is same. Also tried parallel hint but same result.

Also to remove another expensive ¿AND PAY_GROUP_DISP NOT LIKE 'EMPLOYEES'" I have added exists clause as follows (it reduced cost by 3000 but execution time is still same)

All my attempts are ineffective I guess it¿s because we are using like operator and its doing full table scan. Please help me out.

SQL with Exists clause:
SELECT DISTINCT pa.address_line1, pa.address_line2, pa.address_line3,
pa.town_or_city, pa.region_2, pa.postal_code, pa.person_id,
papf.current_employee_flag, avs.vendor_site_code,
avs.vendor_id, avs.address_line1, avs.address_line2,
avs.address_line3, avs.address_line4, avs.city, avs.state,
avs.zip, avs.pay_group_disp, pv.vendor_name
FROM per_addresses pa,
per_all_people_f papf,
apps.ap_vendor_sites_v avs,
po_vendors pv
WHERE papf.current_employee_flag = 'Y'
AND avs.inactive_date IS NULL
AND pa.address_line1 LIKE avs.address_line1
AND papf.person_id = pa.person_id
AND pv.vendor_id = avs.vendor_id
AND EXISTS (
SELECT 1
FROM fnd_lookup_values flv
WHERE lookup_type = 'PAY GROUP'
AND enabled_flag = 'Y'
AND flv.lookup_code <> 'EMPLOYEES'
AND flv.lookup_code = avs.pay_group_disp)





Tom Kyte
March 29, 2009 - 10:48 am UTC

... I have created indexes on the address line on the both the columns in join3
still the result is same. ...

did you close your eyes and mentally visualize how an index could even be used or useful there? I cannot see how an index would even be remotely useful.

You have what is known as a non-equi join, very very very close to a CARTESIAN join - between two large sets.

It will not be fast.


.... AND pa.address_line1 LIKE avs.address_line1 ....

???? why not equals now? that would make it faster.

To Prasad

A reader, March 24, 2009 - 2:25 pm UTC

Will this work? Not sure this is the answer but

AND instr(avs.address_line1,pa.address_line1)>0

Tom Kyte
March 29, 2009 - 10:49 am UTC

same problem.

cartesian join, lots of things to compare. not going to be fast by any definition of the word

SQL Tuning

Prasad, March 24, 2009 - 4:58 pm UTC

Dear reader, Instr gave me wrong number of records and took 10 minutes more to execute.

query

jyothsna, March 25, 2009 - 4:57 am UTC

Hi..
could you tell me the procedure to post new queries to TOM..
As i can see only write review comments......

And in the website i couldn't find any register option or post a query option...

Could you please help me in this
Tom Kyte
March 29, 2009 - 2:33 pm UTC

sorry, it is very much catch as catch can here, I take new questions when I have time.

Last week - five cities, seven flights, all flights 5pm or later to get to next city (hopefully before midnight but not always) so I could get up and do it all over again.

Sometimes I just don't have any time. There is a button this weekend showing I'm accepting new questions.

I typically take 50-100 new ones per month only and as I'm the only one answering them - it really will not increase.

jyothsna from India

jake, March 25, 2009 - 10:41 am UTC

Dude,

look in the upper right side of the asktom site. it specifically states how questions are received. Usually, you will see that Tom has a backlog and does not accept new questions.

However, be persistent as his time does free up to accept them. You have to be present when that window is opened.


Oracle Tuning Golden Rules.

Dhairyasheel Tawde., March 30, 2009 - 6:03 am UTC

Hi Tom,
In my career as an oracle dba I've observed that maximum performance problems are due to poor sql. Also the attitude of youngsters today, who are just getting into the world of oracle, is that they will approach you and the first thing they want to know about is how to do sql tuning? Their expectation is some lightning strike from the clouds which will make them masters at tuning. Hardly ever do you come across dbas & developers who want to spend time and effort studying database, the operating system, how computer hardware works, networking etc.

Some golden rules that i tell most of my colleagues to follow are

1> Find table sizes and their indexes
2> check if the where clause has columns that are available in index.
3> check that sequence of columns in where clause matches with sequence of columns in index.
4> in a join, the table with indexed column should be on right hand side of the = sign.
5>In where clause put static conditions (e.g flag=y) first and joins or complex conditions later.
6> Keep your select clause as simple as possible.
7> Remember that the bottom line of all tuning should be reducing I/O


Do let me know if my rules are wrong

Regards.
Tom Kyte
March 30, 2009 - 4:27 pm UTC

My observation is maximum performance problems are due to poorly implemented algorithms, approaches using slow by slow procedural code instead of set based operations, approaches done by people that stopped reading the SQL Language reference manual after getting an overview of select, from, where, group by and order by.

So, I think our observations are very much in line...

But your "rules", they do not hold water for me.

#1 I'd generalize to "understand your data, understand how the rows arrive into a table, so you know the data patterns. Understand your data model, know what is involved in 1-1 relations (and are they optional relations), 1-m, m-1 and so on, understand the indexing scheme"

#2 why? not always relevant and leads to you promoting the fallacy "if my query doesn't use an index, it is a bad query"


#3 is very very wrong, well, not true - just a waste of time. We don't care about the order. Even the RBO didn't care. This was never a thing to do.

#4 is just plain wrong. Never was true, never did anything.

#5 is wrong. Same as number 4.

#6 is very very very dangerously wrong. I don't want people to do slow by slow (row by row processing). "keep select simple" leads people right into "do not join, do not sort, do not filter in database - take it 'easy' on database". That is the opposite of what you want to do.

#7 is not accurate. In general I like to tune to reduce logical io, but tell me, which query is "better" below?

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create table t
ops$tkyte%ORA10GR2> as
ops$tkyte%ORA10GR2> select * from all_objects;
ops$tkyte%ORA10GR2> */
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly statistics
ops$tkyte%ORA10GR2> select * from t;

50181 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       3991  consistent gets
          0  physical reads
          0  redo size
    2540770  bytes sent via SQL*Net to client
      37195  bytes received via SQL*Net from client
       3347  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      50181  rows processed

ops$tkyte%ORA10GR2> select * from t order by object_name;

50181 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        696  consistent gets
          0  physical reads
          0  redo size
    2869583  bytes sent via SQL*Net to client
      37195  bytes received via SQL*Net from client
       3347  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      50181  rows processed

ops$tkyte%ORA10GR2> set autotrace off



I cut IO way down. Did I do a good thing by doing that?

Wonderful Insight.

Dhairyasheel Tawade., March 31, 2009 - 6:06 am UTC

HI Tom, Thanks for shedding the light on the same & clearing the misconceptions.

However In my work experience I've noticed quite a few times that changing the sequence of conditions in your where clause does cause the query to run faster. It was these experiences with 9i and 10g that lead me to form these conclusions on my own.

Also how I visualize joins is as follows.

a.id=b.id

table a is one bucket and table b is another,

you pick an id from bucket a and go searching for its match in bucket b thats why i believe b should be indexed.

is this how the CBO/RBO processes joins?
Tom Kyte
March 31, 2009 - 8:27 am UTC

... However In my work experience I've noticed quite a few times that changing the
sequence of conditions in your where clause does cause the query to run faster.
...

give us a concrete example.


Your visualization is an inaccurate portrayal of the CBO. The CBO sees "A is joined to B" - which is identical to "B is joined to A". The CBO then reviews the statistics and figures out what to do.

If the query is:

select * from a, b where a.id = b.id;

I would be very disappointed in general if the optimizer used an index - any index. I would expect the CBO to look at that query, determine "which will be smaller - A or B" (suppose A is smaller). Then it will read A and HASH it into memory (hopefully it fits, if not, that is OK, we can deal with it). Then we start reading B and doing a hash probe into the A table we just processed and find the match and return the record.

ops$tkyte%ORA10GR2> create table a as select * from all_objects where rownum <=20000;

Table created.

ops$tkyte%ORA10GR2> create table b as select * from all_objects;

Table created.

ops$tkyte%ORA10GR2> alter table a add constraint a_pk primary key(object_id);

Table altered.

ops$tkyte%ORA10GR2> alter table b add constraint b_pk primary key(object_id);

Table altered.

ops$tkyte%ORA10GR2> create index b_idx on b(owner);

Index created.

ops$tkyte%ORA10GR2> @at
ops$tkyte%ORA10GR2> column PLAN_TABLE_OUTPUT format a72 truncate
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from a, b where a.object_id = b.object_id;

Execution Plan
----------------------------------------------------------
Plan hash value: 652036164

------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes |TempSpc| Cost (%CPU)|
------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      | 20232 |  5058K|       |   831   (3)|
|*  1 |  HASH JOIN         |      | 20232 |  5058K|  2768K|   831   (3)|
|   2 |   TABLE ACCESS FULL| A    | 20232 |  2529K|       |    91   (4)|
|   3 |   TABLE ACCESS FULL| B    | 55955 |  6994K|       |   228   (4)|
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("A"."OBJECT_ID"="B"."OBJECT_ID")

Note
-----
   - dynamic sampling used for this statement


that plans says "read A, hash into memory the 20,000 rows, then read B and hash join to A - do not use any indexes, that would be a really bad idea"

Now, if we add some predicates, the entire situation changes:

ops$tkyte%ORA10GR2> select * from a, b where a.object_id = b.object_id and b.owner = 'SCOTT';

Execution Plan
----------------------------------------------------------
Plan hash value: 3705588195

------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CP
------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |    18 |  4608 |     9   (
|   1 |  NESTED LOOPS                |       |    18 |  4608 |     9   (
|   2 |   TABLE ACCESS BY INDEX ROWID| B     |    18 |  2304 |     2   (
|*  3 |    INDEX RANGE SCAN          | B_IDX |    18 |       |     1   (
|   4 |   TABLE ACCESS BY INDEX ROWID| A     |     1 |   128 |     1   (
|*  5 |    INDEX UNIQUE SCAN         | A_PK  |     1 |       |     0   (
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("B"."OWNER"='SCOTT')
   5 - access("A"."OBJECT_ID"="B"."OBJECT_ID")

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> select * from a, b where b.object_id = a.object_id and b.owner = 'SCOTT';

Execution Plan
----------------------------------------------------------
Plan hash value: 3705588195

------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CP
------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |    18 |  4608 |     9   (
|   1 |  NESTED LOOPS                |       |    18 |  4608 |     9   (
|   2 |   TABLE ACCESS BY INDEX ROWID| B     |    18 |  2304 |     2   (
|*  3 |    INDEX RANGE SCAN          | B_IDX |    18 |       |     1   (
|   4 |   TABLE ACCESS BY INDEX ROWID| A     |     1 |   128 |     1   (
|*  5 |    INDEX UNIQUE SCAN         | A_PK  |     1 |       |     0   (
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("B"."OWNER"='SCOTT')
   5 - access("B"."OBJECT_ID"="A"."OBJECT_ID")

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> select * from b, a where a.object_id = b.object_id and b.owner = 'SCOTT';

Execution Plan
----------------------------------------------------------
Plan hash value: 3705588195

------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CP
------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |    18 |  4608 |     9   (
|   1 |  NESTED LOOPS                |       |    18 |  4608 |     9   (
|   2 |   TABLE ACCESS BY INDEX ROWID| B     |    18 |  2304 |     2   (
|*  3 |    INDEX RANGE SCAN          | B_IDX |    18 |       |     1   (
|   4 |   TABLE ACCESS BY INDEX ROWID| A     |     1 |   128 |     1   (
|*  5 |    INDEX UNIQUE SCAN         | A_PK  |     1 |       |     0   (
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("B"."OWNER"='SCOTT')
   5 - access("A"."OBJECT_ID"="B"."OBJECT_ID")

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> select * from b, a where b.object_id = a.object_id and b.owner = 'SCOTT';

Execution Plan
----------------------------------------------------------
Plan hash value: 3705588195

------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CP
------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |    18 |  4608 |     9   (
|   1 |  NESTED LOOPS                |       |    18 |  4608 |     9   (
|   2 |   TABLE ACCESS BY INDEX ROWID| B     |    18 |  2304 |     2   (
|*  3 |    INDEX RANGE SCAN          | B_IDX |    18 |       |     1   (
|   4 |   TABLE ACCESS BY INDEX ROWID| A     |     1 |   128 |     1   (
|*  5 |    INDEX UNIQUE SCAN         | A_PK  |     1 |       |     0   (
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("B"."OWNER"='SCOTT')
   5 - access("B"."OBJECT_ID"="A"."OBJECT_ID")

Note
-----
   - dynamic sampling used for this statement





Notice that I wrote the where clause in every way, I put the tables in the from clause in every way - the optimizer doesn't really CARE, it looks at statistics (we got that via dynamic sampling in this example) and optimizes based on facts, not on order of things in the where clause.


No matter what way you write that query, the plan remains constant.


3-6 of your rules are wrong.
7 - is not always true

TABLE ACCESS FULL T

A reader, March 31, 2009 - 8:59 pm UTC

I tried your test case http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:8764517459743#1591516000346738591


select *
from
 t order by object_name


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          1          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      869      0.35       0.28          0        178          0       13020
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      871      0.35       0.29          0        179          0       13020

Misses in library cache during parse: 1
Optimizer mode: FIRST_ROWS
Parsing user id: 31

Rows     Row Source Operation
-------  ---------------------------------------------------
  13020  SORT ORDER BY (cr=178 pr=0 pw=0 time=153302 us)
  13020   TABLE ACCESS FULL T (cr=178 pr=0 pw=0 time=13121 us)



select *
from
 t


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.01       0.00          0          1          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      869      0.20       0.16          0       1037          0       13020
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      871      0.21       0.16          0       1038          0       13020

Misses in library cache during parse: 1
Optimizer mode: FIRST_ROWS
Parsing user id: 31

Rows     Row Source Operation
-------  ---------------------------------------------------
  13020  TABLE ACCESS FULL T (cr=1037 pr=0 pw=0 time=26149 us)


Why did the same operation "TABLE ACCESS FULL T" use different consistent gets (1037 vs 178)?
Tom Kyte
April 01, 2009 - 8:58 am UTC

It is the array fetching and the fact that the query without ORDER BY didn't need to copy the data to temp.

select * from t order by 1;

that read the entire table (hopefully into memory) and sorted it - the rows were returned from this temp sort area (and maybe from temp on disk). In any case - the most number of times a block was read from the cache was ONE, we read it, got all of the data from it and then sorted all of it.


The query

select * from t;

would get rows directly from the blocks - it would not get ALL of the rows before returning the first one, rather it would go to the cache - get block one and (using sqlplus's default array size of 15) - get the first 15 rows and return them. Now, since all objects fits about 73 or so row on an 8k block - when we ask for row 16 (we get 16-30), we re-read block 1. In fact we read block one from the cache about 5 times. We read block 2 about 5 times and so on.

If you increase the array size (that would be the correct approach to "tuning" this query by the way.. NOT order by), then we would get and re-get the blocks less often. You can see this:

ops$tkyte%ORA10GR2> /*
ops$tkyte%ORA10GR2> drop table t;
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create table t
ops$tkyte%ORA10GR2> as
ops$tkyte%ORA10GR2> select * from all_objects;
ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats(user,'T');
ops$tkyte%ORA10GR2> */
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly statistics;
ops$tkyte%ORA10GR2> set arraysize 2
ops$tkyte%ORA10GR2> select * from t;

49885 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
      25290  consistent gets
          0  physical reads
          0  redo size
    5271306  bytes sent via SQL*Net to client
     274758  bytes received via SQL*Net from client
      24944  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      49885  rows processed

ops$tkyte%ORA10GR2> set arraysize 10
ops$tkyte%ORA10GR2> select * from t;

49885 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       5620  consistent gets
          0  physical reads
          0  redo size
    2737179  bytes sent via SQL*Net to client
      55264  bytes received via SQL*Net from client
       4990  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      49885  rows processed

ops$tkyte%ORA10GR2> set arraysize 100
ops$tkyte%ORA10GR2> select * from t;

49885 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       1185  consistent gets
          0  physical reads
          0  redo size
    2166949  bytes sent via SQL*Net to client
       5874  bytes received via SQL*Net from client
        500  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
      49885  rows processed



Performance issue with name value pairs

A reader, April 01, 2009 - 5:05 pm UTC

We have 12 tables with 70 columns in each table in the following format.
All of them have got a common column called id. We have a view which joins
all these 12 tables,having approximately 800+ columns. There were performance
issues while querying the view, so we did column profiling found that for 700+
columns in these 12 tables have less than 1% of data (For most of rows the data
in these columns is null) .
So we tried to test the performance by
have two table instead of 12 tables.
1) Table TR which contains 100 columns where data present is >1%.
2) Table TC Contains 3 Columns Id, Column_name,value
-- (Basically name value pairs)

After creating those two tables and loading the data.
we created a view pre_vw which is select id,max(case
when column_name='T0C1'
THEN VALUE END) AS T0C1,
max(case
when column_name='T0C2'
THEN VALUE END) AS T0C2..... T1270
FROM TC GROUP BY ID

This view was performing very bady. Because it has to do max/case evaluation
for almost 700 columns. Is there any other better alternatives?


TABLE_NAME COLUMN_NAME
T0 T0C1
T0 T0C2
T0 T0C3
T0 T0C4
T0 T0C5
..
T0 T0C69

T1 T1C1
T1 T1C2
T1 T1C3
T1 T1C4
T1 T1C5
..
T1 T1C69
.. ..
.. ..
T11 T11C1
T11 T11C2
T11 T11C3
T11 T11C4
T11 T11C5
T11 T11C6

Tom Kyte
April 02, 2009 - 9:13 am UTC

how about one table?

What is going on here?

A reader, April 02, 2009 - 5:42 am UTC

Hi Tom,

We have two fact tables with same number of rows. One fact table joins to a dim table and another with different dim table. The number of rows are same in all tables. The reason for this is do some logic tests.
But it has come to surprise that in one join Oracle used BITMAP CONVERSION TO ROWIDS which comes out in 38 secs, and other without BITMAP CONVERSION TO ROWIDS takes 7 secs. I did explain plan, and found this difference. The bitmap indexes on both fact tables are same, and gather stats was done in same way for all tables. We are using 10gR1.
What could be the reason?
- Query below takes around 38 secs
select count(1)
from FACT_TEST fct
inner join mth_dim mth on fct.mth_key = mth.mth_key
inner join UNIT_DIM org on fct.unit_key = org.unit_key

xecution Plan
---------------------------------------------------------

---------------------------------------------------------------------------------------------------
Id | Operation | Name | Rows | Bytes |TempSpc| Cos
---------------------------------------------------------------------------------------------------
0 | SELECT STATEMENT | | 1 | 16 | | 337
1 | SORT AGGREGATE | | 1 | 16 | |
2 | HASH JOIN | | 8500K| 129M| 6280K| 337
3 | MERGE JOIN CARTESIAN | | 321K| 2509K| | 1
4 | INDEX FULL SCAN | XPKMONTH_DIM | 12 | 36 | |
5 | BUFFER SORT | | 26769 | 130K| | 1
6 | INDEX FAST FULL SCAN | XPKFINANCE_ORG_UNIT_DIM | 26769 | 130K| |
7 | VIEW | index$_join$_001 | 8500K| 64M| | 244
8 | HASH JOIN | | | | |
9 | PARTITION RANGE ALL | | 8500K| 64M| | 2
10 | BITMAP CONVERSION TO ROWIDS| | 8500K| 64M| | 2
11 | BITMAP INDEX FULL SCAN | FACT_MTH_KEY | | | |
12 | PARTITION RANGE ALL | | 8500K| 64M| | 18
13 | BITMAP CONVERSION TO ROWIDS| | 8500K| 64M| | 18
14 | BITMAP INDEX FULL SCAN | ORG_UNIT_KEY | | | |
---------------------------------------------------------------------------------------------------

-- Query below takes around 7 secs.
select count(1)
from FACT fct
inner join mth_dim mth on fct.mth_key = mth.mth_key
inner join UNIT_BRIDGE orb on UNIT_BRIDGE_KEY = ORB.ORG_UNIT_BKEY

Execution Plan
----------------------------------------------------------

----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%C
----------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 16 | | 32466
| 1 | SORT AGGREGATE | | 1 | 16 | |
| 2 | HASH JOIN | | 8500K| 129M| 6280K| 32466
| 3 | MERGE JOIN CARTESIAN | | 321K| 2509K| | 113
| 4 | INDEX FULL SCAN | XPKMONTH_DIM | 12 | 36 | | 1
| 5 | BUFFER SORT | | 26770 | 130K| | 112
| 6 | INDEX FAST FULL SCAN| XPKFINANCE_ORGANISATION_UNIT_B | 26770 | 130K| | 9
| 7 | PARTITION RANGE ALL | | 8500K| 64M| | 23177
| 8 | TABLE ACCESS FULL | FACT | 8500K| 64M| | 23177
----------------------------------------------------------------------------------------------------

PS: The explain plan was done multiple times to eliminate the possibility of an impact of varying system load.
Tom Kyte
April 02, 2009 - 10:15 am UTC

... PS: The explain plan was done multiple times to eliminate the possibility of an impact of varying system load. ...

that isn't useful. the system load won't affect explain plan.

the queries are not touching the same data? (and I cannot read your plans at all, use the CODE button).


describe why you think these two queries should use the same plan, describe how fact_test and fact are "the same".

query with CONCATENATION

Yan, April 08, 2009 - 4:40 pm UTC

Hey Tom:

I have a query as following:

select tx.*
from conferenceparticipant tp, conference tx
where
(tx.id = tp.conference
and ( tx.id in (3491917) or upper(conferenceReference) in ('3491917'));

--------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 465 | 6370 (2)| 00:01:17 |
| 1 | CONCATENATION | | | | | |
| 2 | NESTED LOOPS | | 3 | 279 | 6364 (2)| 00:01:17 |
|* 3 | TABLE ACCESS FULL | CONFERENCEPARTICIPANT | 3 | 33 | 6358 (2)| 00:01:17 |
| 4 | TABLE ACCESS BY INDEX ROWID| CONFERENCE | 1 | 82 | 2 (0)| 00:00:01 |
|* 5 | INDEX UNIQUE SCAN | PK_CONFERENCE | 1 | | 1 (0)| 00:00:01 |
| 6 | NESTED LOOPS | | 2 | 186 | 6 (0)| 00:00:01 |
| 7 | TABLE ACCESS BY INDEX ROWID| CONFERENCE | 1 | 82 | 3 (0)| 00:00:01 |
|* 8 | INDEX UNIQUE SCAN | PK_CONFERENCE | 1 | | 2 (0)| 00:00:01 |
|* 9 | TABLE ACCESS BY INDEX ROWID| CONFERENCEPARTICIPANT | 2 | 22 | 3 (0)| 00:00:01 |
|* 10 | INDEX RANGE SCAN | TX_PARTICIPANT$CONFERENCEID | 2 | | 2 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

3 - filter(UPPER("CONFERENCEREFERENCE")='3491917')
5 - access("TX"."ID"="TP"."CONFERENCE")
8 - access("TX"."ID"=3491917)
9 - filter(LNNVL(UPPER("CONFERENCEREFERENCE")='3491917'))
10 - access("TX"."ID"="TP"."CONFERENCE")


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
27669 consistent gets
27601 physical reads
0 redo size
1171 bytes sent via SQL*Net to client
400 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed

>>>>>>>>I have a index TP_REF_CONFERENCE_FUNCB for (upper(conferencereference, conference)) in the CONFERENCEPARTICIPANT table. I suppose this index will be automatically picked up. But the fact is even I put hint in there, the index won't be used.

if I modify the query like this:

select tx.*
from conferenceparticipant tp, conference tx
where
tx.id = tp.conference
and tx.id in (3491917)
union
select tx.*
from conferenceparticipant tp, conference tx
where
tx.id = tp.conference and
upper(conferenceReference) in ('3491917');


---------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 455 | 16 (69)| 00:00:01 |
| 1 | SORT UNIQUE | | 5 | 455 | 16 (69)| 00:00:01 |
| 2 | UNION-ALL | | | | | |
| 3 | NESTED LOOPS | | 2 | 176 | 5 (0)| 00:00:01 |
| 4 | TABLE ACCESS BY INDEX ROWID| CONFERENCE | 1 | 82 | 3 (0)| 00:00:01 |
|* 5 | INDEX UNIQUE SCAN | PK_CONFERENCE | 1 | | 2 (0)| 00:00:01 |
|* 6 | INDEX RANGE SCAN | TX_PARTICIPANT$CONFERENCEID | 2 | 12 | 2 (0)| 00:00:01 |
| 7 | NESTED LOOPS | | 3 | 279 | 9 (0)| 00:00:01 |
|* 8 | INDEX RANGE SCAN | TP_REF_CONFERENCE_FUNCB | 3 | 33 | 3 (0)| 00:00:01 |
| 9 | TABLE ACCESS BY INDEX ROWID| CONFERENCE | 1 | 82 | 2 (0)| 00:00:01 |
|* 10 | INDEX UNIQUE SCAN | PK_CONFERENCE | 1 | | 1 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

5 - access("TX"."ID"=3491917)
6 - access("TP"."CONFERENCE"=3491917)
8 - access(UPPER("CONFERENCEREFERENCE")='3491917')
10 - access("TX"."ID"="TP"."CONFERENCE")


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
10 consistent gets
0 physical reads
0 redo size
1171 bytes sent via SQL*Net to client
400 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
1 sorts (memory)
0 sorts (disk)
1 rows processed


So I think the full table scan on CONFERENCEPARTICIPANT is caused by the CONCATENATION, am I correct? and how can make the CBO pick up that functional based index without changing the query?

Thank you so much!!
Tom Kyte
April 13, 2009 - 3:29 pm UTC

that looks like a missed path by the optimizer

Here is a concise test case you can use with support to demonstrate the issue and show that the index *could* be used (that was the purpose of me adding the 'regular' index without upper - the index could have been used but wasn't...)



ops$tkyte%ORA10GR2> create table conferenceparticipant ( conference number, CONFERENCEREFERENCE varchar2(20) not null, data char(80) );

Table created.

ops$tkyte%ORA10GR2> create table conference( id number primary key, data char(80) );

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> insert into conferenceparticipant
  2  select level, level+3300000, level
  3    from dual
  4  connect by level <= 100000;

100000 rows created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> insert into conference
  2  select level, level
  3    from dual
  4  connect by level <= 100000;

100000 rows created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index tp_upper_idx on conferenceparticipant (upper(CONFERENCEREFERENCE));

Index created.

ops$tkyte%ORA10GR2> create index tp_regular_idx on conferenceparticipant (CONFERENCEREFERENCE);

Index created.

ops$tkyte%ORA10GR2> create index tp_conferenceid on conferenceparticipant(conference);

Index created.

ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'conferenceparticipant' , cascade=> true );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'conference' , cascade=> true );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select tx.*
  2  from conferenceparticipant tp, conference tx
  3  where
  4  (tx.id = tp.conference and ( tx.id in (3491917) or upper(conferenceReference) in ('3491917')));

Execution Plan
----------------------------------------------------------
Plan hash value: 286815585

-------------------------------------------------------------------------------------------------------
| Id  | Operation                     | Name                  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |                       |     2 |   196 |   442   (4)| 00:00:03 |
|   1 |  CONCATENATION                |                       |       |       |            |          |
|   2 |   NESTED LOOPS                |                       |     1 |    98 |   438   (4)| 00:00:03 |
|*  3 |    TABLE ACCESS FULL          | CONFERENCEPARTICIPANT |     1 |    13 |   437   (4)| 00:00:03 |
|   4 |    TABLE ACCESS BY INDEX ROWID| CONFERENCE            |     1 |    85 |     1   (0)| 00:00:01 |
|*  5 |     INDEX UNIQUE SCAN         | SYS_C0035764          |     1 |       |     0   (0)| 00:00:01 |
|   6 |   NESTED LOOPS                |                       |     1 |    98 |     4   (0)| 00:00:01 |
|   7 |    TABLE ACCESS BY INDEX ROWID| CONFERENCE            |     1 |    85 |     2   (0)| 00:00:01 |
|*  8 |     INDEX UNIQUE SCAN         | SYS_C0035764          |     1 |       |     1   (0)| 00:00:01 |
|*  9 |    TABLE ACCESS BY INDEX ROWID| CONFERENCEPARTICIPANT |     1 |    13 |     2   (0)| 00:00:01 |
|* 10 |     INDEX RANGE SCAN          | TP_CONFERENCEID       |     1 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter(UPPER("CONFERENCEREFERENCE")='3491917')
   5 - access("TX"."ID"="TP"."CONFERENCE")
   8 - access("TX"."ID"=3491917)
   9 - filter(LNNVL(UPPER("CONFERENCEREFERENCE")='3491917'))
  10 - access("TX"."ID"="TP"."CONFERENCE")

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select tx.*
  2  from conferenceparticipant tp, conference tx
  3  where
  4  (tx.id = tp.conference and ( tx.id in (3491917) or (conferenceReference) in ('3491917')));

Execution Plan
----------------------------------------------------------
Plan hash value: 2413614018

-------------------------------------------------------------------------------------------------------
| Id  | Operation                     | Name                  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |                       |     2 |   196 |     7   (0)| 00:00:01 |
|   1 |  CONCATENATION                |                       |       |       |            |          |
|   2 |   NESTED LOOPS                |                       |     1 |    98 |     3   (0)| 00:00:01 |
|   3 |    TABLE ACCESS BY INDEX ROWID| CONFERENCEPARTICIPANT |     1 |    13 |     2   (0)| 00:00:01 |
|*  4 |     INDEX RANGE SCAN          | TP_REGULAR_IDX        |     1 |       |     1   (0)| 00:00:01 |
|   5 |    TABLE ACCESS BY INDEX ROWID| CONFERENCE            |     1 |    85 |     1   (0)| 00:00:01 |
|*  6 |     INDEX UNIQUE SCAN         | SYS_C0035764          |     1 |       |     0   (0)| 00:00:01 |
|   7 |   NESTED LOOPS                |                       |     1 |    98 |     4   (0)| 00:00:01 |
|   8 |    TABLE ACCESS BY INDEX ROWID| CONFERENCE            |     1 |    85 |     2   (0)| 00:00:01 |
|*  9 |     INDEX UNIQUE SCAN         | SYS_C0035764          |     1 |       |     1   (0)| 00:00:01 |
|* 10 |    TABLE ACCESS BY INDEX ROWID| CONFERENCEPARTICIPANT |     1 |    13 |     2   (0)| 00:00:01 |
|* 11 |     INDEX RANGE SCAN          | TP_CONFERENCEID       |     1 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - access("CONFERENCEREFERENCE"='3491917')
   6 - access("TX"."ID"="TP"."CONFERENCE")
   9 - access("TX"."ID"=3491917)
  10 - filter(LNNVL("CONFERENCEREFERENCE"='3491917'))
  11 - access("TX"."ID"="TP"."CONFERENCE")

ops$tkyte%ORA10GR2> set autotrace off

CONCATENATION

Yan, April 08, 2009 - 6:27 pm UTC

Hey Tom:

the same topic as above:

I was trying /*+ NO_EPNAD */, the plan is as following, but this time CBO do the full scan on conference table which is not good either.

select /*+ no_expand */ tx.*
from referenceparticipant tp, reference tx
where
tx.id = tp.reference
and (tx.id = 3491917 or upper(tp.referenceReference) ='3491917');

----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 465 | | 12042 (2)| 00:02:25 |
|* 1 | HASH JOIN | | 5 | 465 | 58M| 12042 (2)| 00:02:25 |
| 2 | INDEX FAST FULL SCAN| TP_REF_REFERENCE_FUNCB | 2662K| 27M| | 1885 (2)| 00:00:23 |
| 3 | TABLE ACCESS FULL | REFERENCE | 1008K| 78M| | 2723 (2)| 00:00:33 |
----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - access("TX"."ID"="TP"."REFERENCE")
filter("TX"."ID"=3491917 OR UPPER("REFERENCEREFERENCE")='3491917')


Statistics
----------------------------------------------------------
1 recursive calls
0 db block gets
20495 consistent gets
10851 physical reads
0 redo size
1171 bytes sent via SQL*Net to client
400 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed

So is there any way CBO will automatically pick up the plan like the union one? and why it didn't pick up the function based index with concatenation? confused!


Thank you very much!

Yan


bitmap to rowid conversion - Unable to Explain

A reader, April 09, 2009 - 8:55 pm UTC

Hi Tom,

We are using 10.1.0.4.
We have created two fact tables - one fact table has 14 dim keys and other has 14+8 dim keys.
The number of rows in both fact tables are same. Both tables (along with dim tables) have been analyzed in the same way.
There are bitmap indexes on all KEY columns in both fact tables.

When I use the a query against one fact table (14 dim keys) - it returns in around 8 secs but the same query against other fact table (14+8 dim keys) - it returns in around 37 secs.
I have drawn the execution plan, and found that second query (37 secs) is using the BITMAP CONVERSION TO ROWIDS thus resulting into additional time.

I am unable to understand why Oracle is doing this way for the same query.

Tables and results are as below
-- Table with 14 dim keys

SQL> desc fact;
Name Null? Type
----------------------------------------- -------- ---------------------
month_key NOT NULL NUMBER(6)
OUB_KEY NOT NULL NUMBER(15)
RLOU_KEY NOT NULL NUMBER(15)
INTOUB_KEY NOT NULL NUMBER(15)
GLA_KEY NOT NULL NUMBER(15)
LGLE_KEY NOT NULL NUMBER(15)
PDU_KEY NOT NULL NUMBER(15)
GLLO_KEY NOT NULL NUMBER(15)
FNC_KEY NOT NULL NUMBER(15)
ENT_KEY NOT NULL NUMBER(15)
CNV_KEY NOT NULL NUMBER(15)
ORG_KEY NOT NULL NUMBER(15)
GLM_KEY NOT NULL NUMBER(15)
SOB_KEY NOT NULL NUMBER(15)
FNC_SBAL NUMBER(15,2)
FNC_MBAL NUMBER(15,2)
ENT_SBAL NUMBER(15,2)
ENT_MBAL NUMBER(15,2)
CNV_SBAL NUMBER(15,2)
CNV_MBAL NUMBER(15,2)
ORG_SBAL NUMBER(15,2)
ORG_MBAL NUMBER(15,2)
FNCA_MTD NUMBER(15,2)
FNCA_YTD NUMBER(15,2)
LLD NOT NULL DATE
PINS NOT NULL NUMBER(15)
SOB NOT NULL NUMBER(5)
BFLG NOT NULL VARCHAR2(1)
CMTH NOT NULL NUMBER(6)

SQL> select count(*) from fact;

COUNT(*)
----------
8500962


-- Table with 14+8 dim keys

SQL> desc fact_test;
Name Null? Type
----------------------------------------- -------- -------------------
month_key NOT NULL NUMBER(6)
OUB_KEY NOT NULL NUMBER(15)
RLOU_KEY NOT NULL NUMBER(15)
INTOUB_KEY NOT NULL NUMBER(15)
GLA_KEY NOT NULL NUMBER(15)
LGLE_KEY NOT NULL NUMBER(15)
PDU_KEY NOT NULL NUMBER(15)
GLLO_KEY NOT NULL NUMBER(15)
FNC_KEY NOT NULL NUMBER(15)
ENT_KEY NOT NULL NUMBER(15)
CNV_KEY NOT NULL NUMBER(15)
ORG_KEY NOT NULL NUMBER(15)
GLM_KEY NOT NULL NUMBER(15)
SOB_KEY NOT NULL NUMBER(15)
FNC_SBAL NUMBER(15,2)
FNC_MBAL NUMBER(15,2)
ENT_SBAL NUMBER(15,2)
ENT_MBAL NUMBER(15,2)
CNV_SBAL NUMBER(15,2)
CNV_MBAL NUMBER(15,2)
ORG_SBAL NUMBER(15,2)
ORG_MBAL NUMBER(15,2)
FNCA_MTD NUMBER(15,2)
FNCA_YTD NUMBER(15,2)
LLD NOT NULL DATE
PINS NOT NULL NUMBER(15)
SOB NOT NULL NUMBER(5)
BFLG NOT NULL VARCHAR2(1)
CMTH NOT NULL NUMBER(6)
OU_KEY NOT NULL NUMBER(15)
ROU_KEY NOT NULL NUMBER(15)
IOU_KEY NOT NULL NUMBER(15)
GLU_KEY NOT NULL NUMBER(15)
LGU_KEY NOT NULL NUMBER(15)
PDUNIT_KEY NOT NULL NUMBER(15)
GLLU_KEY NOT NULL NUMBER(15)
GLMV_KEY NOT NULL NUMBER(15)

1* select count(*) from fact_test
08:48:47 SQL>
08:48:49 SQL> /

COUNT(*)
----------
8500962

-- Dim Tables

SQL> desc monthly_dim;
Name Null? Type
----------------------------------------- -------- ----------------------------
month_key NOT NULL NUMBER(6)
CMTH_ENDING_DT NOT NULL DATE
CMTH_NUM_IN_YEAR NOT NULL NUMBER(12)
CLNDR_YEAR_MTH NOT NULL VARCHAR2(10)
CLNDR_YEAR_MTH_NAME NOT NULL VARCHAR2(100)
CLNDR_YEAR_QTR VARCHAR2(10)
CLNDR_YEAR_QTR_DESCR NOT NULL VARCHAR2(100)
CLNDR_QTR_NUM NUMBER(2)
CLNDR_HALF_YEAR NOT NULL VARCHAR2(10)
CLNDR_HALF_YEAR_DESCR NOT NULL VARCHAR2(10)
CLNDR_YEAR NOT NULL VARCHAR2(10)
FNCL_MTH_NUM_IN_YEAR NUMBER(2)
FNCL_YEAR_MTH NOT NULL VARCHAR2(10)
FNCL_YEAR_QTR NOT NULL VARCHAR2(10)
FNCL_YEAR_QTR_DESCR NOT NULL VARCHAR2(100)
FNCL_QTR_NUM NOT NULL NUMBER(2)
FNCL_HALF_YEAR NOT NULL VARCHAR2(10)
FNCL_HALF_YEAR_DESCR NOT NULL VARCHAR2(100)
FNCL_YEAR NOT NULL VARCHAR2(10)
TOTAL_NUM_DAY_FNCL_YEAR NOT NULL NUMBER(15,2)
TOTAL_NUM_DAY_MTH NOT NULL NUMBER(15,2)
PINS NOT NULL NUMBER(15)

SQL> desc OUB;
Name Null? Type
----------------------------------------- -------- ----------------------------
OU_H_KEY NOT NULL NUMBER(15)
OUB_KEY NOT NULL NUMBER(15)
PINS NOT NULL NUMBER(15)
OU_ID NOT NULL NUMBER(15)
SQL> select count(*) from OUB;

COUNT(*)
----------
26770


-- Execution Plan join of FACT with monthly_dim and OUB

1 select count(1)
2 from FACT fct
3 inner join monthly_dim mth on fct.month_key = mth.month_key
4* inner join OUB orb on FCT.OUB_KEY = ORB.OUB_KEY
8:15:34 SQL> /

COUNT(1)
---------
8500962

lapsed: 00:00:08.67



-- Execution Plan join of FACT with monthly_dim and OUB


SQL> select count(1)
2 from FACT fct
3 inner join monthly_dim mth on fct.month_key = mth.month_key
4 inner join OUB orb on FCT.OUB_KEY = ORB.ORG_UNI
RIDGE_KEY
5 ;

Execution Plan
----------------------------------------------------------
Plan hash value: 1404587622

--------------------------------------------------------------------------------
---------------------------------------------------

| Id | Operation | Name | Rows | Byte
s |TempSpc| Cost (%CPU)| Time | Pstart| Pstop |

--------------------------------------------------------------------------------
---------------------------------------------------

| 0 | SELECT STATEMENT | | 1 | 1
6 | | 32466 (6)| 00:06:30 | | |

| 1 | SORT AGGREGATE | | 1 | 1
6 | | | | | |

|* 2 | HASH JOIN | | 8500K| 12
9M| 6280K| 32466 (6)| 00:06:30 | | |

| 3 | MERGE JOIN CARTESIAN | | 321K| 250
9K| | 113 (2)| 00:00:02 | | |

| 4 | INDEX FULL SCAN | XPKMONTH_DIM | 12 | 3
6 | | 1 (0)| 00:00:01 | | |

| 5 | BUFFER SORT | | 26770 | 13
0K| | 112 (2)| 00:00:02 | | |

| 6 | INDEX FAST FULL SCAN| XPKFINANCE_ORGANISATION_UNIT_B | 26770 | 13
0K| | 9 (0)| 00:00:01 | | |

| 7 | PARTITION RANGE ALL | | 8500K| 6
4M| | 23177 (4)| 00:04:39 | 1 | 6 |

| 8 | TABLE ACCESS FULL | FACT | 8500K| 6
4M| | 23177 (4)| 00:04:39 | 1 | 6 |

--------------------------------------------------------------------------------
---------------------------------------------------


Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("FCT"."OUB_KEY"="ORB"."OUB_KEY" AND "FCT".
"month_key"="MTH"."month_key")


-- -- Execution Plan join of fact_test with monthly_dim and OUB


1 select count(1)
2 from fact_test fct
3 inner join monthly_dim mth on fct.month_key = mth.month_key
4* inner join OUB orb on FCT.OUB_KEY = ORB.OUB_KEY
08:30:23 SQL> /

COUNT(1)
----------
8500962

Elapsed: 00:00:36.87
08:31:01 SQL>

08:31:01 SQL> set autotrace traceonly explain
08:31:37 SQL> /
Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
Plan hash value: 3753434628

--------------------------------------------------------------------------------
-----------------------------------------------------------

| Id | Operation | Name | Rows
| Bytes |TempSpc| Cost (%CPU)| Time | Pstart| Pstop |

--------------------------------------------------------------------------------
-----------------------------------------------------------

| 0 | SELECT STATEMENT | |
1 | 16 | | 33738 (7)| 00:06:45 | | |

| 1 | SORT AGGREGATE | |
1 | 16 | | | | | |

|* 2 | HASH JOIN | | 850
0K| 129M| 6280K| 33738 (7)| 00:06:45 | | |

| 3 | MERGE JOIN CARTESIAN | | 32
1K| 2509K| | 113 (2)| 00:00:02 | | |

| 4 | INDEX FULL SCAN | XPKMONTH_DIM | 1
2 | 36 | | 1 (0)| 00:00:01 | | |

| 5 | BUFFER SORT | | 2677
0 | 130K| | 112 (2)| 00:00:02 | | |

| 6 | INDEX FAST FULL SCAN | XPKFINANCE_ORGANISATION_UNIT_B | 2677
0 | 130K| | 9 (0)| 00:00:01 | | |

| 7 | VIEW | index$_join$_001 | 850
0K| 64M| | 24448 (7)| 00:04:54 | | |

|* 8 | HASH JOIN | |
| | | | | | |

| 9 | PARTITION RANGE ALL | | 850
0K| 64M| | 223 (1)| 00:00:03 | 1 | 6 |

| 10 | BITMAP CONVERSION TO ROWIDS| | 850
0K| 64M| | 223 (1)| 00:00:03 | | |

| 11 | BITMAP INDEX FULL SCAN | NU_ACTUAL_FACT_month_key |
| | | | | 1 | 6 |

| 12 | PARTITION RANGE ALL | | 850
0K| 64M| | 1879 (1)| 00:00:23 | 1 | 6 |

| 13 | BITMAP CONVERSION TO ROWIDS| | 850
0K| 64M| | 1879 (1)| 00:00:23 | | |

| 14 | BITMAP INDEX FULL SCAN | NU_ACTUAL_FACT_ORG_BRIDGE_KEY |
| | | | | 1 | 6 |

--------------------------------------------------------------------------------
-----------------------------------------------------------


Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("FCT"."OUB_KEY"="ORB"."OUB_KEY" AND "FCT".
"month_key"="MTH"."month_key")

8 - access(ROWID=ROWID)


Thanks

bitmap to rowid conversion - Unable to Explain

A reader, April 13, 2009 - 5:55 pm UTC

Hi Tom,

Could you please advise why by just adding more columns in the fact table, same query takes more time (explain plan started doing bitmap to rowid conversion) as per example above.

Regards,
Tom Kyte
April 14, 2009 - 9:47 am UTC

was too big and too hard to read, not formatted, no tkprofs, no explanation why you think the bitmap conversion to rowids is the culprit (no evidence of that), no way for me to reproduce the findings easily (no test case, not even a create table or anything), i do these 'reviews' very very quickly. I'm skipping that one.

Oracle Text performance on 1st pass

ojock, April 17, 2009 - 4:40 pm UTC

Tom,

I have some fairly basic Text queries using CONTEXT indexes on a table with about 8 million rows, and have found that often on first execution it is much slower than subsequent executions of the same query but just using different values for the bind variable (all the values were quite selective tokenwise).

I had suspected maybe it was hard parsing on first go, so I ran a trace and tkprof which showed that there wasn't any material difference in the PARSE step. What I noticed was that there was significantly more DB SEQUENTIAL READ WAITs for RECURSIVE SQL on what appears to be Oracle Text internal objects/calls.

Have you come across this? I've read somewhere about maybe putting some of these objects in the KEEP cache, but then I seem to recall reading here that you weren't too much of a fan of using the KEEP buffer pool?

Can you suggest any improvements I could make to speed up text queries on first pass?
Tom Kyte
April 20, 2009 - 10:48 am UTC

Well, it should be somewhat "clear" that - if what we need is not in the cache (the indexes on the tables that represent your actual text indexes) we need to get it in there.

So, sure, if the buffer cache is devoid of the actual blocks you need (think "root and branch blocks of the indexes on the TEXT tables that are the 'indexes' of my data") - we need to get them in there.

Just like the first of *any query against a set of segments that haven't been touched yet* would be.




Putting them into the keep pool - that would just make managing your memory harder and would not make them "always be there". The keep pool is just another buffer cache that manages blocks in a LRU (least recently used) fashion just like the default cache does. It would just be taking memory and making it ONLY useful for text index data - which wouldn't make the first execution *any faster than it currently is*.


If your first pass is "the first pass after database is started up" (which is what it sounds like) you should

a) start database less often, they should never be shutdown unless they really really have to and they hardly have to.

b) do something upon startup to "prime" the cache with stuff you want primed. As part of the startup, do some queries if you want to prime the cache with blocks.

Oracle Text performance on 1st pass

A reader, April 21, 2009 - 12:53 am UTC

Thanks Tom.

This is the article from one of your colleagues related to Oracle TEXT and KEEP pool - http://www.oracle.com/technology/products/text/htdocs/mem_load.html

Essentially as you suggest, it is "priming" the system on startup.

I'm testing on a development environment where the DB is not being restarted regularly and there is no other activity going on. The problem certainly occurs on 1st pass after DB startup, but it also manifest itself say when I run 20 queries (same query different BIND values) in quick succession,it would do this (not real data values shown);

contains('a')...4.5 seconds
contains('b')...0.1 seconds
contains('c')...0.2 seconds
contains('d')...0.1 seconds
contains('k')...3.5 seconds
contains('g')...0.1 seconds
contains('i')...0.2 seconds...

I can't explain the 35-45 fold increase in performance between queries. It's almost like Oracle Text is perhaps loading chunks of information in sections, eg. runs 'a', load in 'a','b','c' and 'd', runs 'k', load in 'k','g','i'

It tkprof, it would show significant differences in waits between 'a','k' and the others.
Tom Kyte
April 21, 2009 - 3:07 pm UTC

do you know how a database cache works? We only read into the cache information needed to satisfy the current request.

Yes, if you do not ask for "K" datat, we would not load "K" data - text is using good old fashioned tables and indexes on them to process your requests. When you ask for "a" data - you get some of a, b, c and closely related data loaded into the cache "by accident" (it is near the other data in the index, we load BLOCKS of data, not rows, hence when you ask for "a", you get other stuff too)

Eventually you are asking for data NOT IN THE CACHE, it has to be loaded (read in from disk)

It is not that oracle text is loading chunks of data, it is that you are loading blocks into the cache, the blocks contain more data than you actually requested - and because you are doing things alphabetically - your next two or three queries 'accidentally' run 'apparently quickly' because the physical IO you waited for the first time loaded up some data they too needed and therefore they did less physical IO.

sql tune

A reader, May 10, 2009 - 4:47 am UTC

Hi Tom,

I have this sql statement which took about 2:47 hours. and tried to change it's logic and to add indexes to the tables with no luck.
Please advice.


SELECT country, OPERATOR, SUM(TOTAL_SMS) TOTAL_SMS, SMSDATE_RETURN, SMSTIME_RETURN, NETWORK
FROM SMSIW_GTS, SMSIW_SMS_INCOM_SUM, SMSIW_SMS_MCCMNC
WHERE INSTR(CGPAGTADDRESS,GLOBALTITLE) = 1
AND NVL(SMSIW_SMS_INCOM_SUM.MCCMNC,0) = SMSIW_SMS_MCCMNC.MCCMNC
GROUP BY country, OPERATOR, SMSDATE_RETURN, SMSTIME_RETURN, NETWORK
/

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=770142 Card=8318820
Bytes=632230320)

1 0 SORT (GROUP BY) (Cost=770142 Card=8318820 Bytes=632230320)
2 1 HASH JOIN (Cost=4254 Card=8318820 Bytes=632230320)
3 2 MERGE JOIN (CARTESIAN) (Cost=732 Card=233235 Bytes=102
62340)

4 3 TABLE ACCESS (FULL) OF 'SMSIW_SMS_MCCMNC' (Cost=2 Ca
rd=365 Bytes=8760)

5 3 BUFFER (SORT) (Cost=730 Card=639 Bytes=12780)
6 5 TABLE ACCESS (FULL) OF 'SMSIW_GTS' (Cost=2 Card=63
9 Bytes=12780)

7 2 PARTITION RANGE (ALL)
8 7 TABLE ACCESS (FULL) OF 'SMSIW_SMS_INCOM_SUM' (Cost=7
45 Card=1262616 Bytes=40403712)

Tom Kyte
May 11, 2009 - 4:55 pm UTC

if that used an index (short of using an index as a skinny version of the table - that is - we could AVOID the table and just get everything we need from the index) - that will never use an index.

Look at it, think about what needs to happen here - just think about it.

unfortunately, you didn't use correlation names everywhere, so I've no clue what columns come from what tables :(

therefore, I cannot do the blow by blow for you - but think about this please, think about what needs to take place.


sql tune

A reader, May 12, 2009 - 12:05 pm UTC

hi tom,

regarding the above post, i know that i need a relation like dept.deptno = emp.deptno but these tables do not have any relations and all of thier columns are varchar2.
and that i cannot change.
That is why i need your advice.
Tom Kyte
May 13, 2009 - 10:44 am UTC

did you even read my post?

... unfortunately, you didn't use correlation names everywhere, so I've no clue what columns come from what tables :(

therefore, I cannot do the blow by blow for you - but think about this please, think about what needs to take place. ...

all I can do is ultimately describe the incredible amount of work that must be performed here - so that hopefully you can appreciate what has to take place.


given you have given me a query with NO CORRELATION names - I will have no further comments.

Sql tune

A reader, May 15, 2009 - 1:53 pm UTC

hi tom,

Please find below the correlation names:

SELECT country, OPERATOR, SUM(TOTAL_SMS) TOTAL_SMS, SMSDATE_RETURN, SMSTIME_RETURN, NETWORK
FROM SMSIW_GTS a, SMSIW_SMS_INCOM_SUM b, SMSIW_SMS_MCCMNC c
WHERE INSTR(a.CGPAGTADDRESS,b.GLOBALTITLE) = 1
AND NVL(b.MCCMNC,0) = c.MCCMNC
GROUP BY country, OPERATOR, SMSDATE_RETURN, SMSTIME_RETURN, NETWORK
/

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=770142 Card=8318820
Bytes=632230320)

1 0 SORT (GROUP BY) (Cost=770142 Card=8318820 Bytes=632230320)
2 1 HASH JOIN (Cost=4254 Card=8318820 Bytes=632230320)
3 2 MERGE JOIN (CARTESIAN) (Cost=732 Card=233235 Bytes=102
62340)

4 3 TABLE ACCESS (FULL) OF 'SMSIW_SMS_MCCMNC' (Cost=2 Ca
rd=365 Bytes=8760)

5 3 BUFFER (SORT) (Cost=730 Card=639 Bytes=12780)
6 5 TABLE ACCESS (FULL) OF 'SMSIW_GTS' (Cost=2 Card=63
9 Bytes=12780)

7 2 PARTITION RANGE (ALL)
8 7 TABLE ACCESS (FULL) OF 'SMSIW_SMS_INCOM_SUM' (Cost=7
45 Card=1262616 Bytes=40403712)

Tom Kyte
May 15, 2009 - 2:26 pm UTC

Ok, do you see how you "join" to a really big table using instr there?

basically - "a lot of work must be done" there. Think about what you are asking for - you need to compare every row in A to every row in B.


You could cut down on the number of compares greatly by adding:

ops$tkyte%ORA10GR2> SELECT    country, OPERATOR, SUM(TOTAL_SMS) TOTAL_SMS, SMSDATE_RETURN, SMSTIME_RETURN, NETWORK
  2  FROM    SMSIW_GTS a, SMSIW_SMS_INCOM_SUM b, SMSIW_SMS_MCCMNC c<b>
  3  WHERE    substr( a.CGPAGTADDRESS, 1, 1 ) = substr( b.GLOBALTITLE, 1, 1 )</b>
  4    and INSTR(a.CGPAGTADDRESS,b.GLOBALTITLE) = 1
  5  AND    NVL(b.MCCMNC,0) = c.MCCMNC
  6  GROUP BY  country, OPERATOR, SMSDATE_RETURN, SMSTIME_RETURN, NETWORK
  7  /

Execution Plan
----------------------------------------------------------
Plan hash value: 784533551

------------------------------------------------------------------------
| Id  | Operation            | Name                | Rows  | Bytes | Cos
------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |                     | 80681 |    10M|   1
|   1 |  HASH GROUP BY       |                     | 80681 |    10M|   1
|*  2 |   HASH JOIN          |                     | 80681 |    10M|   1
|   3 |    TABLE ACCESS FULL | SMSIW_SMS_MCCMNC    |   365 | 30295 |
|*  4 |    HASH JOIN         |                     | 80681 |  3703K|   1
|   5 |     TABLE ACCESS FULL| SMSIW_GTS           |   639 | 10863 |
|   6 |     TABLE ACCESS FULL| SMSIW_SMS_INCOM_SUM |  1262K|    36M|
------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("C"."MCCMNC"=NVL("B"."MCCMNC",0))
   4 - access(SUBSTR("A"."CGPAGTADDRESS",1,1)=SUBSTR("B"."GLOBALTITLE",1
       filter(INSTR("A"."CGPAGTADDRESS","B"."GLOBALTITLE")=1)



and in fact, if globaltitle has some minimum length (eg: it is always at least '5 characters') you would substr THAT LENGTH instead of just one


What does that do for you?

many many many thanks

A reader, May 19, 2009 - 3:08 am UTC


Converting Columns to Rows

Dulal, May 20, 2009 - 11:00 am UTC

Hi Tom,
Thanks in advance.
I have a problem. Please help.
I have a table with data as follows

Item Brand Quantity
----- ----- --------
Item-1 B-1 10
Item-2 B-1 12
Item-3 B-2 15
....................
....................
Item-n B-2 25

I want the output as follows

Brand Item-1 Item-2 Item-3 .... Item-n
----- ------ ------ ------ ------
B-1 10 12 0 0
B-2 0 0 15 0
.............................................
.............................................
B-2 0 0 0 25

Best regards.

Tom Kyte
May 23, 2009 - 1:12 pm UTC

what does this have even remotely to do with tuning?

and it seems you want to convert ROWS into COLUMNS - not what you said???

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:766825833740

optimizer using index based on faction or number?

jian huang zheng, May 22, 2009 - 11:40 am UTC

Hi Tom

As you mentioned before, it is better for optimizer to generate a plan using index to have a few rows return. I just wonder if the base table has 1 billion rows and the rows returned will be 20000, 20000 rows is a small proportion of table rows.
Will optimizer still use the index to access the table? The decision factor is based on proportion or just mere number of rows returned ,such as less than 1000?
Thanks!
Tom Kyte
May 23, 2009 - 10:32 pm UTC

the cbo uses many metrics - including how clustered the data in the table is by the index key - how many rows are in the table - etc.

Yes, you would probably expect 20,000 rows to be returned via an index from a 1 billion row table.

Index not being used when it should be

Sanji, May 27, 2009 - 5:41 pm UTC

Tom,

The environment is 9.2.0.7, HP-UX.

The STATSPACK for one of the databases, pointed out couple of expensive queries and i'm in the process of fine tuning them. However i'm struggling with instances where the optimizer works better if an index is forced, rather than letting it do full scans.

I collected the statistics on the table as

exec dbms_stats.gather_table_stats('ur','transactions',method_opt=>'for all columns size auto',cascade=>true)


Following are the metrics

TABLE_NAME NUM_ROWS SAMPLE_SIZE LAST_ANALYZED
-------------------- ---------- ----------- -------------
TRANSACTIONS 7153024 7153024 27-MAY-09

TABLE_NAME INDEX_NAME INDEX_TYPE CLUSTERING_FACTOR DISTINCT_KEYS SAMPLE_SIZE
-------------------- ------------------------------ ---------- ----------------- ------------- -----------
TRANSACTIONS TRANSIMPORTID_IDX NORMAL 397981 47846 448769
PK_TRANSACTIONS NORMAL 1569135 7057400 499611
TRANSACTIONS_BALANCES NORMAL 7039256 232555 323447
TRANSACTIONS_MATCHGROUPID NORMAL 5135531 177888 455689
TRANSACTIONS_USERREF1 NORMAL 4601084 145208 420065
TRANSACTIONS_IMPACCOUNTID NORMAL 996331 597 571623
TRANSACTIONS_TACCOUNTID NORMAL 382270 67 557755
TRANSACTIONS_TRANSTYPE NORMAL 418182 37 597468
TRANSACTIONS_EFFECTIVEDATE NORMAL 368856 778 416585


The query is

Select count(*) FROM Transactions
Where transactions.TAccountID IN (117,118,119,120,121,122)
and MatchedFlag = 'U'
and TransactionType <> 'IC'
/

Following is the data sample (histogram)

MIN(TACCOUNTID) MAX(TACCOUNTID) COUNT(TACCOUNTID) WB
--------------- --------------- ----------------- ---------
117 117 181041 229
118 118 19495 231
119 119 83610 233
120 120 50456 235
121 121 1554 237
122 122 26503 239

If i force the indexes, the query performs better

OPEN:SANJI:TRECS@ORADEV1>Select /*+ rule */ count(*) FROM Transactions
2 Where transactions.TAccountID IN (117,118,119,120,121,122)
3 and MatchedFlag = 'U'
4 and TransactionType <> 'IC'
5 /

Elapsed: 00:00:01.02

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=HINT: RULE
1 0 SORT (AGGREGATE)
2 1 CONCATENATION
3 2 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS'
4 3 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE)
5 2 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS'
6 5 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE)
7 2 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS'
8 7 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE)
9 2 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS'
10 9 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE)
11 2 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS'
12 11 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE)
13 2 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS'
14 13 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE)

Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
22598 consistent gets
15320 physical reads
0 redo size
519 bytes sent via SQL*Net to client
651 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed

However, if the query is executed as is, it takes a while

OPEN:SANJI:TRECS@ORADEV1>Select count(*) FROM Transactions
2 Where transactions.TAccountID IN (117,118,119,120,121,122)
3 and MatchedFlag = 'U'
4 and TransactionType <> 'IC'
5 /

Elapsed: 00:00:10.52

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=18328 Card=1 Bytes=9)
1 0 SORT (AGGREGATE)
2 1 TABLE ACCESS (FULL) OF 'TRANSACTIONS' (Cost=18328 Card=19549 Bytes=175941)


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
189901 consistent gets
177818 physical reads
0 redo size
519 bytes sent via SQL*Net to client
651 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
1 rows processed

I played around with optimizer_index_cost_adj and caching and this particular query started using the indexes but it had a detrimental effect on other queries... so i let set them back to default (100 & 0 respectively).

May i request for your opinion on this issue.

Rgds
Sanji

Tom Kyte
May 27, 2009 - 10:36 pm UTC

you need to show the

a) explain plan (estimated cardinality)
b) the tkprof row source operation (what really happened)

of the unhinted query - so we can see if the guess was anywhere near reality

Index not being used when it should be

Sanji, May 27, 2009 - 5:50 pm UTC

I see the same pattern (of index not being used, when it should be) in another query...

OPEN:SANJI:TRECS@ORADEV1>select status, updatedby, updateddate
2 from casetable
3 where exists (select tranid from transactions
4 where transactions.tranid = casetable.tranid
5 and taccountid = 96
6 and matchedflag = 'M')
7 and status <> 'C'
8 /

no rows selected

Elapsed: 00:00:06.88

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=19174 Card=49049 Bytes=1912911)
1 0 HASH JOIN (SEMI) (Cost=19174 Card=49049 Bytes=1912911)
2 1 TABLE ACCESS (FULL) OF 'CASETABLE' (Cost=371 Card=49049Bytes=1324323)
3 1 TABLE ACCESS (FULL) OF 'TRANSACTIONS' (Cost=18328 Card=1221955 Bytes=14663460)


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
193667 consistent gets
180822 physical reads
144 redo size
433 bytes sent via SQL*Net to client
456 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed


OPEN:SANJI:TRECS@ORADEV1>select status, updatedby, updateddate
2 from casetable
3 where exists (select /*+ index(T TRANSACTIONS_TACCOUNTID) */ tranid from transactions T
4 where T.tranid = casetable.tranid
5 and taccountid = 96
6 and matchedflag = 'M')
7 and status <> 'C'
8 /

no rows selected

Elapsed: 00:00:03.30

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=72444 Card=49049 Bytes=1912911)
1 0 HASH JOIN (SEMI) (Cost=72444 Card=49049 Bytes=1912911)
2 1 TABLE ACCESS (FULL) OF 'CASETABLE' (Cost=371 Card=49049 Bytes=1324323)
3 1 TABLE ACCESS (BY INDEX ROWID) OF 'TRANSACTIONS' (Cost=71598 Card=1221955 Bytes=14663460)
4 3 INDEX (RANGE SCAN) OF 'TRANSACTIONS_TACCOUNTID' (NON-UNIQUE) (Cost=2522 Card=1292545)


Statistics
----------------------------------------------------------
0 recursive calls
0 db block gets
51402 consistent gets
51251 physical reads
0 redo size
433 bytes sent via SQL*Net to client
456 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed

Rgds
Tom Kyte
May 28, 2009 - 7:01 am UTC

same request, you always need to set the explain next to the row source operation and see where they differ and then ask "why, why might this difference in actual cardinality from estimated be there"

you would also need to tell us what the indexes are actually on - in a simple readable format.


My guess - skewed data that the optimizer isn't aware of.

index not being used when it should be

Sanji, May 28, 2009 - 10:43 am UTC

Tom,
I did a 10046 trace on the queries (the unindexed and with index TRANSACTIONS_BALANCES) and following is the tkprof output.

Select count(*) from Transactions
Where transactions.TAccountID IN (117,118,119,120,121,122)
and MatchedFlag = 'U'
and TransactionType <> 'IC'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 13.39 16.99 176919 189902 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 13.40 16.99 176919 189902 0 1

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 39

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE
3216 TABLE ACCESS FULL TRANSACTIONS

********************************************************************************

Select /*+ index(transactions TRANSACTIONS_BALANCES) */
count(*) from Transactions
Where transactions.TAccountID IN (117,118,119,120,121,122)
and MatchedFlag = 'U'
and TransactionType <> 'IC'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.29 0.38 1300 11629 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 0.29 0.38 1300 11629 0 1

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 39

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE
3216 INLIST ITERATOR
3216 TABLE ACCESS BY INDEX ROWID TRANSACTIONS
10472 INDEX RANGE SCAN TRANSACTIONS_BALANCES (object id 3895)

********************************************************************************


The explain plans for the respective queries are

OPEN:SANJI:TRECS@ORADEV1>explain plan for
2 Select count(*) from Transactions
3 Where transactions.TAccountID IN (117,118,119,120,121,122)
4 and MatchedFlag = 'U'
5 and TransactionType <> 'IC'
6 /

Explained.

OPEN:SANJI:TRECS@ORADEV1>@rdbms/admin/utlxpls

Id | Operation | Name | Rows | Bytes | Cost |
----------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 9 | 18328 |
| 1 | SORT AGGREGATE | | 1 | 9 | |
|* 2 | TABLE ACCESS FULL | TRANSACTIONS | 19549 | 171K| 18328 |
----------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter(("TRANSACTIONS"."TACCOUNTID"=117 OR
"TRANSACTIONS"."TACCOUNTID"=118 OR "TRANSACTIONS"."TACCOUNTID"=119 OR
"TRANSACTIONS"."TACCOUNTID"=120 OR "TRANSACTIONS"."TACCOUNTID"=121 OR
"TRANSACTIONS"."TACCOUNTID"=122) AND "TRANSACTIONS"."MATCHEDFLAG"='U'
AND "TRANSACTIONS"."TRANSACTIONTYPE"<>'IC')


OPEN:SANJI:TRECS@ORADEV1>explain plan for
2 Select /*+ index(transactions TRANSACTIONS_BALANCES) */
3 count(*) from Transactions
4 Where transactions.TAccountID IN (117,118,119,120,121,122)
5 and MatchedFlag = 'U'
6 and TransactionType <> 'IC'
7 /

Explained.

OPEN:SANJI:TRECS@ORADEV1>@rdbms/admin/utlxpls

Id | Operation | Name | Rows | Bytes | Cost |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 9 | 20758 |
| 1 | SORT AGGREGATE | | 1 | 9 | |
| 2 | INLIST ITERATOR | | | | |
|* 3 | TABLE ACCESS BY INDEX ROWID| TRANSACTIONS | 19549 | 171K| 20758 |
|* 4 | INDEX RANGE SCAN | TRANSACTIONS_BALANCES | 19806 | | 1266 |
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

3 - filter("TRANSACTIONS"."TRANSACTIONTYPE"<>'IC')
4 - access(("TRANSACTIONS"."TACCOUNTID"=117 OR "TRANSACTIONS"."TACCOUNTID"=118 OR
"TRANSACTIONS"."TACCOUNTID"=119 OR "TRANSACTIONS"."TACCOUNTID"=120 OR
"TRANSACTIONS"."TACCOUNTID"=121 OR "TRANSACTIONS"."TACCOUNTID"=122) AND
"TRANSACTIONS"."MATCHEDFLAG"='U')
filter("TRANSACTIONS"."MATCHEDFLAG"='U')


The index details for respective columns on table TRANSACTIONS are

Following are the indexed columns details

INDEX_NAME COLUMN_NAME COLUMN_POSITION
------------------------------ -------------------- ---------------
PK_TRANSACTIONS TRANID 1

TRANSACTIONS_BALANCES TACCOUNTID 1
DEBITORCREDIT 2
BANKBOOKFLAG 3
MATCHEDFLAG 4
TRANSAMOUNT 5

TRANSACTIONS_EFFECTIVEDATE EFFECTIVEDATE 1

TRANSACTIONS_IMPACCOUNTID IMPACCOUNTID 1

TRANSACTIONS_MATCHGROUPID MATCHGROUPID 1

TRANSACTIONS_TACCOUNTID TACCOUNTID 1

TRANSACTIONS_TRANSTYPE TRANSACTIONTYPE 1

TRANSACTIONS_USERREF1 USERREF1 1

TRANSIMPORTID_IDX IMPORTID 1
DEBITORCREDIT 2

The cardinalities from the tkprof and the explain plan do not match.

I did analyze the table to create the histogram, but it seems that the skewed data is being ignored and the optimizer decides on the full scan.

exec dbms_stats.gather_table_stats('ur','transactions',method_opt=>'for all columns size auto',cascade=>true)

Rgds
Tom Kyte
May 28, 2009 - 2:00 pm UTC

which column is skewed, analyze that one and use size 254

Performance MIN / MAX

Stan, May 28, 2009 - 2:27 pm UTC

Hi Tom,

I have reproduced a scenario below in the simplest way I could to illustrate an issue we face with performance.
Please bear with me as I try and explain it best I can. My question is at the end.

>>>>>>>>>> Create 2 tables and their indexes

CREATE TABLE LEDGER_ACCOUNT
( PORTFOLIO_ACCT CHAR(8 BYTE),
BASE_CURRENCY VARCHAR2(3 BYTE),
LOCAL_CURRENCY VARCHAR2(3 BYTE),
ACCT_BASIS VARCHAR2(5 BYTE),
CLASS VARCHAR2(10 BYTE),
LEDGER_ACCT CHAR(55 BYTE),
ASSET_GRP VARCHAR2(20 BYTE),
ASSET_ID NUMBER,
OPEN_EVT_ID VARCHAR2(25 BYTE),
CLS_EVT_ID VARCHAR2(25 BYTE),
ACCOUNT_ID NUMBER(28,0),
UPDATE_DATE DATE,
UPDATE_SOURCE VARCHAR2(32 BYTE)
);

CREATE UNIQUE INDEX PK_LEDGER_ACCT_IDX ON LEDGER_ACCOUNT (PORTFOLIO_ACCT, ACCT_BASIS, BASE_CURRENCY, LOCAL_CURRENCY, LEDGER_ACCT, CLASS, ASSET_GRP, OPEN_EVT_ID, CLS_EVT_ID);

CREATE TABLE LEDGER_BALANCE
( ACCOUNT_ID NUMBER(28,0),
START_DT DATE,
END_DT DATE,
TODAY_DT DATE,
YEAR_END_FLAG VARCHAR2(1 BYTE),
CLOSEOUT_FLAG CHAR(1 BYTE),
BALANCE_AMT NUMBER(38,6),
DEBIT_CREDIT VARCHAR2(2 BYTE),
CUM_DEBIT NUMBER(38,6),
CUM_CREDIT NUMBER(38,6),
TODAY_DEBIT NUMBER(38,6),
TODAY_CREDIT NUMBER(38,6),
MAXPERIOD VARCHAR2(1 BYTE),
CLOSEOUT_LEDGER_ACCT_OFFSET CHAR(55 BYTE),
CLOSEOUT_LEDGER_ACCT_TARGET CHAR(55 BYTE),
UPDATE_SYNC_ID NUMBER(*,0),
UPDATE_DATE DATE,
UPDATE_SOURCE VARCHAR2(32 BYTE)
);

CREATE UNIQUE INDEX PK_LEDGER_BALANCE_IDX ON LEDGER_BALANCE (ACCOUNT_ID, END_DT);

>>>>>>>>>> Fake out stats to match "real life"


exec dbms_stats.set_table_stats(ownname => 'SYSTEM', tabname => 'LEDGER_ACCOUNT', numrows => 2165480);
exec dbms_stats.set_index_stats(ownname => 'SYSTEM', indname => 'PK_LEDGER_ACCT_IDX', numrows => 2347439);

exec dbms_stats.set_table_stats(ownname => 'SYSTEM', tabname => 'LEDGER_BALANCE', numrows => 64727340);
exec dbms_stats.set_index_stats(ownname => 'SYSTEM', indname => 'PK_LEDGER_BALANCE_IDX', numrows => 72072140);

>>>>>>>>>> Explain "typical query"

EXPLAIN PLAN FOR
SELECT SUM(decode(ela.ledger_acct, :b2, elb.balance_amt, 0)),
SUM(decode(ela.ledger_acct, :b1, elb.balance_amt, 0))
FROM ledger_account ela,
ledger_balance elb
WHERE ela.portfolio_acct = :b7
AND ela.base_currency = :b6
AND ela.local_currency = :b6
AND ela.acct_basis = :b5
AND ela.open_evt_id = :b4
AND ela.cls_evt_id = '0'
AND ela.class = 'TF'
AND ela.asset_grp = :b3
AND ela.ledger_acct IN(:b2, :b1)
AND ela.account_id = elb.account_id
AND elb.end_dt =
(SELECT MAX(sub_elb.end_dt)
FROM ledger_balance sub_elb
WHERE sub_elb.account_id = ela.account_id
AND sub_elb.year_end_flag = 'Y'
AND sub_elb.end_dt <= :b8)
;

SELECT plan_table_output
FROM TABLE(dbms_xplan.display());



EXPLAIN PLAN succeeded.
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 3873782790

----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 135 | 7 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 135 | | |
| 2 | NESTED LOOPS | | 1 | 135 | 5 (0)| 00:00:01 |
| 3 | INLIST ITERATOR | | | | | |
| 4 | TABLE ACCESS BY INDEX ROWID | LEDGER_ACCOUNT | 1 | 100 | 4 (0)| 00:00:01 |
|* 5 | INDEX RANGE SCAN | PK_LEDGER_ACCT_IDX | 1 | | 3 (0)| 00:00:01 |
| 6 | TABLE ACCESS BY INDEX ROWID | LEDGER_BALANCE | 1 | 35 | 1 (0)| 00:00:01 |
|* 7 | INDEX UNIQUE SCAN | PK_LEDGER_BALANCE_IDX | 1 | | 0 (0)| 00:00:01 |
| 8 | SORT AGGREGATE | | 1 | 22 | | |
| 9 | FIRST ROW | | 32364 | 695K| 2 (0)| 00:00:01 |
|* 10 | INDEX RANGE SCAN (MIN/MAX)| PK_LEDGER_BALANCE_IDX | 32364 | 695K| 2 (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

5 - access("ELA"."PORTFOLIO_ACCT"=:B7 AND "ELA"."ACCT_BASIS"=:B5 AND "ELA"."BASE_CURRENCY"=:B6
AND "ELA"."LOCAL_CURRENCY"=:B6 AND ("ELA"."LEDGER_ACCT"=:B2 OR "ELA"."LEDGER_ACCT"=:B1) AND
"ELA"."CLASS"='TF' AND "ELA"."ASSET_GRP"=:B3 AND "ELA"."OPEN_EVT_ID"=:B4 AND
"ELA"."CLS_EVT_ID"='0')
7 - access("ELA"."ACCOUNT_ID"="ELB"."ACCOUNT_ID" AND "ELB"."END_DT"= (SELECT
MAX("SUB_ELB"."END_DT") FROM "LEDGER_BALANCE" "SUB_ELB" WHERE "SUB_ELB"."END_DT"<=:B8 AND
"SUB_ELB"."ACCOUNT_ID"=:B1))
10 - access("SUB_ELB"."ACCOUNT_ID"=:B1 AND "SUB_ELB"."END_DT"<=:B8)

29 rows selected

>>>>>>>>>> Query plan above looks good - performance is fine.
>>>>>>>>>> Now user only wants the balance for the year end so we add in the qualifier sub_elb.year_end_flag = 'Y'


EXPLAIN PLAN FOR
SELECT SUM(decode(ela.ledger_acct, :b2, elb.balance_amt, 0)),
SUM(decode(ela.ledger_acct, :b1, elb.balance_amt, 0))
FROM ledger_account ela,
ledger_balance elb
WHERE ela.portfolio_acct = :b7
AND ela.base_currency = :b6
AND ela.local_currency = :b6
AND ela.acct_basis = :b5
AND ela.open_evt_id = :b4
AND ela.cls_evt_id = '0'
AND ela.class = 'TF'
AND ela.asset_grp = :b3
AND ela.ledger_acct IN(:b2, :b1)
AND ela.account_id = elb.account_id
AND elb.end_dt =
(SELECT MAX(sub_elb.end_dt)
FROM ledger_balance sub_elb
WHERE sub_elb.account_id = ela.account_id
AND sub_elb.year_end_flag = 'Y'
AND sub_elb.end_dt <= :b8)
;

SELECT plan_table_output
FROM TABLE(dbms_xplan.display());

EXPLAIN PLAN succeeded.
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 82512059

----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 135 | 8 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 135 | | |
| 2 | NESTED LOOPS | | 1 | 135 | 5 (0)| 00:00:01 |
| 3 | INLIST ITERATOR | | | | | |
| 4 | TABLE ACCESS BY INDEX ROWID | LEDGER_ACCOUNT | 1 | 100 | 4 (0)| 00:00:01 |
|* 5 | INDEX RANGE SCAN | PK_LEDGER_ACCT_IDX | 1 | | 3 (0)| 00:00:01 |
| 6 | TABLE ACCESS BY INDEX ROWID | LEDGER_BALANCE | 1 | 35 | 1 (0)| 00:00:01 |
|* 7 | INDEX UNIQUE SCAN | PK_LEDGER_BALANCE_IDX | 1 | | 0 (0)| 00:00:01 |
| 8 | SORT AGGREGATE | | 1 | 24 | | |
|* 9 | TABLE ACCESS BY INDEX ROWID| LEDGER_BALANCE | 324 | 7776 | 3 (0)| 00:00:01 |
|* 10 | INDEX RANGE SCAN | PK_LEDGER_BALANCE_IDX | 2595 | | 2 (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

5 - access("ELA"."PORTFOLIO_ACCT"=:B7 AND "ELA"."ACCT_BASIS"=:B5 AND "ELA"."BASE_CURRENCY"=:B6
AND "ELA"."LOCAL_CURRENCY"=:B6 AND ("ELA"."LEDGER_ACCT"=:B2 OR "ELA"."LEDGER_ACCT"=:B1) AND
"ELA"."CLASS"='TF' AND "ELA"."ASSET_GRP"=:B3 AND "ELA"."OPEN_EVT_ID"=:B4 AND
"ELA"."CLS_EVT_ID"='0')
7 - access("ELA"."ACCOUNT_ID"="ELB"."ACCOUNT_ID" AND "ELB"."END_DT"= (SELECT
MAX("SUB_ELB"."END_DT") FROM "LEDGER_BALANCE" "SUB_ELB" WHERE "SUB_ELB"."END_DT"<=:B8 AND
"SUB_ELB"."ACCOUNT_ID"=:B1 AND "SUB_ELB"."YEAR_END_FLAG"='Y'))
9 - filter("SUB_ELB"."YEAR_END_FLAG"='Y')
10 - access("SUB_ELB"."ACCOUNT_ID"=:B1 AND "SUB_ELB"."END_DT"<=:B8)

30 rows selected

>>>>>>>>>> Query plan above looks bad - performance is terrible - users complain.
>>>>>>>>>> Real life performance degrades by a factor of 1 thousand
>>>>>>>>>> The plan no longer can use MIN / MAX optimizer feature

>>>>>>>>>> In order to get back the MIN / MAX "type" plan we add in an "extra" index to include the year end flag


DROP INDEX PK_LEDGER_BALANCE_IDX;

CREATE UNIQUE INDEX PK_LEDGER_BALANCE_IDX ON LEDGER_BALANCE (ACCOUNT_ID, END_DT);
CREATE UNIQUE INDEX PK_LEDGER_BALANCE_IDX2 ON LEDGER_BALANCE (ACCOUNT_ID, YEAR_END_FLAG, END_DT);

exec dbms_stats.set_index_stats(ownname => 'SYSTEM', indname => 'PK_LEDGER_BALANCE_IDX', numrows => 72072140);
exec dbms_stats.set_index_stats(ownname => 'SYSTEM', indname => 'PK_LEDGER_BALANCE_IDX2', numrows => 72072140);


EXPLAIN PLAN FOR
SELECT SUM(decode(ela.ledger_acct, :b2, elb.balance_amt, 0)),
SUM(decode(ela.ledger_acct, :b1, elb.balance_amt, 0))
FROM ledger_account ela,
ledger_balance elb
WHERE ela.portfolio_acct = :b7
AND ela.base_currency = :b6
AND ela.local_currency = :b6
AND ela.acct_basis = :b5
AND ela.open_evt_id = :b4
AND ela.cls_evt_id = '0'
AND ela.class = 'TF'
AND ela.asset_grp = :b3
AND ela.ledger_acct IN(:b2, :b1)
AND ela.account_id = elb.account_id
AND elb.end_dt =
(SELECT MAX(sub_elb.end_dt)
FROM ledger_balance sub_elb
WHERE sub_elb.account_id = ela.account_id
AND sub_elb.year_end_flag = 'Y'
AND sub_elb.end_dt <= :b8)
;

SELECT plan_table_output
FROM TABLE(dbms_xplan.display());

EXPLAIN PLAN succeeded.
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1251010790

-----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 135 | 5 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 135 | | |
| 2 | NESTED LOOPS | | 1 | 135 | 4 (0)| 00:00:01 |
| 3 | INLIST ITERATOR | | | | | |
| 4 | TABLE ACCESS BY INDEX ROWID | LEDGER_ACCOUNT | 1 | 100 | 4 (0)| 00:00:01 |
|* 5 | INDEX RANGE SCAN | PK_LEDGER_ACCT_IDX | 1 | | 3 (0)| 00:00:01 |
| 6 | TABLE ACCESS BY INDEX ROWID | LEDGER_BALANCE | 1 | 35 | 0 (0)| 00:00:01 |
|* 7 | INDEX UNIQUE SCAN | PK_LEDGER_BALANCE_IDX | 1 | | 0 (0)| 00:00:01 |
| 8 | SORT AGGREGATE | | 1 | 24 | | |
| 9 | FIRST ROW | | 324 | 7776 | 1 (0)| 00:00:01 |
|* 10 | INDEX RANGE SCAN (MIN/MAX)| PK_LEDGER_BALANCE_IDX2 | 324 | 7776 | 1 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

5 - access("ELA"."PORTFOLIO_ACCT"=:B7 AND "ELA"."ACCT_BASIS"=:B5 AND "ELA"."BASE_CURRENCY"=:B6
AND "ELA"."LOCAL_CURRENCY"=:B6 AND ("ELA"."LEDGER_ACCT"=:B2 OR "ELA"."LEDGER_ACCT"=:B1) AND
"ELA"."CLASS"='TF' AND "ELA"."ASSET_GRP"=:B3 AND "ELA"."OPEN_EVT_ID"=:B4 AND
"ELA"."CLS_EVT_ID"='0')
7 - access("ELA"."ACCOUNT_ID"="ELB"."ACCOUNT_ID" AND "ELB"."END_DT"= (SELECT
MAX("SUB_ELB"."END_DT") FROM "LEDGER_BALANCE" "SUB_ELB" WHERE "SUB_ELB"."END_DT"<=:B8 AND
"SUB_ELB"."YEAR_END_FLAG"='Y' AND "SUB_ELB"."ACCOUNT_ID"=:B1))
10 - access("SUB_ELB"."ACCOUNT_ID"=:B1 AND "SUB_ELB"."YEAR_END_FLAG"='Y' AND
"SUB_ELB"."END_DT"<=:B8)

30 rows selected

>>>>>>>>>> Query plan above looks good - performance is fine again.

Hope that was clear!!!

My question - is there a better way to write this type of query to get the same results? The users can pick any other columns as quantifiers so
every column could potentially be needed in the index so it can use the optimizer MIN / MAX feature.

Thanks in advance!


Tom Kyte
May 28, 2009 - 3:07 pm UTC

I'm confused - all three queries are identical.


but, think about it - if you want the min/max - what *must* be present in the index to do that. close your eyes, envision how the data would be stored. think about it...

FROM ledger_account ela,
  ledger_balance elb
WHERE ela.portfolio_acct = :b7
 AND ela.base_currency = :b6
 AND ela.local_currency = :b6
 AND ela.acct_basis = :b5
 AND ela.open_evt_id = :b4
 AND ela.cls_evt_id = '0'
 AND ela.class = 'TF'
 AND ela.asset_grp = :b3
 AND ela.ledger_acct IN(:b2,   :b1)
 AND ela.account_id = elb.account_id
 AND elb.end_dt =
  (SELECT MAX(sub_elb.end_dt)
   FROM ledger_balance sub_elb
   WHERE sub_elb.account_id = ela.account_id
   AND sub_elb.year_end_flag = 'Y'
   AND sub_elb.end_dt <= :b8)
;



tell us more about elb.end_dt - is it unique within an ACCOUNT_ID? (if so, the predicates on year_end_flag ='Y' and end_dt <= :b8 should be moved out of the subquery - they would be applicable to the outer elb as well).

but we could use analytics instead of a subquery.


select *
  from
(
SELECT SUM(decode(ela.ledger_acct,   :b2,   elb.balance_amt,   0)),
       SUM(decode(ela.ledger_acct,   :b1,   elb.balance_amt,   0)),
       elb.end_dt,
       max(case when elb.year_end_flag = 'Y' and elb.end_dt <= :b8 then end_dt end) over (partition by elb.account_id) max_end_dt
FROM ledger_account ela,
  ledger_balance elb
WHERE ela.portfolio_acct = :b7
 AND ela.base_currency = :b6
 AND ela.local_currency = :b6
 AND ela.acct_basis = :b5
 AND ela.open_evt_id = :b4
 AND ela.cls_evt_id = '0'
 AND ela.class = 'TF'
 AND ela.asset_grp = :b3
 AND ela.ledger_acct IN(:b2,   :b1)
 AND ela.account_id = elb.account_id
)
where end_dt = max_end_dt
/



and if end_date is unique within an account_id, then:

select *
  from
(
SELECT SUM(decode(ela.ledger_acct,   :b2,   elb.balance_amt,   0)),
       SUM(decode(ela.ledger_acct,   :b1,   elb.balance_amt,   0)),
       elb.end_dt,
       row_number() over (partition by elb.account_id order by elb.end_dt DESC) rn
FROM ledger_account ela,
  ledger_balance elb
WHERE ela.portfolio_acct = :b7
 AND ela.base_currency = :b6
 AND ela.local_currency = :b6
 AND ela.acct_basis = :b5
 AND ela.open_evt_id = :b4
 AND ela.cls_evt_id = '0'
 AND ela.class = 'TF'
 AND ela.asset_grp = :b3
 AND ela.ledger_acct IN(:b2,   :b1)
 AND ela.account_id = elb.account_id
 and elb.year_end_flag = 'Y'
 and elb.end_dt <= :b8
)
where rn = 1
/

index not being used when it should be

Sanji, May 28, 2009 - 3:18 pm UTC

Tom,
Ref:
index not being used when it should be May 28, 2009 - 10am US/Eastern Reviewer: Sanji from Shelton, CT

I did collect the statistics on the column with skewed data and the query started picking up the apt indexes.

This resonates with my testcase wherein i did a CTAS order by the skewed column followed by statistcs on all columns size auto.

create table trans1 as select * from transactions order by taccountid;
exec dbms_stats.gather_table_stats('ur','trans1',method_opt=>'for all columns size auto',cascade=>true)

OPEN:SANJI:TRECS@ORADEV1>explain plan for
2 Select count(*) from Trans1
3 Where TAccountID IN (117,118,119,120,121,122)
4 and MatchedFlag = 'U'
5 and TransactionType <> 'IC'
6 /

Explained.

OPEN:SANJI:TRECS@ORADEV1>@rdbms/admin/utlxpls
-------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost |
-------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 9 | 11652 |
| 1 | SORT AGGREGATE | | 1 | 9 | |
| 2 | INLIST ITERATOR | | | | |
|* 3 | TABLE ACCESS BY INDEX ROWID| TRANS1 | 197K| 1733K| 11652 |
|* 4 | INDEX RANGE SCAN | TRANSACTIONS_TACCOUNTID1 | 397K| | 759 |
-------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - filter("TRANS1"."MATCHEDFLAG"='U' AND "TRANS1"."TRANSACTIONTYPE"<>'IC')
4 - access("TRANS1"."TACCOUNTID"=117 OR "TRANS1"."TACCOUNTID"=118 OR
"TRANS1"."TACCOUNTID"=119 OR "TRANS1"."TACCOUNTID"=120 OR
"TRANS1"."TACCOUNTID"=121 OR "TRANS1"."TACCOUNTID"=122)

I have couple of questions and would really appreciate if you could share some insight

1> Why "couldn't" the optimizer detect the skewed data when the histograms were created for "all columns size auto"
and "could" detect it when the histogram was created for only the skewed column ?

2>What should be the strategy going forward to collect statistics on this table...
Should i collect the statistics for only the skewed column as most of the queries refer this column in the where clause.

Rgds
Tom Kyte
May 28, 2009 - 5:15 pm UTC

1) auto "tries", but auto is just auto - we don't really have insight as to what it does under the covers in this case.

2) in general, in a transactional system that uses bind variables - you would not collect histograms at all (or only in certain cases). In a system where you are not using binds - you would generally collect them on many/most columns used in the where clause - with size 254 (might as well max it out..)

Performance MIN / MAX

Stan, May 28, 2009 - 4:49 pm UTC

Hi Tom,

thanks for your quick response. Sorry, cut and paste error the first query should not have had the

AND sub_elb.year_end_flag = 'Y'

So the MIN / MAX worked on the primary key.

Any given account could have a unique ledger balance entry on any given end date - So, account / end date is the primary key.

Here we are summing all the "last entries" for a group of accounts together - the last entries "before" a given date, say, month end, year end, etc. This gives us the current balance. Although I picked "year end flag" which invalidated the use of MIN / MAX this problem for us is universal as there are a lot of different types of queries which rely on the same method and different queries can have a number of different columns potentially used in the sub query depending on what the user is looking for. Every time an additional column is used and we can't use MIN / MAX performance literally degrades by a factor of 1 thousand - so however MIN / MAX works compared to the RANGE SCAN is remarkable.

I will apply the analytics method you show in a test environment and compare some real stats from the SGA.

Thanks Again!
Tom Kyte
May 28, 2009 - 5:27 pm UTC

think about how min/max works - it knows it only needs to look at one entry.


select max(column)
from t
where c1 = ?
and c2 = ?


if you have an index on (column) - it has to either

a) full scan t to find the max for c1=? and c2=?
b) index range scan DESC through the index on column - going from the index to the table, index to table over and over - until it hits a row where c1=? and c2=?. It might never find that row (it might not exist) or it might find it on the first try - and the way to write that query would be:

select column from (select column from t where c1=? and c2=? order by column desc) where rownum = 1;



if you have an index on (c1,column) or (c2,column) - pretty much the same, a little more efficient via the index - but still - index to table index to table to look up the other column value.


if you have an index on (c1,c2,column) or (c2,c1,column) then it can go right to c1=? and c2=? and reading the index in a descending fashion IMMEDIATELY give you the max(column) for that c1=? and c2=?. Just imagine what the data looks like in a big sorted list and how much work YOU would have to do to find the max(column) given the various big sorted lists you could present yourself. We do the same.

Performance MIN / MAX

Stan, May 28, 2009 - 6:27 pm UTC

Thanks Tom,

not having used analytics before I can't seem to get this to run...

I'm getting:

ERROR at line 7:
ORA-00937: not a single-group group function



EXPLAIN PLAN FOR
select *
from
(
SELECT SUM(decode(ela.ledger_acct, :b2, elb.balance_amt, 0)),
SUM(decode(ela.ledger_acct, :b1, elb.balance_amt, 0)),
elb.end_dt,
row_number() over (partition by elb.account_id order by elb.end_dt DESC)) rn
FROM ledger_account ela,
ledger_balance elb
WHERE ela.portfolio_acct = :b7
AND ela.base_currency = :b6
AND ela.local_currency = :b6
AND ela.acct_basis = :b5
AND ela.open_evt_id = :b4
AND ela.cls_evt_id = '0'
AND ela.class = 'TF'
AND ela.asset_grp = :b3
AND ela.ledger_acct IN(:b2, :b1)
AND ela.account_id = elb.account_id
and elb.year_end_flag = 'Y'
and elb.end_dt <= :b8
)
where rn = 1
;


Tom Kyte
May 29, 2009 - 8:06 am UTC

select SUM(decode(ledger_acct,   :b2,   balance_amt,   0)),
       SUM(decode(ledger_acct,   :b1,   balance_amt,   0))
  from
(
SELECT ela.ledger_acct, elb.balance_amt,
       elb.end_dt,
       row_number() over (partition by elb.account_id order by elb.end_dt 
DESC)) rn
FROM ledger_account ela,
  ledger_balance elb
WHERE ela.portfolio_acct = :b7
 AND ela.base_currency = :b6
 AND ela.local_currency = :b6
 AND ela.acct_basis = :b5
 AND ela.open_evt_id = :b4
 AND ela.cls_evt_id = '0'
 AND ela.class = 'TF'
 AND ela.asset_grp = :b3
 AND ela.ledger_acct IN(:b2,   :b1)
 AND ela.account_id = elb.account_id
 and elb.year_end_flag = 'Y'
 and elb.end_dt <= :b8
)
where rn = 1
;

For Stan

Narendra Prabhudesai, May 29, 2009 - 5:16 am UTC

Stan,

Just change the query to


EXPLAIN PLAN FOR
select SUM(elb1), SUM(elb2)
from
(
SELECT decode(ela.ledger_acct, :b2, elb.balance_amt, 0) elb1,
decode(ela.ledger_acct, :b1, elb.balance_amt, 0) elb2,
elb.end_dt,
row_number() over (partition by elb.account_id order by elb.end_dt DESC)) rn
FROM ledger_account ela,
ledger_balance elb
WHERE ela.portfolio_acct = :b7
AND ela.base_currency = :b6
AND ela.local_currency = :b6
AND ela.acct_basis = :b5
AND ela.open_evt_id = :b4
AND ela.cls_evt_id = '0'
AND ela.class = 'TF'
AND ela.asset_grp = :b3
AND ela.ledger_acct IN(:b2, :b1)
AND ela.account_id = elb.account_id
and elb.year_end_flag = 'Y'
and elb.end_dt <= :b8
)
where rn = 1


p.s. Apologies Tom for "jumping" on to your forum
Tom Kyte
May 29, 2009 - 8:34 am UTC

no worries, I "goofed" - but that is because I didn't have the table creates to actually test with.

I think about 100% of the time, when I try to do a SQL statement without actually being able to test it.... some little thing will be wrong.

Index not being used when it shoudl be

Sanji, May 29, 2009 - 5:04 pm UTC

Tom,
Ref
index not being used when it should be May 28, 2009 - 3pm US/Eastern Reviewer: Sanji from Shelton, CT

Apparently the statistics whether generated on 1 column, indexed columns or combination of columns, were not influencing the optimizer to pick the most efficient plan for other queries. It was working for 1 but not for others.

I did a CTAS of this table ordered by the most skewed data column (taccountid).
Then created indexes and generated statistics on all columns size 254.

Executed the same set of queries against this table and all the queries were picking up indexes where required.

So, i exported the statistics of this table into a stat table (TRANS_STAT) and updated column C5 which stores the owner name. Column C1 stores the table name and corresponding indexes, so i updated these to match the original table names and then i imported the statistics onto the original table.

Major success... The optimizer is rolling out the most efficient plans (as deemed) for all the queries.

So, in totality, we influenced the optimizer with statistics generated on another table with neatly arranged and ordered data to work similarly on the orignial table...

Thanks Tom for all the help.
Rgds

enabling trace has improved performance

Bala, June 17, 2009 - 2:19 am UTC

Hi Tom,

I have come across a wearied performance issues , We have Oracle Applications R12. Most of the users complains for invoice validation takes nearly 6 to 7 minutes . We have enabled the trace to check the issue , after enabling the trace invoice validation completes with in 20 to 30 Seconds.

I don't really understand how is this possible. After taking tkprof of that trace file , i don't find huge values too in the tkprof.

Can you please give me some tips . How to troubleshoot this issue.

Thank you.

Strange problem

Bhavesh Ghodasara, June 18, 2009 - 3:53 am UTC

hi Tom,
I encouneted one starnge problem.

Our produciton is on 10g. there is one table is_doc_master, which we analyzed almost daily.
there are 10 million rows in it. and we have index on ctt_insertdt.

My problem is that when i fire query for 21 days on that table. it is using index. but when
i fire query for 22 days it is using full scan.

Also forcibly when i give hint of rule then it is using index. and ofcourse the query with index returns result
very fast then the full scan.

Query-1)


select *
from is_doc_master a
where a.ctt_insertdt >= '01-APR-09'
AND a.ctt_insertdt < '21-APR-09'

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=ALL_ROWS 213 K 28958
FILTER
TABLE ACCESS BY INDEX ROWID PPSSUB99.IS_DOC_MASTER 213 K 19 M 28958
INDEX RANGE SCAN PPSSUB99.IDX_CTT_INSERTDT 213 K 815

Query-2)
select *
from is_doc_master a
where a.ctt_insertdt >= '01-APR-09'
AND a.ctt_insertdt < '22-APR-09'

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=ALL_ROWS 224 K 29048
FILTER
TABLE ACCESS FULL PPSSUB99.IS_DOC_MASTER 224 K 20 M 29048

Query-3)
select /*+ RULE */*
from is_doc_master a
where a.ctt_insertdt >= '01-APR-09'
AND a.ctt_insertdt < '22-APR-09'

Operation Object Name Rows Bytes Cost Object Node In/Out PStart PStop

SELECT STATEMENT Optimizer Mode=HINT: RULE
TABLE ACCESS BY INDEX ROWID PPSSUB99.IS_DOC_MASTER
INDEX RANGE SCAN PPSSUB99.IDX_CTT_INSERTDT



Please help.

Tom Kyte
June 18, 2009 - 3:08 pm UTC

first - stop comparing dates to strings, be explicit, always use to_date on the strings ALWAYS use a date format on the to_date call.


You are at what is known as a "tipping point", when you cross the boundary from 213k rows to 224k rows - the optimizer is saying "better to use a full scan". It is "correct" (if the row estimates are correct - are they?? are you getting 213,000 rows with query 1 and 224,000 with query 2) if every IO was a physical IO - but they are not (in real life)

do you have SYSTEM statistics - does the optimizer know what your true multiblock read count is, what your single and multiblock IO true speeds are? (not statistics on the dictionary, but statistics on your SYSTEM)

To "Bhavesh Ghodasara from Ahmedabad,India"

Narendra, June 18, 2009 - 4:28 am UTC

Not again...:)

Bhavesh,
you are (possibly) comparing dates with strings and that is (one of) the reason(s).

running TKPROF remotely

Vikram, June 22, 2009 - 11:21 am UTC

Hi Tom, is there a way we can run TKPROF remotely from the client machine? Typically we developers are not provided access to the database server.

Does oracle have inbuilt APIs for
1) running the TKPROF on any trace file.
2) reading the TKPROF file from the database server
3) Showing to the user the TKPROF output either as a DBMS_OUTPUT or into a database table.

Appreciate your input on this.

Regards,
Vikram
Tom Kyte
June 22, 2009 - 3:36 pm UTC

sql developer can be used - or tkprof on the client can be used and you can use

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:7115831027951

to get the trace.

bitmap indexes

A reader, July 03, 2009 - 9:50 am UTC

Hi Tom,

We have a table which has bitmap indexes on month key (YYYYMM), and the data is loaded for 12 months every month as type = 'PLAN'.
Now we need to load data for same 12 months as type = 'FORECAST'. If I load data in the same table, can first load and second load happen in parallel?

Regards,
Tom Kyte
July 06, 2009 - 7:36 pm UTC

if you use a parallel load (external table with parallel insert as select or sqlldr with direct=y parallel enabled) sure.

If you try to just do it from two sessions - probably not, as you'll hit massive contention on your bitmaps if they are using the same date values.

Clarification

A reader, July 07, 2009 - 2:27 pm UTC

Hi Tom,
Thanks.
Could please clarify this
If you try to just do it from two sessions - probably not, as you'll hit massive contention on your bitmaps if they are using the same date values.
Tom Kyte
July 07, 2009 - 7:09 pm UTC

a bitmap key points to many rows.

If two people try to insert a record with the same key, it is probable that one of the sessions will block.

ops$tkyte%ORA10GR2> create table emp
  2  as
  3  select *
  4    from scott.emp;

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create bitmap index job_idx on emp(job);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select ename, job from emp where ename like 'S%';

ENAME      JOB
---------- ---------
SMITH      CLERK
SCOTT      ANALYST

ops$tkyte%ORA10GR2> update emp set job = 'CLERK' where ename = 'SCOTT';

1 row updated.

<b>transaction 1 above has locked the bitmap key with CLERK (had to change a 0 to a 1 in the bitmap so we know that scott is now a clerk) and with ANALYST (had to change a 1 to a 0 so we reflect that scott is no longer an analyst)

transaction 2 (using a single session, two transactions - if you use two sessions - session 2 would just block - not deadlock, this is just a demo - the deadlock below represents a blocking lock in two sessions in real life) gets blocked

transaction 2 needs to modify the bitmap key of analyst and clerk as well - but cannot, not until transaction 1 commits
</b>
 
ops$tkyte%ORA10GR2> declare
  2      pragma autonomous_transaction;
  3  begin
  4      update emp set job = 'ANALYST' where ename = 'SMITH';
  5      commit;
  6  end;
  7  /
declare
*
ERROR at line 1:
ORA-00060: deadlock detected while waiting for resource
ORA-06512: at line 4


ops$tkyte%ORA10GR2> declare
  2      pragma autonomous_transaction;
  3  begin
  4      insert into emp(empno,job) values (1234,'CLERK');
  5      commit;
  6  end;
  7  /
declare
*
ERROR at line 1:
ORA-00060: deadlock detected while waiting for resource
ORA-06512: at line 4

<b>same for an insert, the insert in this case needs to modify the bitmap key with clerk, but cannot since the first transaction still has a lock on that bitmap key</b>


ops$tkyte%ORA10GR2> rollback;

Rollback complete.

SQL profile

A reader, July 14, 2009 - 4:07 pm UTC

When I do dbms_xplan.display for a SQL , it shows the plan and then it shows the following SQL profile was used .

Note
-----
- SQL profile "SYS_SQLPROF_0248232559084000" used for this statement




But , I have disabled the SQL profile , flushed the shared pool , buffer cache ( This is a test system ; not a production )
Still this SQL is picking up the SQL profile .


Select created , to_char(last_modified , 'dd-mon-yyyy hh:mi:ss') modified_date ,
status from DBA_SQL_PROFILES where name ='SYS_SQLPROF_0248232559084000';

CREATED MODIFIED_DATE STATUS
----------- -----------------------------------
4/9/2009 4: 14-jul-2009 12:05:58 DISABLED




Select first_load_time from gv$sql where sql_id = '2t1ba4mzh1msb';

FIRST_LOAD_TIME
-------------------
2009-07-14/15:01:30
2009-07-14/15:01:30
2009-07-14/15:01:30
2009-07-14/15:01:30



Tom Kyte
July 15, 2009 - 11:20 am UTC

display does an explain plan, what if you use display_cursor - which uses v$sql - which is "reality"?


A reader, July 15, 2009 - 11:25 am UTC

I did display_cursor(sqlid , planhashvalue)
Tom Kyte
July 15, 2009 - 12:29 pm UTC

.. When I do dbms_xplan.display for a SQL...

regarding display_cursor - that isn't what you said the first time.

why would you use planhashvalue?

I want a cut and paste of the entire sqlplus session showing all of the steps - from the call to disable, to the verification, to the flushing of the shared pool, to showing the plan is flushed, to showing the query executed, and then use display_cursor by itself with no inputs (set serveroutput off so dbms_output isn't called by sqlplus)

I just want to see step by step what you did - just like I always show you guys. A full cut and paste.


High I/O on Big Table

Raja, July 29, 2009 - 11:09 am UTC

Hi Tom,

We have a 20GB unpartitioned table and the query are showing high I/O on that table.

The AWR is showing us "db file sequential read" as the top most wait events.

Will partitioning the table will help reduce the I/O wait? And is the I/O wait is causing query performance issue?

Thanks for your time.

Regards,
Raja
Tom Kyte
August 03, 2009 - 2:21 pm UTC

probably not, close your eyes and think about it - envision what is happening now and what could happen later...


db file sequential read - that is single block IO, the IO you get when you range scan an index and then read a table by rowid.

You are not full scanning the table, you are using index access.

So, would partitioning reduce the number of blocks that need to be inspected in the table? Highly unlikely (like very near 0%) since you find those blocks by indexes - not via a full scan. every block you visit right now - you would still have to visit afterward.


partitioning can reduce the IO on the table by partitioning elimination - which would require you to be full scanning right now. But you are not.


Is there any opportunity for it to reduce IO? Yes, there is. But again, you'd have to close your eyes and envision the data yourself.


I'll give you an example whereby this could reduce IO. Let's say you have an indexed column that returns 5% of the table for any value (eg: where column = :x will return 5% of the table). So, we know this column has 20 discrete values. Right now, the values are spread out all over the place (eg: we can fit 20 rows on a block and if you looked at any given block - you would discover that the values for that column on that block are unique - therefore, EVERY BLOCK in the table right now has one of those rows).

So, now say you decide to list partition by this value - you create 20 partitions and each one has only a single value for that column. Now, if you looked at a block in each partition - it would have 20 rows on it, but all 20 rows would be the same column value.

A query of the form "where column = :x" would have to read only 5% of the table blocks it did before you partitioned in this case. We used partitioning to force clustering of data - all column = :x values are located together.



But again, this is not probable, it is an edge case - it it highly likely that partitioning will do nothing to reduce the IO's against this table for you.


Further, you wrote: nd is the I/O wait
is causing query performance issue?


you would have to tell us that as well - only you can answer that. How much of the query runtime is spent waiting on IO?

If it is 1%, no, this isn't the cause....

What does high waits on "db file sequential read" indicate

Sagar, August 06, 2009 - 12:37 pm UTC

Hi Tom,

If "db file sequential read" is single block read(index usage). Why does some queries give high waits on "db file sequential read"?. What does high waits on "db file sequential read" indicate?.
Tom Kyte
August 06, 2009 - 1:26 pm UTC

I don't know what else to say??

db file sequential read is the read of a single block from disk.

some queries you run do not find their data in the cache, hence they must read from disk.

when you read from disk, you wait for disk.

If you read lots of times from disk, you experience "high waits on IO" (we call this single block IO wait "db file sequential read" waits)

A high wait on db file sequential read means you are running a query that a) needs lots of blocks and b) most of those blocks are NOT in the cache yet.

Thanks

Sagar, August 06, 2009 - 1:57 pm UTC


Tune a query for a different version of DB

A reader, August 07, 2009 - 2:25 pm UTC

Tom,
We recently did a database upgrade from 10.2.0.1.0 to 10.2.0.4.0. One of the SQL in the new database is running without using indexes while in the
earlier environment it was using the indexes available on the columns. The following is the table structure.

DROP TABLE OBJECT CASCADE CONSTRAINTS ;

CREATE TABLE OBJECT_TABLE (
ID NUMBER (38) NOT NULL,
VERSION NUMBER NOT NULL,
P_VERSION NUMBER DEFAULT 0,
PARENT_ID NUMBER (38),
TYPE NUMBER NOT NULL,
STATUS_CD VARCHAR2 (1) NOT NULL,
APRV_STATUS_CD VARCHAR2 (1),
NAME VARCHAR2 (128),
NAME_LOWER VARCHAR2 (129),
PATH VARCHAR2 (700),
PATH_LOWER VARCHAR2 (701),
LABEL VARCHAR2 (128),
DESC_1 VARCHAR2 (512),
NOTES VARCHAR2 (2000),
BEGIN_DT DATE,
END_DT DATE,
PRIORITY NUMBER,
CREATE_DT DATE NOT NULL,
MODIFY_DT DATE NOT NULL,
CREATED_BY NUMBER (38) NOT NULL,
MODIFIED_BY NUMBER (38) NOT NULL,
ATTR_TEXT CLOB,
ATTR_UPTODATE VARCHAR2 (1) DEFAULT 'F',
DEL_COUNT NUMBER DEFAULT 0 NOT NULL,
DEL_STATUS_CD VARCHAR2 (1),
SYS_TIMESTAMP DATE DEFAULT SYSDATE,
CONSTRAINT XPKOBJECT
PRIMARY KEY ( ID, VERSION ) ) ;

CREATE INDEX XAKOBJ_NM_LOWER ON
OBJECT_TABLE(NAME_LOWER, VERSION)
;

CREATE INDEX XAKOBJ_PARENT ON
OBJECT_TABLE(PARENT_ID, VERSION, ID)
;

CREATE INDEX XAKOBJ_PATH_LOWER ON
OBJECT_TABLE(PATH_LOWER, VERSION)
;

CREATE INDEX XAKOBJ_CREATED_BY ON
OBJECT_TABLE(CREATED_BY)
;

CREATE INDEX OBJECT_IDX_007 ON
OBJECT_TABLE(TYPE, OBJ_ID)
;

CREATE INDEX OBJECT_IDX_006 ON
OBJECT_TABLE(PARENT_ID)
;

CREATE INDEX OBJECT_IDX_005 ON
OBJECT_TABLE(MODIFIED_BY)
;

CREATE INDEX OBJECT_IDX_008 ON
OBJECT_TABLE(TYPE, PARENT_ID, VERSION)
;

CREATE INDEX OBJECT_IDX_009 ON
OBJECT_TABLE(TYPE, ID, VERSION)
;

CREATE INDEX XAKOBJ_TYPE ON
OBJECT_TABLE(TYPE)
;

CREATE INDEX ROLE_OBJ_VER_LBL ON
OBJECT_TABLE(VERSION, LABEL)
;


$ sqlplus (prod_user@old_db)
Enter password:
Connected.
SQL> explain plan for SELECT TYPE, ID, NAME
2 FROM martini_store.OBJECT_TABLE
3 WHERE PARENT_ID=6757598526815142
4 AND VERSION=0
5 AND STATUS_CD <> 'D';

Explained.

SQL> @explain_plan.sql

Operation Object
------------------------------ ------------------------------
SELECT STATEMENT ()
TABLE ACCESS (BY INDEX ROWID) OBJECT_TABLE
INDEX (RANGE SCAN) XAKOBJ_PARENT

SQL> conn (prod_user@prod_db)
Enter password:
Connected.
SQL> delete from plan_table;

0 rows deleted.

SQL> commit;

Commit complete.

SQL> explain plan for SELECT TYPE, ID, NAME
2 FROM martini_store.OBJECT_TABLE
3 WHERE PARENT_ID=6757598526815142
4 AND VERSION=0
5 AND STATUS_CD <> 'D'
6
SQL> /

Explained.

SQL> @explain_plan.sql

Operation Object
------------------------------ ------------------------------
SELECT STATEMENT ()
TABLE ACCESS (FULL) OBJECT_TABLE

SQL> delete from plan_table;

2 rows deleted.

SQL> commit;

Commit complete.

SQL> explain plan for SELECT /*+ first_rows */ TYPE, ID, NAME
2 FROM martini_store.OBJECT_TABLE
3 WHERE PARENT_ID=6757598526815142
4 AND VERSION=0
5 AND STATUS_CD <> 'D'
6 /

Explained.

SQL> @explain_plan.sql

Operation Object
------------------------------ ------------------------------
SELECT STATEMENT ()
TABLE ACCESS (BY INDEX ROWID) OBJECT_TABLE
INDEX (RANGE SCAN) OBJECT_IDX_006

SQL>


My question is, why would the database use a different execution path when the DB version changes. Is it because it is a different optimizer? Also, changing the SQL to use the hint /*+ first_rows */ seems to work, but is this the right approach. Is there a different approach one can take to improve the performance of this query without changing the query (in terms of doing anything on the database server side). I ask this because this query is part of a third party tool, that we do not have access to (modify it). If all else fails, and changing the query is the only option, then we might have to reach out to the vendor, but in the interim I wanted to know what exactly was responsible for this behavior, and how best to improve performance.

Thanks!

Tom Kyte
August 07, 2009 - 2:42 pm UTC

you are missing the only useful information

estimated row counts :(

and you didn't use the CODE button, so it is really hard to read too.

SQL Tuning - Best approch

balu, August 08, 2009 - 3:45 am UTC

I have query which takes 3 views (each view again involve in 2 to 3 table joined) input and runs for long time. with no predicate it takes 1 hrs.
with predicate on month it comes in 2 min.
1.
we did threading by creating dynmic query with month predicate in pl/sql and create job for the query

2. each job will store in to common table named month_all

3. validate all jobs completed. ie. all query populate the data in month_all table.

4.
get the data from month_all and display it.
we are able get it done in 5 min.

is it any best/ideal way which oracle creates dynamically with threading concept

SORT GROUP BY

A reader, August 09, 2009 - 10:08 am UTC

Greetings thomas,

and thanks like always.

Can you help me with this query.

SELECT /*+choose*/ c.ND MSISDN,b.NDOS co_id,DECODE(b.datrs,NULL,'a','d') status,b.DATMS ACTIVATION_DATE,
b.DATRS DEACTIVATION_DATE,a.ncli customer_id,d.ABRV_PERS TITLE,a.PRENOM1 CCFNAME,a.NOM CCNAME,a.PRENOM2 CCLNAME,
DECODE(a.DATEN_RS,NULL,'a','d') customer_status,a.ncli custcode,NULL CONTACT_PERSON,NULL SHORT_MSG_NO,
NULL ORP_SERIAL_NO,c.ne AUTHORIZATION_FM,LQUAL_ABO||' => '||e.lcat cust_group,a.TYPE_IDENT DOC_TYPE,a.NREGC id_no,
b.GROUPE_FACT billcycle, MAX(datem_fact) LAST_BILL
, NULL BIRTHDATE,NULL NATIONALITY,NULL PASSWORD,a.NOM FULL_NAME,
SUM(MNT_SOLDE_FACT) CURRENT_BALANCE,
(SELECT NVL(SUM(mnt_com),0)
FROM com_t_all
WHERE ncli = a.ncli
AND nd = c.nd) UNBILLED_AMOUNT,
NULL PAYMENTNAME,NULL BANK_ACCOUNT_OWNER,NULL BANKACC_NO,NULL VALID_UNTIL,
NULL BANK_NAME,NULL FLEET_MANAGER,NULL PAYMENT_TYPE,NULL GROUP_CODE,null/*a.NREGC*/ CSCOMPREGNO,NULL NOTE,
NULL PAYMENT_SEQ_ID
FROM client a,dossier b,doslig0 c,p_cpers d,p_categorie e,facture f,P_QUALABO PQ
WHERE a.NCLI = b.NCLi
AND a.NCLI = c.NCLI
AND a.NCLI = f.NCLI (+)
AND b.NDOS = c.NDOS
AND a.CPERS = d.CPERS
AND a.CCAT = e.CCAT
AND A.CQUAL_ABO = PQ.CQUAL_ABO
AND c.DATDEB_LD = (SELECT MAX(DATDEB_LD) FROM doslig0 WHERE ncli = c.ncli AND ndos = c.ndos)
GROUP BY c.ND ,b.NDOS ,DECODE(b.datrs,NULL,'a','d') ,b.DATMS ,b.DATRS ,
a.ncli ,d.ABRV_PERS ,a.PRENOM1 ,a.NOM ,a.PRENOM2 ,
DECODE(a.DATEN_RS,NULL,'a','d'),PQ.LQUAL_ABO,e.lcat ,a.TYPE_IDENT ,a.NREGC ,
b.GROUPE_FACT,a.NOM ,a.NREGC,c.ne

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer=HINT: CHOOSE (Cost=142889575 Card
=1681227606 Bytes=386682349380)

1 0 SORT (AGGREGATE)
2 1 VIEW OF 'COM_T_ALL' (Cost=49 Card=6 Bytes=210)
3 2 SORT (UNIQUE) (Cost=49 Card=6 Bytes=3378)
4 3 UNION-ALL
5 4 TABLE ACCESS (BY INDEX ROWID) OF 'COM_T_A' (Cost=1
Card=1 Bytes=563)

6 5 INDEX (RANGE SCAN) OF 'I_COM_T_A_1' (NON-UNIQUE)
(Cost=2 Card=8)

7 4 TABLE ACCESS (BY INDEX ROWID) OF 'COM_T_B' (Cost=6
Card=1 Bytes=563)

8 7 INDEX (RANGE SCAN) OF 'I_COM_T_B_1' (NON-UNIQUE)
(Cost=2 Card=8)

9 4 TABLE ACCESS (BY INDEX ROWID) OF 'COM_T_C' (Cost=6
Card=1 Bytes=563)

10 9 INDEX (RANGE SCAN) OF 'I_COM_T_C_1' (NON-UNIQUE)
(Cost=2 Card=8)

11 4 TABLE ACCESS (BY INDEX ROWID) OF 'COM_T_D' (Cost=6
Card=1 Bytes=563)

12 11 INDEX (RANGE SCAN) OF 'I_COM_T_D_1' (NON-UNIQUE)
(Cost=2 Card=8)

13 4 TABLE ACCESS (BY INDEX ROWID) OF 'COM_T_E' (Cost=6
Card=1 Bytes=563)

14 13 INDEX (RANGE SCAN) OF 'I_COM_T_E_1' (NON-UNIQUE)
(Cost=2 Card=8)

15 4 TABLE ACCESS (BY INDEX ROWID) OF 'COM_T_F' (Cost=6
Card=1 Bytes=563)

16 15 INDEX (RANGE SCAN) OF 'I_COM_T_F_1' (NON-UNIQUE)
(Cost=2 Card=8)

17 0 SORT (GROUP BY) (Cost=142889575 Card=1681227606 Bytes=3866
82349380)

18 17 HASH JOIN (Cost=88988 Card=1681227606 Bytes=386682349380
)

19 18 TABLE ACCESS (FULL) OF 'P_CPERS' (Cost=2 Card=2000 Byt
es=14000)

20 18 HASH JOIN (Cost=88512 Card=9246752 Bytes=2062025696)
21 20 TABLE ACCESS (FULL) OF 'P_QUALABO' (Cost=2 Card=2000
Bytes=60000)

22 20 HASH JOIN (Cost=88506 Card=27740 Bytes=5353820)
23 22 TABLE ACCESS (FULL) OF 'P_CATEGORIE' (Cost=2 Card=
2000 Bytes=40000)

24 22 NESTED LOOPS (OUTER) (Cost=88503 Card=971 Bytes=16
7983)

25 24 HASH JOIN (Cost=87453 Card=14 Bytes=2226)
26 25 TABLE ACCESS (BY INDEX ROWID) OF 'DOSLIG0' (Co
st=3 Card=1 Bytes=36)

27 26 NESTED LOOPS (Cost=12480 Card=14 Bytes=1988)
28 27 NESTED LOOPS (Cost=6480 Card=2000 Bytes=21
2000)

29 28 TABLE ACCESS (FULL) OF 'DOSSIER' (Cost=2
480 Card=2000 Bytes=92000)

30 28 TABLE ACCESS (BY INDEX ROWID) OF 'CLIENT
' (Cost=2 Card=1 Bytes=60)

31 30 INDEX (UNIQUE SCAN) OF 'I_CLIENT_U1' (
UNIQUE) (Cost=1 Card=1)

32 27 INDEX (RANGE SCAN) OF 'I_DOSLIG0_U1' (UNIQ
UE) (Cost=2 Card=1)

33 25 VIEW OF 'VW_SQ_1' (Cost=74955 Card=13785258 By
tes=234349386)

34 33 SORT (GROUP BY) (Cost=74955 Card=13785258 By
tes=206778870)

35 34 INDEX (FULL SCAN) OF 'I_DOSLIG0_U1' (UNIQU
E) (Cost=74955 Card=13785258 Bytes=206778870)

36 24 TABLE ACCESS (BY INDEX ROWID) OF 'FACTURE' (Cost
=75 Card=69 Bytes=966)

37 36 INDEX (RANGE SCAN) OF 'I_FACTURE_1' (NON-UNIQU
E) (Cost=3 Card=74)
Tom Kyte
August 11, 2009 - 1:36 pm UTC

looks good to me.

not sure what else you were expecting anyone to say?

Slow query performance

A reader, August 10, 2009 - 6:25 am UTC

Hi Tom,

First of all thank you very much for your support to Oracle community. 

We are running Oracle 10.2.0.4 on HP-UX 11.11 platform. The application is experiencing performance problem with its SEARCH functionality. Unfortunately query rewrite (Code change) is not an option as the application was not developed by our developers and third party vendor will take at least 4 weeks for any code change which will cost money to our company this management would not like to go to that path. It would be great if you could suggest and index strategy to help below query...

#######
Query:
#######

select
        *
    from
        ( select
            distinct cmelog0_.mesg_id as mesg1_1_,
            cmelog0_.app_datestamp as app2_1_,
            cmelog0_.app_mesg_id as app3_1_,
            cmelog0_.app_name as app4_1_,
            cmelog0_.app_type as app5_1_,
            cmelog0_.insert_date_time as insert6_1_,
            cmelog0_.mesg_datestamp as mesg7_1_,
            cmelog0_.module_name as module8_1_,
            cmelog0_.project_name as project9_1_,
            cmelog0_.service_name as service10_1_,
            cmelog0_.unit_name as unit11_1_
        from
            SBYN_CSF_R3.csf_cme_log cmelog0_,
            SBYN_CSF_R3.csf_user_fields userfields1_,
            SBYN_CSF_R3.csf_user_fields userfields2_,
            SBYN_CSF_R3.csf_user_fields userfields3_
        where
            cmelog0_.mesg_id=userfields1_.mesg_id
            and cmelog0_.mesg_id=userfields2_.mesg_id
            and cmelog0_.mesg_id=userfields3_.mesg_id
            and (
                cmelog0_.insert_date_time = '01-MAY-08'
                or cmelog0_.insert_date_time= '15-JUN-08'
                or cmelog0_.insert_date_time> '01-MAY-08'
                and cmelog0_.insert_date_time< '15-JUN-08')
            and ( userfields1_.field_name like '%' )
            and (userfields1_.field_value like '%')
            and (userfields1_.field_name like '%')
            and (userfields1_.field_value like '%')
            and (cmelog0_.app_mesg_id like '%')
            and userfields3_.field_name = 'Interface'
            and (userfields3_.field_value like 'IF5B')
            and userfields2_.field_name= 'State'
            and (userfields2_.field_value like '%')
            and cmelog0_.insert_date_time=(
                select
                    max(cmelog4_.insert_date_time)
                from
                    SBYN_CSF_R3.csf_cme_log cmelog4_,
                    SBYN_CSF_R3.csf_user_fields userfields5_
                where
                    cmelog4_.mesg_id=userfields5_.mesg_id
                    and userfields5_.field_name= 'State'
                    and cmelog4_.app_mesg_id=cmelog0_.app_mesg_id
            )
        order by
            cmelog0_.insert_date_time )
        where
            rownum <= 100;
############
Tkprof
############
call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      1.04       1.02          0          0          2           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        1     92.31     276.25     282706   12490864          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3     93.35     277.28     282706   12490864          2           0

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 36

Rows     Row Source Operation
-------  ---------------------------------------------------
      0  COUNT STOPKEY (cr=12490864 pr=282706 pw=1178 time=276258244 us)
      0   VIEW  (cr=12490864 pr=282706 pw=1178 time=276258207 us)
      0    SORT ORDER BY STOPKEY (cr=12490864 pr=282706 pw=1178 time=276258202 us)
      0     SORT UNIQUE (cr=12490864 pr=282706 pw=1178 time=276258168 us)
      0      TABLE ACCESS BY INDEX ROWID CSF_USER_FIELDS (cr=12490864 pr=282706 pw=1178 time=276258123 us)
      1       NESTED LOOPS  (cr=12490864 pr=282706 pw=1178 time=276258104 us)
      0        NESTED LOOPS  (cr=12490864 pr=282706 pw=1178 time=276258100 us)
      0         NESTED LOOPS  (cr=12490864 pr=282706 pw=1178 time=276258097 us)
   2862          NESTED LOOPS  (cr=12479041 pr=279013 pw=1178 time=243818507 us)
 309704           VIEW  VW_SQ_1 (cr=11855769 pr=267438 pw=1178 time=238047064 us)
 309704            HASH GROUP BY (cr=11855769 pr=267438 pw=1178 time=237737359 us)
2871456             NESTED LOOPS  (cr=11855728 pr=266257 pw=0 time=232647112 us)
2871553              TABLE ACCESS FULL CSF_USER_FIELDS (cr=369514 pr=151114 pw=0 time=126371748 us)
2871456              TABLE ACCESS BY INDEX ROWID CSF_CME_LOG (cr=11486214 pr=115143 pw=0 time=121430973 us)
2871553               INDEX UNIQUE SCAN PK_CSF_CME_LOG5 (cr=8614661 pr=34411 pw=0 time=88810006 us)(object id 6881)
   2862           TABLE ACCESS BY INDEX ROWID CSF_CME_LOG (cr=623272 pr=11575 pw=0 time=30634008 us)
   2862            INDEX RANGE SCAN Q1_DESC (cr=620410 pr=9908 pw=0 time=25919071 us)(object id 80697)
      0          TABLE ACCESS BY INDEX ROWID CSF_USER_FIELDS (cr=11823 pr=3693 pw=0 time=7011498 us)
  17633           INDEX RANGE SCAN MESGID_INDEX (cr=8781 pr=1376 pw=0 time=2059654 us)(object id 80968)
      0         TABLE ACCESS BY INDEX ROWID CSF_USER_FIELDS (cr=0 pr=0 pw=0 time=0 us)
      0          INDEX RANGE SCAN MESGID_INDEX (cr=0 pr=0 pw=0 time=0 us)(object id 80968)
      0        INDEX RANGE SCAN MESGID_INDEX (cr=0 pr=0 pw=0 time=0 us)(object id 80968)

Below is info about table involved in the query:

SQL> desc SBYN_CSF_R3.csf_user_fields
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 MESG_ID                                   NOT NULL VARCHAR2(128)
 SEQUENCE_ID                               NOT NULL NUMBER(38)
 FIELD_NAME                                         VARCHAR2(512)
 FIELD_VALUE                                        VARCHAR2(512)

Number of records in the table=25338616

Indexes on the table:

PK_CSF_USR_FLDS (Primary Key) on ("MESG_ID", "SEQUENCE_ID")
MESGID_INDEX on ("MESG_ID")
BITMAP index INTEGRATION_FIELD_VALUE_BITMAP on ("FIELD_NAME", "FIELD_VALUE")


SQL> desc SBYN_CSF_R3.csf_cme_log
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 MESG_ID                                   NOT NULL VARCHAR2(128)
 MESG_DATESTAMP                            NOT NULL TIMESTAMP(6)
 APP_MESG_ID                                        VARCHAR2(128)
 APP_DATESTAMP                                      TIMESTAMP(6)
 PROJECT_NAME                                       VARCHAR2(128)
 APP_TYPE                                  NOT NULL VARCHAR2(128)
 APP_NAME                                           VARCHAR2(128)
 SERVICE_NAME                              NOT NULL VARCHAR2(128)
 MODULE_NAME                               NOT NULL VARCHAR2(128)
 UNIT_NAME                                 NOT NULL VARCHAR2(128)
 INSERT_DATE_TIME                                   TIMESTAMP(6)

Total number of records in the table=3937303

Indexes on the table:
PK_CSF_CME_LOG5 (Primary Key) on (MESG_ID)
CSF_CME_LOG_APP_MESG_ID on (APP_MESG_ID)
Function based index Q1_DESC  on ("INSERT_DATE_TIME" DESC)

Statistics are gathered on both the table using Oracle 10G default method...

Can you please suggest how to improve performance of above query??

Thanks in advance..

Cheers,



Tune a query for a different version of DB

Jayanth Kalluri, August 11, 2009 - 5:48 pm UTC

Sorry about the formatting, Tom. I was using a relatively new browser (Chrome), that didn't quite do what the Code button wanted it to do, and I didn't realize it was the browsers fault.

Coming to the question that I asked previously, after a couple of days of persuasion, the DBA gathered statistics for the full table, instead of the 1% (that he did when the migration was done), and that fixed the query execution time.

I had one question though. What do you mean by estimated row counts? Is it the values from the rows column when you run autotrace? I copied the full autotrace on that sql below, but unfortunately since the statistics were gathered on the table, it is now using the index, so my question is no longer valid I guess.

Please do let me know if my understanding of estimated row counts is right, or what it actually means.

no rows selected

Elapsed: 00:00:00.09

Execution Plan
----------------------------------------------------------
Plan hash value: 2483285859

----------------------------------------------------------------------------------------------
| Id  | Operation                   | Name           | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                |     1 |    29 |     4   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| OBJECT         |     1 |    29 |     4   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | OBJECT_IDX_006 |     1 |       |     3   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("OBJ_STATUS_CD"<>'D' AND "VERSION"=0)
   2 - access("OBJ_PARENT_ID"=6757598526815142)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          3  consistent gets
          0  physical reads
          0  redo size
        347  bytes sent via SQL*Net to client
        339  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          0  rows processed

17:13:16 SQL>


Thanks!
Tom Kyte
August 13, 2009 - 9:14 am UTC

... What do you mean by estimated row counts? Is it the values from the rows column when you run autotrace? ...

yes.

Tuning Packges

Rajeshwaran, Jeyabal, August 12, 2009 - 11:39 am UTC

Tom,

  I Use a package that reads data from a Flat file (Pipe Delimited file using UTL_FILE packages).
  The code inside the package is fully done in Pl/SQL Collections (mostly in Associative Array & Nested tables) and collections are Delete once utilized.
  To load a file of about 27MB it tooks nearly 45 mins. I need to tune the package now to make things faster.
  If there are some SQL statements inside the package then i can get help from SQLTrace or TKPROF or dbms_sqltune.
  I thought to make use of dbms_profiler package but DBA's had not granted Privilege.
  Since only Collections are involved how can I Identify the areas that is Consuming more Time? 
   
Thanks,
Rajesh. 

Tom Kyte
August 13, 2009 - 12:04 pm UTC

you should erase all of the procedural code and use an external table - fast, easy, correct approach.

High I/O on Big Table

Raja, August 13, 2009 - 4:24 am UTC

Hi Tom,

Thanks for your valuable answer. It was helpful to underastand the concept of I/O wait and partitioning.

This is a followup from one of the above thread :
Further, you wrote: nd is the I/O wait
is causing query performance issue?

The answer to the above question is :

My query run with an average time of 0.090 secs for 715977 executions. So it comes around 17 hours for a day in total. Out of this the "sequential I/O wait" on this big table is 92.18% around 14 hours.

As you indicated yes the query is doing a very well index scan, but still the query is having high I/O.

We are planning to purge some of the data for this big 20GB table to have reduce the size. Will that help reduce the high I/O on it?

What generally is the solution for high I/O scenario? Do we need to think of some other index?

Thanks again.
Raja

Tom Kyte
August 13, 2009 - 12:17 pm UTC

.. Out of this the "sequential I/O wait"
on this big table is 92.18% around 14 hours.
....

how did you figure that?


... We are planning to purge some of the data for this big 20GB table to have
reduce the size. Will that help reduce the high I/O on it?
....

probably not - think about it.... close your eyes, envision what will happen before and after the purge - would it reduce the physical IO's?

I'm not yet convinced you have an IO problem - tell me how you arrived at that 14 hour number.

High I/O on Big Table

Raja, August 14, 2009 - 9:07 am UTC

Thanks Tom,

These data are from my monitoring tool from symantec.

As my query run with an average time of 0.090 secs for 715977 executions. So it comes around 17 hours
for a day in total. Out of this the "sequential I/O wait" on this big table is 92.18% (All these data are from the tool and I calculated a 92.18% of 17 hours to be around 14 hours)

Sorry if this calculation is wrong.

Is there any other method that I can prove this high I/O?

Thanks again,
Raja

Tom Kyte
August 24, 2009 - 7:48 am UTC

... These data are from my monitoring tool from symantec. ...

that means nothing to me, I have no idea how they compute what they compute or if you are interpreting the numbers correctly.

Use statspack or AWR data to see what is happening - we can all agree with what it means.



Change in Execution Plan

Vengata N Guruswamy, August 21, 2009 - 7:25 pm UTC

Hi Tom,

What are the circumstances the execution plan for any sql which is running fine suddenly changes. Atleast from one of the issues faced recently in a siebel database, I found that the plan for a query changed from skip scan to range scan on different index .The plan change had a lot of impact on the application and the db performance by slowing down db and spiking cpu utilization. Then the solution was flushing the shared pool and then the proper plan was restored automatically. The cpu consumption came down.

The plan change I came to know from AWR history tables. Can you please throw any light on this? I have never asked question as I always get answer when ever I search through your site. But this time I am really confused from where to start?
Tom Kyte
August 25, 2009 - 9:00 am UTC

there are many reasons

every time a query is hard parsed, it could come up with a different plan than was in the shared pool the last time it was hard parsed.

So, you need to understand two things

a) what will cause hard parses - these can introduce different plans over time.
b) why would a plan change


a) is rather straight forward. some things would be:

It could be the first time the query is executed after a database restart, we have to hard parse.

The sql might have aged out of the shared pool (make room for other sql).

The environment the sql is parsed in might be different (i.e. I parsed using first_rows in the session, you parsed using all_rows).

The sql might look the same but is not (select * from t - when I run it, it queries tkyte.t, when you do, it queries scott.t).

The underlying objects may have had new statistics and the old query plan was invalidated in the shared pool so as to force a hard parse to use the new statistics

You did some ddl on the underlying objects (add index, drop index for example)


b) is a little trickier. What I would suspect in this case however is bind peeking

http://www.google.com/search?q=site%3Atkyte.blogspot.com+bind+peeking

When you executed the query the first time, the skip scan was appropriate GIVEN THE BIND VALUES present when you hard parsed. Then, the next hard parse picked an index range scan based on the BIND VALUES PRESENT when that was hard parsed.

Thanks a Lot

Vengata N Guruswamy, August 28, 2009 - 2:32 pm UTC

Hi Tom,

Thanks for the information. I will check and get back to you.

Thanks,
Vengata

strange optimization

Mauro, September 02, 2009 - 1:02 pm UTC

Respectable and honorable TOM!

can you explain why it happens?

look at the two query,
only by adding "||''" I have halved the cost

many many thanks


SELECT *
FROM ps_si_anag_tit c, ps_si_insoluti a, ps_si_case b
WHERE a.si_case_id = b.si_case_id
AND c.si_co_pan = a.si_co_pan_str
AND si_co_pan = '111111111111111111111111'




----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=14 Card=1 Bytes=345)
1 0 MERGE JOIN (CARTESIAN) (Cost=14 Card=1 Bytes=345)
2 1 NESTED LOOPS (Cost=11 Card=1 Bytes=202)
3 2 TABLE ACCESS (FULL) OF 'PS_SI_INSOLUTI' (Cost=9 Card=1
Bytes=131)

4 2 TABLE ACCESS (BY INDEX ROWID) OF 'PS_SI_CASE' (Cost=2
Card=1 Bytes=71)

5 4 INDEX (UNIQUE SCAN) OF 'PS_SI_CASE' (UNIQUE) (Cost=1
Card=1)

6 1 BUFFER (SORT) (Cost=12 Card=1 Bytes=143)
7 6 TABLE ACCESS (BY INDEX ROWID) OF 'PS_SI_ANAG_TIT' (Cos
t=3 Card=1 Bytes=143)

8 7 INDEX (RANGE SCAN) OF 'PS0SI_ANAG_TIT' (NON-UNIQUE)
(Cost=2 Card=1)





Statistiche
----------------------------------------------------------
0 recursive calls
0 db block gets
76 consistent gets
74 physical reads
0 redo size
2273 bytes sent via SQL*Net to client
236 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed




SELECT *
FROM ps_si_anag_tit c, ps_si_insoluti a, ps_si_case b
WHERE a.si_case_id = b.si_case_id
AND c.si_co_pan||'' = a.si_co_pan_str
AND si_co_pan = '111111111111111111111111'




----------------------------------------------------------
0 SELECT STATEMENT Optimizer=CHOOSE (Cost=7 Card=1 Bytes=345)
1 0 NESTED LOOPS (Cost=7 Card=1 Bytes=345)
2 1 NESTED LOOPS (Cost=5 Card=1 Bytes=274)
3 2 TABLE ACCESS (BY INDEX ROWID) OF 'PS_SI_ANAG_TIT' (Cos
t=4 Card=1 Bytes=143)

4 3 INDEX (RANGE SCAN) OF 'PS0SI_ANAG_TIT' (NON-UNIQUE)
(Cost=3 Card=1)

5 2 TABLE ACCESS (BY INDEX ROWID) OF 'PS_SI_INSOLUTI' (Cos
t=1 Card=1 Bytes=131)

6 5 INDEX (UNIQUE SCAN) OF 'PS_SI_INSOLUTI' (UNIQUE)
7 1 TABLE ACCESS (BY INDEX ROWID) OF 'PS_SI_CASE' (Cost=2 Ca
rd=1 Bytes=71)

8 7 INDEX (UNIQUE SCAN) OF 'PS_SI_CASE' (UNIQUE) (Cost=1 C
ard=1)





Statistiche
----------------------------------------------------------
0 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
2282 bytes sent via SQL*Net to client
236 bytes received via SQL*Net from client
1 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
0 rows processed
Tom Kyte
September 02, 2009 - 1:24 pm UTC

c.si_co_pan||''

obviates an index access to that column, you caused the plan to change. you caused the estimated cardinalities to change.

Look at the card= values in the plans
look at the actuals in a tkprof.



or, if you have current versions, you can use this technique to see what the card= values are versus the actuals:

ops$tkyte%ORA10GR2> create table t
  2  as
  3  select decode( mod(rownum,2), 0, 'Y', 'N' ) f1,
  4         decode( mod(rownum,2), 0, 'N', 'Y' ) f2,
  5             a.*
  6    from all_objects a
  7  /

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx on t(f1,f2);

Index created.

ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats( user, 'T', estimate_percent => 100, method_opt=> 'for all indexed columns size 254', cascade => true );

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select num_rows from user_tables where table_name = 'T';

  NUM_ROWS
----------
     49774

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set serveroutput off
ops$tkyte%ORA10GR2> select /*+ gather_plan_statistics */ f1, f2, owner
  2    from t
  3   where f1 = 'N'
  4     and f2 = 'N'
  5  /

no rows selected

ops$tkyte%ORA10GR2> select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
SQL_ID  ag6yuzvnzypd9, child number 0
-------------------------------------
select /*+ gather_plan_statistics */ f1, f2, owner   from t  where f1 = 'N'
   and f2 = 'N'

Plan hash value: 1601196873

------------------------------------------------------------------------------------
| Id  | Operation         | Name | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
------------------------------------------------------------------------------------
|*  1 |  TABLE ACCESS FULL| T    |      1 |  12444 |      0 |00:00:00.01 |     717 |
------------------------------------------------------------------------------------

<b>so, we can see the e-rows (estimated cardinality) was 12,444 - that is about 1/4 of the data.  That is because the optimizer knows f1='N' gets 50% of the rows and f2='N' gets 50% of the rows but doesn't know (yet) about the relationship between f1 and f2 (there are no N,N or Y,Y rows).  So, lets 'fix' that, here is one way</b>

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(("F1"='N' AND "F2"='N'))


18 rows selected.

ops$tkyte%ORA10GR2> select /*+ gather_plan_statistics <b>dynamic_sampling( t 3 ) </b>*/ f1, f2, owner
  2    from t
  3   where f1 = 'N'
  4     and f2 = 'N'
  5  /

no rows selected

ops$tkyte%ORA10GR2> select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
SQL_ID  dncuuqknurcsv, child number 0
-------------------------------------
select /*+ gather_plan_statistics dynamic_sampling( t 3 ) */ f1, f2, owner   from t
where f1 = 'N'    and f2 = 'N'

Plan hash value: 470836197

-----------------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
-----------------------------------------------------------------------------------------------
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |      1 |      5 |      0 |00:00:00.01 |       2 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |      1 |      5 |      0 |00:00:00.01 |       2 |
-----------------------------------------------------------------------------------------------

<b>now the e-rows are much closer to the a-rows AND the plan changed as a result.</b>

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("F1"='N' AND "F2"='N')

Note
-----
   - dynamic sampling used for this statement


23 rows selected.



Your estimated card=values are likely off by a bit - leading it to chose one plan over the other - by using the ||"" 'trick', you made one plan not possible and it chose something else.

A reader, September 02, 2009 - 2:27 pm UTC

In above reply you already create index and gather stats on table, then why when you run first time

select /*+ gather_plan_statistics */ optimizer does not pickup right card


Thanks


Tom Kyte
September 02, 2009 - 2:30 pm UTC

the optimizer knows

a) there are about 50,000 records in the table
b) 50% of them are f1=n
c) 50% of them are f2=n

that is what is knows. Now, based on that, how many are

f1=n and f2=n

using simple statistics and guess that the two are independent - then the probability of f1=n (50%) times the probability of f2=n (50%) is 25%, so 1/4th of the data is assumed to be returned.

The optimizer works with imperfect information and uses simple statistics to fill in the blanks.

I fixed its guessing by using dynamic sampling
https://www.oracle.com/technetwork/issue-archive/2009/09-jan/o19asktom-086775.html

other approaches could have been

extended statistics in 11g - we could gather statistics on f1,f2 together.

sql profiles

Difference between Plan output & Auto Trace output

craty, September 07, 2009 - 9:02 am UTC

Thanks for this wonderful article. I just have a simple query based on your responses.

As evident from your above explanations, it seems the plan output & auto trace output are different. The former one tells what I expect and latter one tells us what we got.

Can you please help me understand better how they are calculated so that I can actually understand the difference between them.

Pardon me if this very novice query.
Tom Kyte
September 07, 2009 - 11:08 am UTC

no, plan output is what autotrace gives.

there is the explain plan
there is reality (row source operation in tkprof, v$sql_plan queries)


explain plans are 'calculated' without being able to bind peek
without knowing the datatype of the binds
using the current sessions environment
using dynamic sampling as of the point in time of the explain plan

whereas reality is what the optimizer did to generate the code to run a query.
it used bind peeking
it used datatypes of binds
it used the session environment that was in place when the parse occurred
it dynamically sampled at hard parse time.

craty, September 08, 2009 - 1:24 am UTC

Thanks for your above clarification Tom regarding explain plan and auto-trace.

But, as you said if explain plan is the output of auto-trace, then why do we have these both as two different options in Oracle SQL Developer.

In SQL Developer, you can find two options - Explain Plan (F6) & AutoTrace (F10). If explain plan is the output of auto-trace then why do we have a separate button from explain plan.

More-over when I try to AutoTrace a sql query after entering the bind variable values, its showing me below error message - No Data in v$sql_plan, table or view does not exist error.

Please clarify the above two queries.

Thanks
Tom Kyte
September 08, 2009 - 6:04 am UTC

autotrace runs the statement and displays more than just a plan

explain plan just shows a plan, and does not run a statement.


and it could be that autotrace in sqldeveloper (I use sqlplus - sqlplus uses explain plan) uses v$sql_plan which would mean that it shows the actual plan - whereas explain plan would show a probable plan, one that might or might not be used.

Rebuild table

KC YEUNG, September 08, 2009 - 2:50 pm UTC

Tom,

"You might be tempted therefore to run out and try to rebuild all of your tables now to make all indexes have a good clustering factor, but that would be a waste of time in most cases. It will affect cases where you do index range scans of a large percentage of a table."

I don't get the idea from the above statement very well (quoted from your Expert Oracle book).

1. Why it is a waste of time in most cases? Can you give an example?

2. Why it will affect "index range scans of a large percentage of a table"? Does it affect positively or negatively in terms of performance?

Thanks.


Tom Kyte
September 09, 2009 - 6:03 am UTC

1) in most cases, you are not doing huge range scans. So, in most cases - it is not necessary. and remember - you can only sort the table on disk one way - so in general ONLY ONE index can have a "good clustering factor" - so it wouldn't even begin to make sense to do this to make "all indexes have a good clustering factor"

2) did you read the example in the book? I used an organized table and a disorganized table. I demonstrated how we stopped range scanning the index against the disorganized table well before the organized table.

I tried to demonstrate that if the data in the table is ordered by the index key (has a good clustering factor) then range scans for "lots of rows" will be efficient enough to use the index.


You might want to work through the examples in that chapter and visualize how the data is laid out on disk in all of the different cases. I cannot really expound on it further - I said it as clearly as I could - with examples and lots of detail.


The "better" the clustering factor will have us use the index for larger and larger range scans of the data.

implicit conversion

A reader, September 09, 2009 - 9:04 am UTC

Tom,

There is a column defined as varchar2 with an index. Looking at the data (numbers only), if query is issued without quotes for the indexed column, will Oracle (10g) implicitly convert, and use the index?
Tom Kyte
September 14, 2009 - 10:04 am UTC

when you compare a number to a string, the string is (has to be) converted into a number first, the index would not be useful.

You should NOT do that - if the data is numbers only, and the data is supposed to be a number, the use of the varchar2 datatype would be stupid.

the strings 1.0 1.0000000 +1 +1.0000000000000000 are all the number "1", the strings

1,0
1.0

both might be the number 1 depending on where you live, hence strings are promoted to numbers when you compare strings to numbers.

But you should never never never never use a string to store a number - if you do, stop saying "I am using a string to store a number", start saying "I'm using a string <period>" And compare it to another string.

ops$tkyte%ORA10GR2> create table t ( x varchar2(10) primary key );

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from t where x = 1;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |     7 |     2   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| T    |     1 |     7 |     2   (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(TO_NUMBER("X")=1)

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> select * from t where x = '1';

Execution Plan
----------------------------------------------------------
Plan hash value: 1848078584

----------------------------------------------------------------------------------
| Id  | Operation         | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |              |     1 |     7 |     1   (0)| 00:00:01 |
|*  1 |  INDEX UNIQUE SCAN| SYS_C0038969 |     1 |     7 |     1   (0)| 00:00:01 |
----------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("X"='1')

ops$tkyte%ORA10GR2> set autotrace off

Rebuild Table

KC, September 09, 2009 - 10:29 am UTC

Hi Tom,

I have re-read the colocated/disorganized table examples and I am now very clear about the message being delivered in that section.

On the same chapter you have mention that it "is not identical" when dump data from production and load it into development. Not being identical because the physical organization of data is different.

So how can we make production and development identical? How can we ensure that the physical organization is the same?

Reason #1 why I might want to doing this is to simulate or reproduce production behavior / problem being observed.

Reason #2 is to look for a best practice to prepare a production-like environment for testing and benchmark performance tuning code before the code goes to Live.

Thanks
Tom Kyte
September 14, 2009 - 10:09 am UTC

... So how can we make production and development identical? How can we ensure that
the physical organization is the same?
...

easy: RESTORE BACKUP

it makes sure that your DBA can (you might be surprised! many people would be - that their DBA cannot restore their backups in their sleep - the DBA might have to spend quite a while figuring out how to do that - which is a GOOD THING, then when they need to - they will know how)


Clustering Factor

Leonard, September 10, 2009 - 8:42 am UTC

Hi Tom,

One question about clustering factor of an index:

What is the best way to improve it so that the I can achieve a good clustering value for an index?
Tom Kyte
September 14, 2009 - 11:23 am UTC

"it depends"


say you have a stock quote table, the primary key is stock_symbol and dt.

the data arrives day by day - so that the data for any given stock symbol is widely scattered throughout the table.

you frequently query "where stock_symbol = :x and dt >= sysdate-20" or "where stock_symbol = :x" or whatever - but mostly via "stock_symbol".

It would be nice to have all of the data for any given stock symbol stored "together" so that the data for ORCL is on as few blocks in the table as possible.

methods:

a) list partition by stock symbol, create a separate partition for each (might not be feasible, then again, might be)

b) Index Organized table - primary key(stock_symbol,dt), the data will be stored on the blocks sorted by stock_symbol and then by date - all data for ORCL will be near other ORCL data)

c) sorted hash cluster - hash key = stock_symbol, sort key = dt

d) b*tree cluster, cluster key - stock_symbol. Index on stock_symbol,dt would be nicely clustered.

e) hash cluster, cluster key = stock_symbol...

f) dbms_redefinition from time to time to reorganize the data using the orderby_cols parameter (online rebuild)

g) create table NEW as select from old order by stock_symbol, dt; drop table old; rename new to old (offline rebuild)



which one works best?

IT DEPENDS

an IOT might be really nice, unless you have lots of secondary indexes or the record is too large to fit on the leaf block....

list partitioning might be nice, if you have sufficiently small set of values to partition on.

and so on - it depends on the data you are talking about, it depends on how it arrives, it depends on how it is used.

changing explain plan

A reader, September 14, 2009 - 6:54 pm UTC

Tom,
I am unable to understand the reason my explain plan changes when I switch a table with a wrapper view
The problem table is lschannelcutdata, the last table in the from clause, the plan changes from index range scan to index full scan, when I replace the table with a wrapper view.

Here's my original query:
select /*+ordered
index(lscd LSCHANNELCUTDATA_SPK)
no_merge(lscd)
*/lsch.recorder ,
lsch.spi,
lscd.uidchannelcut uidchannelcut,
lscd.pit_start pit_start,
lscd.pit_start_yq pit_start_yq,
lscd.pit_stop pit_stop,
lscd.valuecodes valuecodes,
lsch.dstparticipant,
lsch.starttime,
lsch.stoptime,
lsch.intervalcount
from billdeterminant bdt,
settlementchanhist stch,
lschannelcutheader lsch,
lschannelcutdata lscd
where bdt.billdetermcode = 'MCPCRP' AND
lsch.starttime >= to_date('2006-01-01 00:00:00','YYYY-MM-DD HH24:MI:SS') AND
stch.uidbilldeterminant = bdt.uidbilldeterminant AND
lsch.uidchannel = stch.uidchannel AND
lscd.uidchannelcut= lsch.uidchannelcut AND
lscd.pit_start between lsch.pit_start and lsch.pit_stop AND
lscd.pit_stop > lsch.pit_start AND
lscd.pit_start_yq between lsch.pit_start_yq and to_number(to_char(lsch.pit_start+1,'YYYYQ'))AND
bdt.pit_start_yq <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between bdt.pit_start and bdt.pit_stop AND
stch.pit_start_yq <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between stch.pit_start and stch.pit_stop AND
lsch.pit_start_yq <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between lsch.pit_start and lsch.pit_stop AND
lscd.pit_start_yq<= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between lscd.pit_start and lscd.pit_stop
+++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
SELECT STATEMENT, GOAL = ALL_ROWS 336035877 1 271
TABLE ACCESS BY LOCAL INDEX ROWID LSCHANNELCUTDATA 125 1 115
NESTED LOOPS 336035877 1 271
NESTED LOOPS 6974685 2633501 410826156
NESTED LOOPS 9692 35706 2356596
PARTITION RANGE ITERATOR 2 1 35
PARTITION LIST ITERATOR 2 1 35
TABLE ACCESS BY LOCAL INDEX ROWID BILLDETERMINANT 2 1 35
INDEX RANGE SCAN LODSTAR BILLDETERMINANT_N1 1 1
PARTITION RANGE ITERATOR 9690 28290 876990
PARTITION LIST ITERATOR 9690 28290 876990
TABLE ACCESS BY LOCAL INDEX ROWID SETTLEMENTCHANHIST 9690 28290 876990
INDEX RANGE SCAN LODSTAR SETTLEMENTCHANHIST_N2 206 28296
PARTITION RANGE ITERATOR 244 74 6660
PARTITION LIST ITERATOR 244 74 6660
TABLE ACCESS BY LOCAL INDEX ROWID LSCHANNELCUTHEADER 244 74 6660
INDEX RANGE SCAN LSCHANNELCUTHEADER_N5 124 125
PARTITION RANGE ITERATOR 124 1
PARTITION LIST ITERATOR 124 1
INDEX RANGE SCAN LSCHANNELCUTDATA_SPK 124 1

It does a index range scan.
Now I create a wrapper view :

CREATE OR REPLACE VIEW APP.LS_LSCHANNELCUTDATA_V AS
SELECT
t.pit_start pit_start_lscd
,t.pit_start_yq pit_start_yq_lscd
,t.pit_stop pit_stop_lscd
,t.uidchannelcut uid_channel_cut_lscd
,t.valuecodes value_codes_lscd
FROM ls.LSCHANNELCUTDATA t;
++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++

when I use the view instead of the table, the cost changes drastically and I cant make it do a index range scan..
any ideas are very much appreciated..

select /*+ordered
index(lscd.t LSCHANNELCUTDATA_SPK)
no_merge(lscd)
*/lsch.recorder ,
lsch.spi,
lscd.uid_channel_cut_lscd uidchannelcut,
lscd.pit_start_lscd pit_start,
lscd.pit_start_yq_lscd pit_start_yq,
lscd.pit_stop_lscd pit_stop,
lscd.value_codes_lscd valuecodes,
lsch.dstparticipant,
lsch.starttime,
lsch.stoptime,
lsch.intervalcount
from billdeterminant bdt,
settlementchanhist stch,
lschannelcutheader lsch,
app.ls_lschannelcutdata_v lscd
where bdt.billdetermcode = 'MCPCRP' AND
lsch.starttime >= to_date('2006-01-01 00:00:00','YYYY-MM-DD HH24:MI:SS') AND
stch.uidbilldeterminant = bdt.uidbilldeterminant AND
lsch.uidchannel = stch.uidchannel AND
lscd.uid_channel_cut_lscd= lsch.uidchannelcut AND
lscd.pit_start_lscd between lsch.pit_start and lsch.pit_stop AND
lscd.pit_stop_lscd > lsch.pit_start AND
lscd.pit_start_yq_lscd between lsch.pit_start_yq and to_number(to_char(lsch.pit_start+1,'YYYYQ'))AND
bdt.pit_start_yq <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between bdt.pit_start and bdt.pit_stop AND
stch.pit_start_yq <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between stch.pit_start and stch.pit_stop AND
lsch.pit_start_yq <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between lsch.pit_start and lsch.pit_stop AND
lscd.pit_start_yq_lscd <= to_number(to_char(sysdate,'YYYYQ')) AND
sysdate between lscd.pit_start_lscd and lscd.pit_stop_lscd


_------------------------------------------------------------
SELECT STATEMENT, GOAL = ALL_ROWS 556926871 1 2202
HASH JOIN 556926871 1 2202
TABLE ACCESS BY LOCAL INDEX ROWID LSCHANNELCUTHEADER 244 74 6660
NESTED LOOPS 6974685 2633501 410826156
NESTED LOOPS 9692 35706 2356596
PARTITION RANGE ITERATOR 2 1 35
PARTITION LIST ITERATOR 2 1 35
TABLE ACCESS BY LOCAL INDEX ROWID LODSTAR BILLDETERMINANT 2 1 35
INDEX RANGE SCAN BILLDETERMINANT_N1 1 1
PARTITION RANGE ITERATOR 9690 28290 876990
PARTITION LIST ITERATOR 9690 28290 876990
TABLE ACCESS BY LOCAL INDEX ROWID SETTLEMENTCHANHIST 9690 28290 876990
INDEX RANGE SCAN SETTLEMENTCHANHIST_N2 206 28296
PARTITION RANGE ITERATOR 124 125
PARTITION LIST ITERATOR 124 125
INDEX RANGE SCAN LSCHANNELCUTHEADER_N5 124 125
PARTITION RANGE ITERATOR 441847445 1289305807 2637919681122
PARTITION LIST ITERATOR 441847445 1289305807 2637919681122
VIEW APP LS_LSCHANNELCUTDATA_V 441847445 1289305807 2637919681122
TABLE ACCESS BY LOCAL INDEX ROWID LSCHANNELCUTDATA 441847445 1289305807 175345589752
INDEX FULL SCAN LSCHANNELCUTDATA_SPK 3750713 1289305807



Tom Kyte
September 15, 2009 - 9:42 am UTC

remove hints, remove all hints and let's work from there. I don't like hints - I'm not especially interested in diagnosing anything with them.


But in short, you did it yourself, you made it not possible to provide access path hints by your no_merge hint.

16.3.3 Hints and Nonmergeable Views
http://docs.oracle.com/docs/cd/B19306_01/server.102/b14211/hintsref.htm#i22120
Because nonmergeable views are optimized separately from the top-level query, access path and join hints inside the view are preserved. For the same reason, access path hints on the view in the top-level query are ignored.



This is why I hate hints, unless and until you program THE ENTIRE QUERY - ALL OF IT - YOU HAVE NO IDEA HOW THE HINTS WILL BE USED.

Ordered - entirely insufficient, if you say ordered, you better tell us how to join T1 to T2 (nested loop? hash join?), T2 to T3 and so on.

Once you use a single hint, you have to use all of them - or you will see strange things, especially as you go from version to version.



My favorite example - from Jonathan Lewis - I'll paraphrase it slightly:

situation: on a version of Oracle that didn't do something - like subquery unnesting. Used an ordered hint - was joining t1 to t2 to t3 - a subquery was used to filter the data.

upgrade, release of Oracle upgraded to does subquery unnesting or something similar. In any case - the subquery is moved UP a level, instead of

from t1, t2, t3 where (subquery)

we have

from (subquery), t1, t2, t3


now, the subquery which used to be last to be evaluated is done FIRST and used the drive the entire query - and that was a really bad idea (in this case). You missed a HINT in this case - the no_unnest - but you didn't even know about that hint because subquery unnesting wasn't being done in the original release.


Just let the optimizer do it's job, if it gets the wrong plan - it is due to missing, invalid, stale, incomplete statistics - things like dbms_stats, dynamic_sampling, sql profiles would be used to correct the issue - NOT hints.

Shweta, September 16, 2009 - 7:55 am UTC

Can you please help me with the tuning of the below query: It is taking 10 minutes to give the result


SELECT * FROM (SELECT ROWNUM recRowNum, listQueryTable.* FROM ( SELECT DISTINCT ccmd.APPL_ID,
ccmd.CUST_NAME, NVL (ccmd.COLLECTION_CYCLE, 0) CYCLE, NVL
(TO_CHAR (ccmd.PRINCIPLE_OUTSTANDING, (SELECT VALUE FROM
PARAMETERS_MST WHERE KEY='CS_CURRENCY_FORMAT')), 0.00) PRIOUTSTANDING,
DPD, NVL (TO_CHAR (ccmd.PAY_DATE, (SELECT VALUE FROM PARAMETERS_MST WHERE KEY='CS_DATEFORMAT')), ' ') PAYDATE,
nvl(TO_CHAR((select installment_amt
from payment_details_v
where pay_date = (select max(pdv.pay_date)
from PAYMENT_DETAILS_V pdv
where pdv.appl_id = ccmd.appl_id and
pdv.cust_id = ccmd.cust_id
and pdv.financier_id = ccmd.financier_id group by pdv.appl_id
) and rownum <2),(SELECT VALUE FROM PARAMETERS_MST WHERE KEY='CS_CURRENCY_FORMAT')),0.00) TOTAMTREC, NVL (ccmd.REMARKS, ' ') REMARKS FROM cs_case_mvmt_details ccmd
WHERE ALLOCATION_DATE >= to_date('01/06/2009','dd/mm/yyyy') AND ALLOCATION_DATE <= to_date('01/07/2009','dd/mm/yyyy') ORDER BY APPL_ID, CUST_NAME) listQueryTable WHERE ROWNUM <16) WHERE recRowNum BETWEEN 1 AND 15

Substr and Instr Workaround ?

Jonty Rhodes, September 16, 2009 - 4:20 pm UTC

Hi Tom,

Thank you for the helpful article(s). I frequent your site for advice.

I am working on tuning a query that runs for ~ 4 hours. Excuse the spacing, it is for readability

UPDATE line SET
line.ID = (SELECT ID FROM header WHERE header.UIDY = line.PARENT_ID)
WHERE line.ID is null
AND
EXISTS(select tj.fisc_year, tj.fisc_mnth from transaction_journal tj
WHERE tj.doc_num =
SUBSTR(line.UIDY, INSTR(line.UIDY, '&',17,1 )+1, INSTR(line.UIDY, '&', 17, 2)-INSTR(line.UIDY, '&',17,1 )-1 )
AND
tj.dtyp =
SUBSTR(line.uidy, INSTR(line.uidy, '&',1, 4) + 1, (INSTR(line.uidy, '&',1, 5) - INSTR(line.uidy, '&',1, 4) - 1))
AND
tj.doc_actn ='O'
group by fisc_year, fisc_mnth
having count(*) = 1);

The UIDY columns represent PKs. They are concatenated values formed by data from other fields with ampersand delineation. We have close to zero normalization in the database so we must pull values out of the UIDY to join. Is there anyway to speed the substr and instr functionality? The table being updated is not partitioned.
Tom Kyte
September 16, 2009 - 5:45 pm UTC

add columns to the table, have a trigger maintain them.

do the substr/instr ONCE - upon insert
instead of once every time you access the data.


enabling trace has improved performance

Bala, September 17, 2009 - 1:13 am UTC

Hi,

I have asked this question already and you have referred to me this URL:-
http://tkyte.blogspot.com/2007/09/tuning-with-sqltracetrue.html I came to know that due to bind peeking this problem is happening .

I have tried Re-Gathering stats with no_invalidate=>false so that dependent cursors get invalidated immediately and go for hard parsing and picks with new plan but still my problem is not resolved and i should enable sql_trace to resolve the problem . Can you please correct me if i am wrong.

We have in 10.2.0.2

Regards

Bala
Tom Kyte
September 17, 2009 - 9:15 am UTC

step 1: verify that the plan was in fact reloaded
step 2: verify the binds used to optimize that plan


remember, the binds first used pick the plan. If you flush the sql from the shared pool and the first hard parse says "let's use a full scan" and that is the correct plan for that query, so be it, everyone will use a full scan.


ops$tkyte%ORA10GR2> create table t
  2  as
  3  select 99 id, a.*
  4    from all_objects a
  5   where rownum <= 20000;

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> update t set id = 1 where rownum = 1;

1 row updated.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx on t(id);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> begin
  2     dbms_stats.gather_table_stats
  3     ( user, 'T',
  4       method_opt=>'for all indexed columns size 254',
  5       estimate_percent => 100,
  6       cascade=>TRUE );
  7  end;
  8  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> variable n number
ops$tkyte%ORA10GR2> exec :n := 99

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> select count(object_type) from t where id = :n;

COUNT(OBJECT_TYPE)
------------------
             19999

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> column sql_id new_value s
ops$tkyte%ORA10GR2> column child_number new_value c
ops$tkyte%ORA10GR2> select sql_id, child_number from v$sql where sql_text like 'select count(object_type) from t where id = :n%';

SQL_ID        CHILD_NUMBER
------------- ------------
12g0bkvcxc9vu            0

ops$tkyte%ORA10GR2> select *
  2    from table( dbms_xplan.display_cursor('&S',&C,'typical +peeked_binds'));
old   2:   from table( dbms_xplan.display_cursor('&S',&C,'typical +peeked_binds'))
new   2:   from table( dbms_xplan.display_cursor('12g0bkvcxc9vu',         0,<b>'typical +peeked_binds'</b>))

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------
SQL_ID  12g0bkvcxc9vu, child number 0
-------------------------------------
select count(object_type) from t where id = :n

Plan hash value: 2966233522

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |       |       |    23 (100)|          |
|   1 |  SORT AGGREGATE    |      |     1 |    14 |            |          |
|*  2 |   TABLE ACCESS FULL| T    | 19999 |   273K|    23   (5)| 00:00:01 |
---------------------------------------------------------------------------
<b>
Peeked Binds (identified by position):
--------------------------------------

   1 - :N (NUMBER): 99
</b>
Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("ID"=:N)


24 rows selected.

enabling trace has improved performance

Bala, September 18, 2009 - 5:41 am UTC

Hi Tom,

We don't have this issue today to verify , since they bounced the instance today morning i think it got hard parsed again so it was a perfect plan from then on . We are using oracle applications R12 for your information. Today i could see there are two cursors got created with bind_mismatch in v$sql_shared_cursor .

1. We will get this issue intermittently . Can this issue will be fixed with outline or so ?

2. I have taken execution plans of all four cursors yesterday but all are same as far as i know. Can i upload to this site some where to verify this .

3. When i have taken sql trace on that form , created tkprof on that trace and i am concentrating only on the first query since it was sorted based on sort='prsela,exeela,fchela' this options . I doubt that form contains more than one query and now the question is which one to look and which query might be facing with this bind peeking issue.

Tom I am requesting to please spare some time for this as this issue is long time for us.

Regards

Bala
Tom Kyte
September 18, 2009 - 12:23 pm UTC

1) you can use query plan stability - yes.

you could stop gathering statistics that cause plans to change (eg: if you did not have histograms on a column - we would never flip flop back and forth between an index and a full scan - it would always be one or the other)

you could not bind the particular column in question - if there are sufficiently small number of values - say 25 - you would have 25 plans in the shared pool and each one would be optimal for the literal value

2) read them, compare them. If you cannot read them, save them to a file and just run DIFF on them. You can tell if they are the same or not, you don't need help with that (really - they are just a report)

3) why sort by parse elapsed, you'd be more interested in run time would you not?

if that form does not contain more than one query, why would you ask which one to look at? there is only one? Not sure what you mean.

but you should know what query you are looking FOR, it is the one that gives you poor performance - you already know what query you are looking for don't you?

Tuning Queries with DISTINCT

Vikas, September 28, 2009 - 4:11 pm UTC

Dear Mr. Kyte,

How are you doing? Quite a long time since I last seeked your valuable advice on Oracle related queries and issues. As usual, this time again my selfish instincts have motivated me to write in.

I have a small question about SQL queries with "DISTINCT" -

My very first and basic query is, how to take care and move ahead elegantly with queries that have "DISTINCT" clause in them so that one gets optimal performance?

Secondly, I have a simple query which used "DISTINCT" in it -

select distinct problem_type, qualifier_1, qualifier_2, qualifier_3, qualifier_4
from remedy_questions
order by problem_type, qualifier_1, qualifier_2, qualifier_3, qualifier_4 asc;

The plan for the same is -
Plan
SELECT STATEMENT FIRST_ROWSCost: 2,643 Bytes: 3,887,360 Cardinality: 60,740
2 SORT UNIQUE Cost: 1,704 Bytes: 3,887,360 Cardinality: 60,740
1 TABLE ACCESS FULL TABLE ACSSPROD.REMEDY_QUESTIONS Cost: 764 Bytes: 3,887,360 Cardinality: 60,740

The table has 32000 records in total and has no primary/unique key and is being run on version 10.2.0.4.

Can you please hint and trigger my thoughts and knowledge as of what I can do to improve the execution plan of this query, and in such a given scenario how can one avoid Full Table Scans (FTS)? Would the use of group by help in here?

Thanks in advance for sharing your knowlegde to enlightening me on this.

Regards



Tom Kyte
September 30, 2009 - 7:35 am UTC

... My very first and basic query is, how to take care and move ahead elegantly
with queries that have "DISTINCT" clause in them so that one gets optimal
performance?
...

you are done already - if you need distinct - you use it.
if you do not - you do not use it.

if you need to use it, it is already "optimal"

... Can you please hint and trigger my thoughts and knowledge as of what I can do
to improve the execution plan of this query, and in such a given scenario how
can one avoid Full Table Scans (FTS)?...

well, the full table scan is NOT A BAD THING here. We will be full scanning *SOMETHING*

if you create an index on (problem_type, qualifier_1, qualifier_2, qualifier_3,
qualifier_4)

in that order, we can INDEX FULL SCAN a smaller structure (assuming the table has lots of other columns and the index is small) and would be able to avoid the sort - as long as one of problem_type, qualifier_1, qualifier_2, qualifier_3,
qualifier_4
is defined as NOT NULL - if not, you'll have to add a where clause to preclude one of them from being null so the index can be used if appropriate.

query

A reader, September 30, 2009 - 9:12 am UTC

Tom:

kind of surprised by your comment

if you have 2 tables with same rows but diff columns:

T1
----
col1
col2
col3

T2
-----
col1
...
col100

Is it really faster when you do a select on 2 columns from the small table.

select col1,col2 from T1;
versus
select col1,col2 from T2;

2. Would not a unique index only save DISTINCT records and make query faster.
Tom Kyte
October 07, 2009 - 8:38 am UTC

1) I have no clue what you are referring to smk. none.


big page here, and you again provide NO CONTEXT whatsoever.




2) please think about what you just said there.

A unique index would force the index key to be unique in the table.

If you select distinct a, b, c from t AND there is a unique constraint on (a,b,c), then.... (think about this for a minute....)

Further to - Tuning Queries with DISTINCT

Vikas, September 30, 2009 - 9:41 am UTC

Dear Mr. Kyte,

Thanks a lot for the knowledge sharing.

To the "Reader Above"
========================
Hi, if you query comes in context to my query above, Yes you are right, a Unique key (Index) or a Primary key would have done what was required. But as mentioned above, due to the business requirement and model, we cannot have a Unique/Primary key defined on this table.

One thing that I thought and tried to do is, create a Function Based Index (FBI) with unique values which got failed.

May be thats the reason why we have Unique Indexes. Now the question is, Can we create a function based index on a non-unique column/s for Distinct Values??

I tried but got errors. Is it doable? Any takers???


Thanks and Regards
Tom Kyte
October 07, 2009 - 8:42 am UTC

... due to the business requirement and model, we cannot have a
Unique/Primary key defined on this table.
...

you just made me hurt myself as I fell out of my chair. "Business requirement", if I hear that term used again to justify "doing things in a way we absolutely know we should not" - I'm going to scream.


... Can we
create a function based index on a non-unique column/s for Distinct Values?? ...

please close your eyes and visualize how this would "happen". Think about it, then you'll see why "it could not really be possible"

You could create a materialized view, refresh fast on commit, if you wanted that would


select a, b, c, count(*) from t group by a,b,c;

and that would have unique a,b,c values. But it would still be the wrong way.

Need Example - Tuning Queries with DISTINCT

Vikas, September 30, 2009 - 1:14 pm UTC

Dear MR. Kyte,

With all due regards, may I request you to provide a suitable expample to support and explain the below comment, as it seems a bit un-clear to me -

"in that order, we can INDEX FULL SCAN a smaller structure (assuming the table has lots of other columns and the index is small) and would be able to avoid the sort - as long as one of problem_type, qualifier_1, qualifier_2, qualifier_3, qualifier_4 is defined as NOT NULL - if not, you'll have to add a where clause to preclude one of them from being null so the index can be used if appropriate."

Thanks and Regards.
Tom Kyte
October 07, 2009 - 8:56 am UTC

you have a table T with lots of columns - a,b,c,d,....z

you want to find distinct values of a,c

if you have an index such that a,b is on the leading edge of the index (the first two columns of the index)

AND at least one attribute in the index is NOT NULL (so we know that all rows in the table are in the index, if all of the indexed attributes are nullable - we do not know that all rows in the table are in the index since entirely null keys are NOT INDEXED)
OR we use "and a is not null or b is not null" - so as to render the previous point 'not relevant'

we can index full scan (read the index in sorted order) to find the distinct values of a,b
ops$tkyte%ORA10GR2> create table t as select * from all_objects;

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx on t(owner,object_type);

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select owner,object_type from t group by owner, object_type order by owner,object_type;

Execution Plan
----------------------------------------------------------
Plan hash value: 847563073

-------------------------------------------------------------------------------
| Id  | Operation             | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |       | 42293 |  1156K|    19  (22)| 00:00:01 |
|   1 |  SORT GROUP BY        |       | 42293 |  1156K|    19  (22)| 00:00:01 |
|   2 |   INDEX FAST FULL SCAN| T_IDX | 42293 |  1156K|    16   (7)| 00:00:01 |
-------------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> select /*+ first_rows(100) */ owner,object_type from t group by owner, object_type order by owner,object_type;

Execution Plan
----------------------------------------------------------
Plan hash value: 2505321027

------------------------------------------------------------------------------
| Id  | Operation            | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |       | 42293 |  1156K|     2   (0)| 00:00:01 |
|   1 |  SORT GROUP BY NOSORT|       | 42293 |  1156K|     2   (0)| 00:00:01 |
|   2 |   INDEX FULL SCAN    | T_IDX | 42293 |  1156K|     2   (0)| 00:00:01 |
------------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement

ops$tkyte%ORA10GR2> set autotrace off

or at the very least, we can index fast full scan (avoid full scanning table, full scan using multiblock IO the SMALLER index instead) the index to arrive at the answer.

KC, October 01, 2009 - 1:36 am UTC

To Vikas

b* tree indexes do not store completely null entries. An index entry is made when at least one of the column in the index is not null. This is the way b* tree works except cluster b* tree indexes.

The DISTINCT in your SQL statement requires Oracle to return NULL entries. As entire NULL entries are not 'visible' in b* tree index, Oracle will do the right thing by not using the b* tree index.

index

sam, October 01, 2009 - 3:42 pm UTC

It is hard to understand someone creating a business rule not to enforce a primary key. That person should be fired as he does not know much about DB design--since every table in a datbase *MUST* have a PK.

Tom is correct. for a 32000 record table let it do a full scan. how long does it take? An index may not help here.

Tom says create a smaller version table/index on those columns only if your main table has a lot of columns. But your index cannot have NULL values on thos columns. so you select statement will exclude those NULLS so it can use the INDEX.


Tom Kyte
October 07, 2009 - 2:59 pm UTC

... But your index cannot have NULL values on thos
columns. so you select statement will exclude those NULLS so it can use the
INDEX.
...

not entirely true - the index can have nulls, it would be that at least ONE of the attributes must be NOT NULL .

SQL Tune.

A reader, October 08, 2009 - 7:00 am UTC

Dear Tom,

I have:


select * from v1 where v1_col1=:BIND_VAR

v1 is a view:

create view v1
(v1_col1, v1_col2)
as
select t1.col1, t2.col2 from t1,t2
where t1.col1=t2.col2

t1.col1 - unique index,
t2.col2 - non unique index.


Noticed that:

select * from v1 where v1.col1=?

takes about 60sec to execute.

however,

select * from ( select t1.col1, t2.col2 from t1,t2
where t1.col1=t2.col2
and t1.col1=:BIND_VAR)

takes 1 sec to execute.

mainly here rowsource is reduced when t1.col1 is taken alongwith inner query.


question:

a) Is there any way we can pass bind variable to the inner query with using view v1 ( i know BIND var cannot be passed to DDL)but any other way you would suggest to achieve the same result?
b) any other suggestion/comment?

Need Example - Tuning Queries with DISTINCT

A reader, October 19, 2009 - 4:10 pm UTC

Dear Mr. Kyte,

Thanks a tons for providing the above example to my query.

To rest all...
Thank you so much for your thought provoking discussion and knowledge sharing.

Take care.

Latest SQL Tuning Books?

H, November 03, 2009 - 12:18 pm UTC

Can you please update the Refrences Link with the latest books on 10g & 11i for Query Tuning.

PS: Simply the best!!!
Tom Kyte
November 09, 2009 - 2:41 pm UTC

all releases have a concepts guide and a performance guide, just follow the links on otn to the documentation for your version and read away.

Latest SQL Tuning Books?

H, November 03, 2009 - 12:19 pm UTC

Can you please update the Refrences Link with the latest books on 10g & 11i for Query Tuning.

PS: Simply the best!!!

Latest SQL Tuning Books?

H, November 03, 2009 - 12:19 pm UTC

Can you please update the Refrences Link with the latest books on 10g & 11i for Query Tuning.

PS: Simply the best!!!

SQL Tuning.

A Reader, December 16, 2009 - 12:55 pm UTC

Dear Tom,
Thanks for your time.

I have:

-- from Statspack ( 20 mins) on 9.2.0.8 Oracle

                                                     CPU      Elapsd
 Physical Reads  Executions  Reads per Exec %Total Time (s)  Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
      1,785,843           77       23,192.8   12.9   335.65    634.59 3259607616
Module: java_q4p@host (TNS V1-V3)

SELECT
    objid,col2,col3,......, col245
   FROM T
    WHERE  S_id_number IS   NULL   ORDER BY 1 DESC


( There are 245 columns selected in the query. To save space, i have cut these short in display)

AUTOTRACE shows:

SQL> SELECT
  2  objid,col2,col3,......, col245
 53  FROM T
 54  WHERE  S_id_number IS   NULL   ORDER BY 1 DESC
 55  /

1271 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=100734 Card=1094
           Bytes=833628)

   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'T' (Cost=100734
           Card=1094 Bytes=833628)

   2    1     INDEX (FULL SCAN DESCENDING) OF 'SYS_C002133' (UNIQUE) (
          Cost=369 Card=111321)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
     260500  consistent gets
      44507  physical reads
          0  redo size
     305920  bytes sent via SQL*Net to client
      16715  bytes received via SQL*Net from client
       1273  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
       1271  rows processed

SQL>
SQL>
SQL>
SQL>


SQL> select count(*) from T;

  COUNT(*)
----------
    136252

SQL> select  count(*) from T  WHERE  S_id_number IS NULL;

  COUNT(*)
----------
      1271

SQL>  select  count(*) from T  WHERE  S_id_number IS NOT NULL
  2  /

  COUNT(*)
----------
    134981


Indexing : 
table T has SYS_C002133 Index on column objid
table T has Unique index on column S_id_number


Question:

a) How to best write this SQL so that IO can be reduced?


Tom Kyte
December 16, 2009 - 1:36 pm UTC

I would suggest an index on (s_id_number,objid desc) if possible.

right now, it looks like it is reading EVERY row out of the table (do you have first rows set or something??? do you mean to have first rows set? I would not expect that plan at all) via the index. If you have an index that can do the predicate (objid I would presume is NOT NULL, it would allow us to do the "IS NULL" on s_id_number in the index) and the sorting, that'd be nice. Like this:


ops$tkyte%ORA10GR2> create index t_idx on t(s_id_number,objid desc);

Index created.

ops$tkyte%ORA10GR2> set autotrace traceonly
ops$tkyte%ORA10GR2> select * from t where s_id_number is null order by s_id_number, objid desc;

1513 rows selected.


Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |  1439 |   150K|    90   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |  1439 |   150K|    90   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |  1439 |       |     8   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("S_ID_NUMBER" IS NULL)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       1620  consistent gets
          0  physical reads
          0  redo size
     104127  bytes sent via SQL*Net to client
       1500  bytes received via SQL*Net from client
        102  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
       1513  rows processed

ops$tkyte%ORA10GR2> set autotrace off


Tuning issue

A reader, December 16, 2009 - 5:04 pm UTC

Hey Tom,

We had a tuning issue recently. Transport table has 13 columns. Recently we merged 4 child tables (transportamend, transportnovation, transporttermination,transportExtend) into Transport table.
The merge brings 55 more columns to new transport table called txncombo.
The transportParticipant and dealpackage are two tables associated with transport table, with transport column referencing the id of transport.

When we merged the tables, we ordered the new table by primary key. So the clustering factor of the primary key is much lower than the original primary key.

Clustering factor of pk_txncombo is 72443 comparing to 2187642 of pk_transport. I have compared the user_indexes and user_segments for these two indexes, they have
the same extents, bytes..

Transport has 2403603 records.

After merge we found an interesting issue. The physical gets from the new table is higher than original table when pk_transport and pk_txncombo are picked up.
Wonder why this happens?

eg, INDEX UNIQUE SCAN PK_TRANSPORT (cr=854744 pr=1647 pw=0 time=5785953 us)(object id 552746)
INDEX UNIQUE SCAN PK_TXNCOMBO (cr=854744 pr=2786 pw=0 time=5598706 us)(object id 555996)


-- original table stats

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 4 1.00 0.98 0 0 0 0
Execute 4 0.00 0.00 0 0 0 0
Fetch 272 46.90 160.31 106538 5139937 0 536
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 280 47.91 161.29 106538 5139937 0 536

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 497

Rows Row Source Operation
------- ---------------------------------------------------
134 COUNT STOPKEY (cr=1284985 pr=34675 pw=0 time=48529796 us)
134 VIEW (cr=1284985 pr=34675 pw=0 time=48529650 us)
134 SORT ORDER BY STOPKEY (cr=1284985 pr=34675 pw=0 time=48529230 us)
134 NESTED LOOPS OUTER (cr=1284985 pr=34675 pw=0 time=8527377 us)
134 NESTED LOOPS OUTER (cr=1284581 pr=34452 pw=0 time=7799435 us)
134 NESTED LOOPS OUTER (cr=1284412 pr=34358 pw=0 time=6977661 us)
134 NESTED LOOPS OUTER (cr=1284142 pr=34274 pw=0 time=6595741 us)
134 NESTED LOOPS OUTER (cr=1284004 pr=34230 pw=0 time=6582129 us)
134 NESTED LOOPS OUTER (cr=1283866 pr=34184 pw=0 time=6568510 us)
134 NESTED LOOPS (cr=1283725 pr=34172 pw=0 time=6555144 us)
427371 SORT UNIQUE (cr=1609 pr=0 pw=0 time=1566094 us)
480340 INDEX RANGE SCAN IDX_TP_INSTITUTION_TRANSPORT (cr=1609 pr=0 pw=0 time=1443130 us)(object id 552829)
134 TABLE ACCESS BY INDEX ROWID TRANSPORT (cr=1282116 pr=34172 pw=0 time=44026216 us)
427371 INDEX UNIQUE SCAN PK_TRANSPORT (cr=854744 pr=1647 pw=0 time=5785953 us)(object id 552746)
5 TABLE ACCESS BY INDEX ROWID TRANSPORTAMEND (cr=141 pr=12 pw=0 time=82957 us)
5 INDEX UNIQUE SCAN TRANSPORTAMEND_TXN_UDX (cr=136 pr=8 pw=0 time=51592 us)(object id 552824)
2 TABLE ACCESS BY INDEX ROWID TRANSPORTREJECTREASON (cr=138 pr=46 pw=0 time=112645 us)
2 INDEX UNIQUE SCAN PK_TX_REJECT_RSN (cr=136 pr=44 pw=0 time=96548 us)(object id 552836)
2 TABLE ACCESS BY INDEX ROWID TRANSPORTTERMINATION (cr=138 pr=44 pw=0 time=123295 us)
2 INDEX UNIQUE SCAN PK_TX_NOVATION (cr=136 pr=42 pw=0 time=113192 us)(object id 552833)
0 TABLE ACCESS BY INDEX ROWID TRANSPORTEXTEND (cr=270 pr=84 pw=0 time=441383 us)
0 INDEX UNIQUE SCAN PK_TX_EXTEND (cr=270 pr=84 pw=0 time=440744 us)(object id 552826)
33 TABLE ACCESS BY INDEX ROWID TRANSPORTNOVATION (cr=169 pr=94 pw=0 time=432053 us)
33 INDEX UNIQUE SCAN PK_TX_TERMINATION (cr=136 pr=68 pw=0 time=213416 us)(object id 552828)
134 TABLE ACCESS BY INDEX ROWID DEALPACKAGE (cr=404 pr=223 pw=0 time=1310118 us)
134 INDEX UNIQUE SCAN PK_DEALPACKAGE (cr=270 pr=95 pw=0 time=502697 us)(object id 552764)

-- new table stats

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 4 0.02 0.02 0 0 0 0
Execute 4 0.00 0.00 0 0 0 0
Fetch 272 55.95 192.93 226374 5137064 0 536
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 280 55.98 192.96 226374 5137064 0 536

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 497

Rows Row Source Operation
------- ---------------------------------------------------
134 COUNT STOPKEY (cr=1284266 pr=50508 pw=0 time=44757584 us)
134 VIEW (cr=1284266 pr=50508 pw=0 time=44757176 us)
134 SORT ORDER BY STOPKEY (cr=1284266 pr=50508 pw=0 time=44756894 us)
134 NESTED LOOPS OUTER (cr=1284266 pr=50508 pw=0 time=7371020 us)
134 NESTED LOOPS OUTER (cr=1284128 pr=50504 pw=0 time=7356559 us)
134 NESTED LOOPS (cr=1283724 pr=50491 pw=0 time=6199853 us)
427371 SORT UNIQUE (cr=1609 pr=0 pw=0 time=725162 us)
480340 INDEX RANGE SCAN IDX_TP_INSTITUTION_TRANSPORT (cr=1609 pr=0 pw=0 time=480410 us)(object id 552829)
134 TABLE ACCESS BY INDEX ROWID TXNCOMBO (cr=1282115 pr=50491 pw=0 time=43456791 us)
427371 INDEX UNIQUE SCAN PK_TXNCOMBO (cr=854744 pr=2786 pw=0 time=5598706 us)(object id 555996)
134 TABLE ACCESS BY INDEX ROWID DEALPACKAGE (cr=404 pr=13 pw=0 time=106302 us)
134 INDEX UNIQUE SCAN PK_DEALPACKAGE (cr=270 pr=6 pw=0 time=48234 us)(object id 552764)
2 TABLE ACCESS BY INDEX ROWID TRANSPORTREJECTREASON (cr=138 pr=4 pw=0 time=23701 us)
2 INDEX UNIQUE SCAN PK_TX_REJECT_RSN (cr=136 pr=4 pw=0 time=23086 us)(object id 552836)


And also when we run the query against original table, it took 45 seconds in the first time. After couple of runs, the physical gets came down to 0.
This makes sense since it benefits from the cache. However, when we run the query against new table, no matter how many times we ran it, it always took
more than 50 second and sometimes even more. The physical gets kept the same. Can you explain why?

Thank you very much!
Tom Kyte
December 17, 2009 - 7:23 am UTC

a multi-table join, no query to look at, no real information about the other tables, a table that is much larger than the original, completely different plans.

I don't know - nothing really to work on there.

SQL Tuning.... contd

A reader, December 23, 2009 - 10:02 am UTC

Hi Tom.
Happy X-Mas and New Year 2010.



Regd :
The post :
/*
SQL Tuning. 
...Followup   December 16, 2009 - 1pm Central time zone:
...I would suggest an index on (s_id_number,objid desc) if possible. 
*/


I have created index  TC_IDXZ

 select INDEX_NAME,TABLE_NAME,COLUMN_NAME,COLUMN_POSITION from user_ind_columns where table_name='T';

INDEX_NAME TABLE_NAME           COLUMN_NAME          COLUMN_POSITION
---------- -------------------- -------------------- ---------------
TC_IDXZ    T              S_ID_NUMBER                1
TC_IDXZ    T             SYS_C002133                2



Now:

SQL>Set autotrace traceonly

SQL> select * from T where S_id_number IS NULL ORDER BY S_id_number,1 DESC;


1271 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=10 Card=1094 Bytes=833628)

   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'T' (Cost=10 Card=1094 Bytes=833628)

   2    1     INDEX (RANGE SCAN) OF 'TC_IDXZ' (NON-UNIQUE) (Cost=2 Card=1094)





Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       2545  consistent gets
          0  physical reads
          0  redo size
     305920  bytes sent via SQL*Net to client
      16723  bytes received via SQL*Net from client
       1273  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
       1271  rows processed


IO reduced :).

Further, could you suggest someway out wherein I need not to change my SQL but i can still reduce the IO.
i.e.
I will use the same old SQL:

select * from T where S_id_number IS NULL ORDER BY 1 DESC;


Thanks for your time.

OR SELF JOIN

A reader, December 30, 2009 - 10:33 am UTC

Hi Tom,

I have a similar problem as shown in my simple example. I'm doing a self join of two tables based on an OR condition.

The database is always using an FTS + FILTER condition for the join. The FTS takes to long in my case. Could you please explain how to resolve this? How can I push the predicates deeper?


[18] test@X092> create table all_objects as select * from all_objects;

Table created.

Elapsed: 00:00:13.07
[18] test@X092> create index idx1 on all_objects (object_id);

Index created.

Elapsed: 00:00:00.05
[18] test@X092> create index idx2 on all_objects (created, last_ddl_time);

Index created.

Elapsed: 00:00:00.05
[18] test@X092> explain plan for
  2  select * from all_objects x, all_objects y where y.object_id = 58389 and (x.created = y.created OR x.last_ddl_time = y.last_ddl_time);

Explained.

Elapsed: 00:00:00.01
[18] test@X092> select * from table (dbms_xplan.display);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------

----------------------------------------------------------------------------
| Id  | Operation                   |  Name        | Rows  | Bytes | Cost  |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |              |       |       |       |
|*  1 |  TABLE ACCESS BY INDEX ROWID| ALL_OBJECTS  |       |       |       |
|   2 |   NESTED LOOPS              |              |       |       |       |
|   3 |    TABLE ACCESS FULL        | ALL_OBJECTS  |       |       |       |
|*  4 |    INDEX RANGE SCAN         | IDX1         |       |       |       |
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("X"."CREATED"="Y"."CREATED" OR
              "X"."LAST_DDL_TIME"="Y"."LAST_DDL_TIME")
   4 - access("Y"."OBJECT_ID"=58389)

Note: rule based optimization

19 rows selected.

Elapsed: 00:00:02.01
[18] test@X092> exec dbms_stats.gather_table_stats (user, 'ALL_OBJECTS', cascade=>true);

PL/SQL procedure successfully completed.

Elapsed: 00:00:05.00
[18] test@X092> explain plan for
  2  select * from all_objects x, all_objects y where y.object_id = 58389 and (x.created = y.created OR x.last_ddl_time = y.last_ddl_time);

Explained.

Elapsed: 00:00:00.00
[18] test@X092> select * from table (dbms_xplan.display);

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------

-----------------------------------------------------------------------------
| Id  | Operation                    |  Name        | Rows  | Bytes | Cost  |
-----------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |              |    53 |  9858 |    40 |
|   1 |  NESTED LOOPS                |              |    53 |  9858 |    40 |
|   2 |   TABLE ACCESS BY INDEX ROWID| ALL_OBJECTS  |     1 |    93 |     2 |
|*  3 |    INDEX RANGE SCAN          | IDX1         |     1 |       |     1 |
|*  4 |   TABLE ACCESS FULL          | ALL_OBJECTS  |    53 |  4929 |    38 |
-----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("Y"."OBJECT_ID"=58389)
   4 - filter("X"."CREATED"="Y"."CREATED" OR
              "X"."LAST_DDL_TIME"="Y"."LAST_DDL_TIME")

Note: cpu costing is off

19 rows selected.

Elapsed: 00:00:00.01

Tom Kyte
January 04, 2010 - 10:05 am UTC

word to wise:

do not create a table named all_objects, you are just asking for trouble.

Also, to all that like public synonyms, chew on this example for a bit, hmmm, can you spell "trojan horse", a very good reason to NOT use public synonyms...





think about this - forget about self join (that is red herring), just think about any two table join, with a predicate like you have. A non-equi join. What is there to "push"???

Here is a (*semantically different*) approach, that will actually return the same result IF "select *" from both tables provides a Unique key somewhere

ops$tkyte%ORA10GR2> create index idx1 on t (object_id);

Index created.

ops$tkyte%ORA10GR2> create index idx2 on t (created);

Index created.

ops$tkyte%ORA10GR2> create index idx3 on t (last_ddl_time);

Index created.

ops$tkyte%ORA10GR2> delete from plan_table;

13 rows deleted.

ops$tkyte%ORA10GR2> explain plan for
  2  select *
  3    from t a, t b
  4   where a.object_id = 58389
  5     and a.created = b.created
  6   union
  7  select *
  8    from t a, t b
  9   where a.object_id = 58389
 10     and a.last_ddl_time = b.last_ddl_time
 11  /

Explained.

ops$tkyte%ORA10GR2> select * from table( dbms_xplan.display );

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 800396134

----------------------------------------------------------------------------------------
| Id  | Operation                       | Name | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                |      |     2 |   512 |    20  (60)| 00:00:01 |
|   1 |  SORT UNIQUE                    |      |     2 |   512 |    20  (60)| 00:00:01 |
|   2 |   UNION-ALL                     |      |       |       |            |          |
|   3 |    TABLE ACCESS BY INDEX ROWID  | T    |   290 | 37120 |     7   (0)| 00:00:01 |
|   4 |     NESTED LOOPS                |      |     1 |   256 |     8   (0)| 00:00:01 |
|   5 |      TABLE ACCESS BY INDEX ROWID| T    |     1 |   128 |     1   (0)| 00:00:01 |
|*  6 |       INDEX RANGE SCAN          | IDX1 |     1 |       |     1   (0)| 00:00:01 |
|*  7 |      INDEX RANGE SCAN           | IDX2 |   290 |       |     1   (0)| 00:00:01 |
|   8 |    TABLE ACCESS BY INDEX ROWID  | T    |   169 | 21632 |     9   (0)| 00:00:01 |
|   9 |     NESTED LOOPS                |      |     1 |   256 |    10   (0)| 00:00:01 |
|  10 |      TABLE ACCESS BY INDEX ROWID| T    |     1 |   128 |     1   (0)| 00:00:01 |
|* 11 |       INDEX RANGE SCAN          | IDX1 |     1 |       |     1   (0)| 00:00:01 |
|* 12 |      INDEX RANGE SCAN           | IDX3 |   169 |       |     1   (0)| 00:00:01 |
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   6 - access("A"."OBJECT_ID"=58389)
   7 - access("A"."CREATED"="B"."CREATED")
  11 - access("A"."OBJECT_ID"=58389)
  12 - access("A"."LAST_DDL_TIME"="B"."LAST_DDL_TIME")

Note
-----
   - dynamic sampling used for this statement

31 rows selected.



Now, if object ID is a primary key, tell us that and see what happens:

ops$tkyte%ORA10GR2> create table t as select * from all_objects;

Table created.

ops$tkyte%ORA10GR2> alter table t add constraint t_pk primary key(object_id);

Table altered.

ops$tkyte%ORA10GR2> create index idx2 on t (created);

Index created.

ops$tkyte%ORA10GR2> create index idx3 on t (last_ddl_time);

Index created.

ops$tkyte%ORA10GR2> delete from plan_table;

12 rows deleted.

ops$tkyte%ORA10GR2> explain plan for
  2  select * from t x, t y where y.object_id = 58389 and
  3  (x.created = y.created OR x.last_ddl_time = y.last_ddl_time);

Explained.

ops$tkyte%ORA10GR2> select * from table( dbms_xplan.display );

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1232327374

--------------------------------------------------------------------------------------
| Id  | Operation                     | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |      |     2 |   512 |     8   (0)| 00:00:01 |
|   1 |  CONCATENATION                |      |       |       |            |          |
|   2 |   NESTED LOOPS                |      |     1 |   256 |     4   (0)| 00:00:01 |
|   3 |    TABLE ACCESS BY INDEX ROWID| T    |     1 |   128 |     2   (0)| 00:00:01 |
|*  4 |     INDEX UNIQUE SCAN         | T_PK |     1 |       |     1   (0)| 00:00:01 |
|   5 |    TABLE ACCESS BY INDEX ROWID| T    |     1 |   128 |     2   (0)| 00:00:01 |
|*  6 |     INDEX RANGE SCAN          | IDX3 |     1 |       |     1   (0)| 00:00:01 |
|   7 |   NESTED LOOPS                |      |     1 |   256 |     4   (0)| 00:00:01 |
|   8 |    TABLE ACCESS BY INDEX ROWID| T    |     1 |   128 |     2   (0)| 00:00:01 |
|*  9 |     INDEX UNIQUE SCAN         | T_PK |     1 |       |     1   (0)| 00:00:01 |
|* 10 |    TABLE ACCESS BY INDEX ROWID| T    |     1 |   128 |     2   (0)| 00:00:01 |
|* 11 |     INDEX RANGE SCAN          | IDX2 |     1 |       |     1   (0)| 00:00:01 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - access("Y"."OBJECT_ID"=58389)
   6 - access("X"."LAST_DDL_TIME"="Y"."LAST_DDL_TIME")
   9 - access("Y"."OBJECT_ID"=58389)
  10 - filter(LNNVL("X"."LAST_DDL_TIME"="Y"."LAST_DDL_TIME"))
  11 - access("X"."CREATED"="Y"."CREATED")

Note
-----
   - dynamic sampling used for this statement

31 rows selected.



constraints matter!

Cost v/s Time

hb, January 06, 2010 - 2:48 pm UTC

Hi Tom,

Have a situation, there is a query which suddenly changed plan, proabably due to an index(idx5) getting skewed or something. The explain plan started showing using another index (idx4), and started to take forever in the database. If I force it to use the original index(idx5), it works in less than 2 mins.

The part I am not able to understand how in the world oracle show lower cost with idx4 and never come back where as with idx5, it takes so little time to come back. Why would the Oracle switch to plan thats non-performing?

Any clues or direction would be much appreciated?

Thanks
Tom Kyte
January 06, 2010 - 3:34 pm UTC

indexes don't get skewed.

data values do...


it all has to do with the estimated cardinality - versus the actual.

And the estimated cardinality depends on many factors - statistics, or the lack thereof. The predicate and how the statistics can be applied to them (see this for example: https://www.oracle.com/technetwork/issue-archive/2009/09-jan/o19asktom-086775.html )

As a quick guess, let us say that the values in column idx5 are skewed. "where idx5 = 1" would return ten records, but "where idx5 = 99" would return thousands. Suppose there are five thousand records in the table altogether. If the optimizer has histograms - you might be running into bind peeking, see https://asktom.oracle.com/Misc/oramag/on-tuning-by-tracing.html

Conversely, what if there are no histograms and you do not use bind variables for that column. Then - 5,000 rows - two values - the optimizer will guess "2,500 records for idx5=1 and 2,500 records for idx5=99" - it will not use the index for idx5=1 - but you know it should.

it'll boil down to that - look at the estimated card= value in the plan in v$sql_plan and ask yourself "why is it so far off" - and correct that.

If we get the right estimated card= value, we get the right plan.

Get the wrong card= value, you get the wrong plan (probably)

Bind Variable Peeking...

A reader, January 11, 2010 - 3:53 am UTC


Hi Tom,

As per your suggestion we should not create histograms to circumvent the problems of "Bind Variable Peeking", but on the other hand can't we use the method_opt with skewed option? Won't it have the desired effect?

Thanks.

Tom Kyte
January 18, 2010 - 6:25 am UTC

if you gather with skewed, what do you get?

histograms.

think about it for a minute.....


And, my suggestion IS NOT "do not create histograms", I gave that as one (of many) options. It is NOT the only way, it is not the BEST way (there is no "best way, else there would only be that way).


INDEX FULL SCAN,

A reader, January 15, 2010 - 10:10 am UTC

I have a table with couple of billion rows. When I perform a SELECT COUNT(*) on that table (without any where clause), the explain plan says it is using one of the Indexes and doing a INDEX FULL SCAN. From what I understand is, INDEX FULL SCAN extracts one index block in each I/O unlike INDEX FAST FULL SCAN which can extract multiple blocks (like db file scatterred read) in each I/O.

How can we make optimizer to use INDEX FAST FULL SCAN?

Thanks,

Tom Kyte
January 18, 2010 - 5:26 pm UTC

show me the plan and query please.

Outline with advanced option

Raja, January 21, 2010 - 4:58 am UTC

Hi Tom,

Whle using the advanced option with display_cursor to get the execution plan, it is giving me a section titled "Outline Data".

select * from table(dbms_xplan.display_cursor('8va56uz9wzv2a',0, 'ADVANCED')) ;

How to use that section while tuning a query.

Thank You.
Tom Kyte
January 21, 2010 - 8:46 am UTC

you read it?

not sure what else to say - it is more information, it is telling you "this outline was/was not used". You caused the outline to be created, we are just reporting to you "it was there"

Query and its plan,

A reader, January 21, 2010 - 1:10 pm UTC

The query and its plan that use INDEX FULL SCAN is below:

SQL> explain plan for SELECT COUNT(1) FROM "CPG"."SUBDIE_CLASS_ANALOG" PARTITION("SCA_P1179");

Explained.

SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 1908812635

--------------------------------------------------------------------------
| Id  | Operation               | Name   | Rows  | Cost  | Pstart| Pstop |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT        |        |     1 |     1 |       |       |
|   1 |  SORT AGGREGATE         |        |     1 |       |       |       |
|   2 |   PARTITION RANGE SINGLE|        |    33M|     1 |   346 |   346 |
|   3 |    INDEX FULL SCAN      | SCA_02 |    33M|     1 |   346 |   346 |
--------------------------------------------------------------------------


PLAN_TABLE_OUTPUT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
Note
-----
   - cpu costing is off (consider enabling it)


Information about the indexes available on that table:

INDEX_NAME           COLUMN_NAME               COLUMN_POSITION
-------------------- ------------------------- ---------------
SCA_02               SUBDIE_TEST_DESCP_KEY                   1
SCA_PK               TEST_RUN_KEY                            1
SCA_PK               ID_KEY                                  2
SCA_PK               SUBDIE_KEY                              3
SCA_PK               SUBDIE_TEST_DESCP_KEY                   4

Thanks,

Tom Kyte
January 25, 2010 - 1:32 am UTC

the cost of that full scan is one.

Therefore, I would suspect the statistics on that index are WAY WAY WAY off.

Tuning a query

A Reader, February 02, 2010 - 11:46 am UTC

Tom,

Thanks for sharing your knowledge with us.

Oracle - 9.2.0.8

Problem SQL:


                                                     CPU      Elapsd
  Buffer Gets    Executions  Gets per Exec  %Total Time (s)  Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
      2,395,552          242        9,899.0    1.0   165.36    606.52  328058800
Module: java_q4p@hostA (TNS V1-V3)
SELECT * FROM T WHERE  x_focus_id IS NULL and  (  x_proc_inst ! =  :P16 or
x_test_id =  :P17 or  x_test_stop_time <>  TO_DATE (  '01/01/1753' ,  :P18 )  )  
order by x_test_stop_time DESC


Refrenced Column data types & INdexing scheme:
X_FOCUS_ID               NUMBER ----- INDEXED.
X_PROC_INST              NUMBER,
X_TEST_ID                VARCHAR2(50 BYTE),
X_TEST_STOP_TIME         DATE
....
....
OBJID                  NUMBER ---- PRIMARY KEY


Table "T" has 30 columns in total.




Data disribution:

        select count(*) from T
 237361
 
 
 select count(*) from  T where x_focus_id IS NULL
 0 
 
 select count(*) from T where x_proc_inst ! =  0
 95203
 
 select count(*) from T where x_test_id =  'M DIAG'
 73973
 
 select count(*) from T where x_test_stop_time <>  TO_DATE (  '01/01/1753' ,  'dd/mm/yyyy' )
 187773


 
AUTOTRACE:

SQL> set timing on
SQL> set autotrace traceonly
SQL>
SQL> SELECT *
 12  FROM T
 13   WHERE  x_focus_id IS NULL
 14   and  (  x_proc_inst ! =  0  or  x_test_id =  'M DIAG'
 15  or  x_test_stop_time <>  TO_DATE (  '01/01/1753' ,  'dd/mm/yyyy' )  )
 16   order by x_test_stop_time DESC
 17  /

no rows selected

Elapsed: 00:00:06.51

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=377 Card=1 Bytes=222)

   1    0   SORT (ORDER BY) (Cost=377 Card=1 Bytes=222)
   2    1     TABLE ACCESS (FULL) OF 'T' (Cost=375 Card=1 Bytes=222)





Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       7473  consistent gets
       7442  physical reads
          0  redo size
       3499  bytes sent via SQL*Net to client
        460  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          0  rows processed

SQL>



EXPLAIN PLAN:

SQL> set autotrace off
SQL> explain plan for
  2  SELECT * T
 14   WHERE  x_focus_id IS NULL
 15   and  (  x_proc_inst ! =  0  or  x_test_id =  'M DIAG'
or  x_test_stop_time <>  TO_DATE (  '01/01/1753' ,  'dd/mm/yyyy' )  )
 16   17   order by x_test_stop_time DESC
 18  /

Explained.

Elapsed: 00:00:00.00

SQL> @xplan.sql

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------

--------------------------------------------------------------------------------
| Id  | Operation            |  Name                   | Rows  | Bytes | Cost  |
--------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |                         |     1 |   222 |   377 |
|   1 |  SORT ORDER BY       |                         |     1 |   222 |   377 |
|*  2 |   TABLE ACCESS FULL  | T                    |     1 |   222 |   375 |
--------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("T"."X_FOCUS_ID" IS NULL AND
              ("T"."X_PROC_INST"<>0 OR
              "T"."X_TEST_ID"='M DIAG' OR
              "T"."X_TEST_STOP_TIME"<>TO_DATE(' 1753-01-01 00:00:00',
              'syyyy-mm-dd hh24:mi:ss')))

Note: cpu costing is off

19 rows selected.

Elapsed: 00:00:00.05
SQL>



Question/s

a) What would be the best Indexing scheme to reduce the gets/exec ( to avoid Full Scan on table)?

b) use of exists/not exists can help ?


Regards






Tom Kyte
February 02, 2010 - 12:46 pm UTC

if the column x_focus_id is mostly null, then:
ops$tkyte%ORA11GR2> create index t_idx on t(x_focus_id,0);

Index created.

ops$tkyte%ORA11GR2> set autotrace on
ops$tkyte%ORA11GR2> SELECT /*+ first_rows(10) */ *
  2    FROM T
  3   WHERE  x_focus_id IS NULL and  (  x_proc_inst ! =  0  or  x_test_id =  'M DIAG'
  4         or  x_test_stop_time <>  TO_DATE (  '01/01/1753' ,  'dd/mm/yyyy' )  )
  5   order by x_test_stop_time DESC
  6  /

no rows selected


Execution Plan
----------------------------------------------------------
Plan hash value: 1454352066

--------------------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |     1 |    89 |     2  (50)| 00:00:01 |
|   1 |  SORT ORDER BY               |       |     1 |    89 |     2  (50)| 00:00:01 |
|*  2 |   TABLE ACCESS BY INDEX ROWID| T     |     1 |    89 |     1   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN          | T_IDX |     1 |       |     1   (0)| 00:00:01 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter("X_TEST_STOP_TIME"<>TO_DATE(' 1753-01-01 00:00:00',
              'syyyy-mm-dd hh24:mi:ss') OR "X_PROC_INST"<>0 OR "X_TEST_ID"='M DIAG')
   3 - access("X_FOCUS_ID" IS NULL)


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
          2  consistent gets
          1  physical reads
          0  redo size
        546  bytes sent via SQL*Net to client
        409  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          0  rows processed

ops$tkyte%ORA11GR2> set autotrace off




see
http://asktom.oracle.com/Misc/something-about-nothing.html
for why the ",0"

contd...Tuning a query

A Reader, February 02, 2010 - 11:51 am UTC

Tom,

Sorry I missed this bit earlier.

Excerpts

....

CPU Elapsd
Buffer Gets Executions Gets per Exec %Total Time (s) Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
2,395,552 242 9,899.0 1.0 165.36 606.52 328058800
Module: java_q4p@hostA (TNS V1-V3)
SELECT * FROM T WHERE x_focus_id IS NULL and ( x_proc_inst ! = :P16 or
x_test_id = :P17 or x_test_stop_time <> TO_DATE ( '01/01/1753' , :P18 ) )
order by x_test_stop_time DESC

.....

copied above is from 20 mins durataion statspack.

Regards

..contd.. SQL tuning

A reader, February 02, 2010 - 1:02 pm UTC

Tom,

As I mentioned above...

select count(*) from T where x_focus_id IS NULL
0

So, there is "NO" null entry for x_focus_id in table T.

Kindly suggest.

Regards.

Tom Kyte
February 02, 2010 - 2:20 pm UTC

did you read what I wrote above? I said "if it is mostly null then...."

so, I suggested above already

..contd.. SQL tuning

A Reader, February 02, 2010 - 2:45 pm UTC

My Ignorance.

Sorry Tom.


A reader, February 03, 2010 - 4:20 pm UTC

Hi Tom,

I have a table as below

create table tab1
(
key1 char(25),
key2 char(25)
)

and a lookup table as below

create table lkp
(
key char(45),
SK_ID integer
)

my requirement is I have to retain records if there is no mate on lkp table for the fields key1 and key2

so i write below query

select *
from
(
select *
from tab1 a left outer join lkp b
on a.key1=b.key
)a
Left outer join
lkp b
on a.key2=b.key

here I have to join two times one for key1 and next for key2

Can we do this in single left outer join? OR anyother way


Many Thanks



Tom Kyte
February 04, 2010 - 12:11 pm UTC

never use char(n), use only varchar2 - you'll never be sorry.


I do not follow your schema *at all*. I see no primary keys, no foreign keys. I don't see how you could logically be joining a char(25) to a char(45).



If you have two reads for two different records in lkp for each row in tab1, you need two joins, it is as if lkp was two tables in one (it is in fact :( )



you can either

ops$tkyte%ORA10GR2> insert into tab1 values ( 'x', 'y' );

1 row created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select *
  2    from tab1 left join lkp l1 on (tab1.key1=l1.key) left join lkp l2 on (tab1.key2=l2.key)
  3  /

KEY1                      KEY2
------------------------- -------------------------
KEY                                                SK_ID
--------------------------------------------- ----------
KEY                                                SK_ID
--------------------------------------------- ----------
x                         y



x                         y




ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> select tab1.*,
  2         (select sk_id from lkp where tab1.key1=key),
  3         (select sk_id from lkp where tab1.key2=key)
  4    from tab1
  5  /

KEY1                      KEY2
------------------------- -------------------------
(SELECTSK_IDFROMLKPWHERETAB1.KEY1=KEY) (SELECTSK_IDFROMLKPWHERETAB1.KEY2=KEY)
-------------------------------------- --------------------------------------
x                         y


x                         y



 



the first query is best if you want many rows from tab1 AND your goal is total throughput.

the second query is probably best if you want a few rows from tab1 OR your goal is initial (first row) response time.

A reader, February 04, 2010 - 12:17 pm UTC

Thanks Sir for your prompt reply

oracle chooose wrong explain.

A reader, February 21, 2010 - 1:14 am UTC

Hello Tom
Please have a look on my test:
SQL> ed
Wrote file afiedt.buf

  1  create table t(object_id int,object_name varchar2(1000)) partition by range
(object_id)
  2  (
  3  partition p1 values less than(5000),
  4  partition p2 values less than(10000),
  5  partition p3 values less than(15000),
  6  partition p4 values less than(20000),
  7  partition pm values less than(maxvalue)
  8* )
SQL> /

Table created.

SQL>begin 
1 for i in 1..30 loop
2 insert into t select object_id,object_name from dba_objects;
3 end loop;
4 end 
5 /
1520581 rows created.
SQL> select count(*) from t partition(p1);

  COUNT(*)
----------
    146760

SQL> select count(*) from t partition(p2);

  COUNT(*)
----------
    123630

SQL> select count(*) from t partition(p3);

  COUNT(*)
----------
    149010

SQL> select count(*) from t partition(p4);

  COUNT(*)
----------
    150000

SQL> select count(*) from t partition(pm);

  COUNT(*)
----------
    951181

SQL>create index ind_t_id on t(object_id) local;
index created 

SQL>  exec bms_stats.gather_table_stats(user,'t',method_opt=>'for all columns',cascade=>true);

PL/SQL procedure successfully completed.
SQL> set autotrace traceonly explain;
SQL> set linesize 120;
SQL> select  object_id,count(*) from t where object_id>1 and object_id<5999 group by object_id;

Execution Plan
----------------------------------------------------------
Plan hash value: 2931106398

-------------------------------------------------------------------------------------------------
| Id  | Operation                | Name | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT         |      |  3697 | 18485 |   280  (13)| 00:00:04 |       |       |
|   1 |  PARTITION RANGE ITERATOR|      |  3697 | 18485 |   280  (13)| 00:00:04 |     1 |     2 |
|   2 |   HASH GROUP BY          |      |  3697 | 18485 |   280  (13)| 00:00:04 |       |       |
|*  3 |    TABLE ACCESS FULL     | T    |   172K|   843K|   255   (4)| 00:00:04 |     1 |     2 |
-------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - filter("OBJECT_ID"<5999 AND "OBJECT_ID">1)

SQL> select /*+ index(t IND_T_ID) */ object_id,count(*) from t where object_id>1 and object_id<5999 group by object_id;

Execution Plan
----------------------------------------------------------
Plan hash value: 1485624018

-----------------------------------------------------------------------------------------------------
| Id  | Operation                | Name     | Rows  | Bytes | Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT         |          |  3697 | 18485 |   389   (2)| 00:00:05 |       |       |
|   1 |  PARTITION RANGE ITERATOR|          |  3697 | 18485 |   389   (2)| 00:00:05 |     1 |     2 |
|   2 |   SORT GROUP BY NOSORT   |          |  3697 | 18485 |   389   (2)| 00:00:05 |       |       |
|*  3 |    INDEX RANGE SCAN      | IND_T_ID |   172K|   843K|   389   (2)| 00:00:05 |     1 |     2 |
-----------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("OBJECT_ID">1 AND "OBJECT_ID"<5999)
       filter("OBJECT_ID"<5999 AND "OBJECT_ID">1)

SQL>

It looks oracle choose a FTS way than INDEX.


Then I set sql_trace trace it again ,here are info of 2 SQL  from trace file:
select  object_id,count(*) 
from
 t where object_id>1 and object_id<5999 group by object_id


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.02          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      383      0.21       0.21          0       1068          0        5718
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      385      0.21       0.23          0       1068          0        5718

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 61  

Rows     Row Source Operation
-------  ---------------------------------------------------
   5718  PARTITION RANGE ITERATOR PARTITION: 1 2 (cr=1068 pr=0 pw=0 time=206338 us)
   5718   HASH GROUP BY (cr=1068 pr=0 pw=0 time=216647 us)
 171540    TABLE ACCESS FULL T PARTITION: 1 2 (cr=1068 pr=0 pw=0 time=686385 us)

********************************************************************************

select /*+ index(t IND_T_ID) */ object_id,count(*) 
from
 t where object_id>1 and object_id<5999 group by object_id


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch      383      0.20       0.52        359        743          0        5718
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total      385      0.20       0.52        359        743          0        5718

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 61  

Rows     Row Source Operation
-------  ---------------------------------------------------
   5718  PARTITION RANGE ITERATOR PARTITION: 1 2 (cr=743 pr=359 pw=0 time=341080 us)
   5718   SORT GROUP BY NOSORT (cr=743 pr=359 pw=0 time=309190 us)
 171540    INDEX RANGE SCAN IND_T_ID PARTITION: 1 2 (cr=743 pr=359 pw=0 time=1395563 us)(object id 63924)
from the trace file I found the sql using index is used less blocks than FTS,
could you give some comments?
D:\>sqlplus test/aaaaaa

SQL*Plus: Release 10.2.0.3.0 - Production on Sun Feb 21 15:11:19 2010

Copyright (c) 1982, 2006, Oracle.  All Rights Reserved.


Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.3.0 - Production
With the Partitioning, OLAP and Data Mining options

SQL> show parameter opt;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
filesystemio_options                 string
object_cache_optimal_size            integer     102400
optimizer_dynamic_sampling           integer     2
optimizer_features_enable            string      10.2.0.3
optimizer_index_caching              integer     0
optimizer_index_cost_adj             integer     100
optimizer_mode                       string      ALL_ROWS
optimizer_secure_view_merging        boolean     TRUE
plsql_optimize_level                 integer     2
SQL>


Regards
Alan
Tom Kyte
March 01, 2010 - 5:38 am UTC

umm, your query took longer due to the physical IO it had to do.

what was your point? You chose the wrong plan in this case, the inefficient index. The optimizer looks pretty OK to me here.



Segment statistics

Raja, March 04, 2010 - 9:13 am UTC

Hi Tom,

While tuning a query I have a table which is quite volatile, means that data is trunctaed first and then insert and merge operation happened on that table.

Is there any dba/awr view that will help us to know the past Data manipulation (insert/update/delete) on the table.

Thanks


Tom Kyte
March 04, 2010 - 10:03 am UTC

define "past", how "past"? past the truncate? or what

DBA_TAB_MODIFICATIONS will give you an idea of the activity.

Segment Statistics

Raja, March 05, 2010 - 12:50 am UTC

Thanks Tom,

DBA_TAB_MODIFICATION gives me the latest data manipulation on the table.

What I was trying to get is the history of data manipulations on that table.

Say on 2nd mar - 2000 inserts, 10 deletes, 0 updates
on 3rd mar - 1000 inserts, 20 deletes, 10 updates

Thanks
Tom Kyte
March 05, 2010 - 5:39 am UTC

not going to happen, to low level - we don't need that information internally for anything so we would never burden ourselves with tracking it.

If you want that minutiae, you'll have to record it from your application.

Thanks

Raja, March 09, 2010 - 2:23 am UTC

Thanks Tom

regarding plan_hash_value

VS, March 10, 2010 - 7:52 am UTC

Dear Tom,
good day to you, I was reading a document on performance tuning and I am confused with the below text, if you can please help me on the same.

"An alternative is to examine the shrared pool to determine whether there are many statements with same sql plan but with different sql text"

Do they mean plan_hash_value from v$sql when they say "determine if there are many statements with same sql plan" if not can you please shed some light on the same.

Thanks a lot for your help on this.
Tom Kyte
March 10, 2010 - 9:00 am UTC

select distinct *
  from
(
select sql_text,plan_hash_value,
       count(distinct sql_text) over (partition by plan_hash_value) cnt
  from v$sql
)
where cnt > 1
order by 2
/


yes.

Performance Tuning

Anish, March 12, 2010 - 7:32 am UTC

Hi Tom,

Say we have a table Tab1 with millions of records; also we have constraint that we cannot create any indexes on table Tab1 as this table would be dynamically created and populated from PL/SQL.
When this table Tab1 is joined with the other application tables, obviously the optimizer would do FTS on table Tab1.
In my case the bytes for the FTS is 963M which is very huge because we are using many aggregate function on the columns of this table
Can you please let me know the other approaches by which the performance could be increased; I mean to say by increasing the size of the Oracle parameters for the session level?
As I am a beginner in SQL tuning, please help me with this

Thanks
Anish

Tom Kyte
March 12, 2010 - 3:48 pm UTC

also we have constraint that
we cannot create any indexes on table Tab1 as this table would be dynamically
created and populated from PL/SQL.


that basically says "we have a SELF-IMPOSED RESTRICTION that we cannot do X because of Y" - but I see no basis in reality for Y precluding X, none. I do not see a single connection between the two. Please do explain.


When this table Tab1 is joined with the other application tables, obviously the
optimizer would do FTS on table Tab1.


and that probably is the right plan, and you surely have not given us one reason to think otherwise. If I want to get most of the rows from a table, which I have to assume you do - you don't show us or explain anything otherwise - a full scan is dead on, correct, the right way.

In my case the bytes for the FTS is 963M which is very huge because we are
using many aggregate function on the columns of this table


even MORE SO - these are reasons to full scan, you haven't given us any indication that any other way would make sense yet.


As I am a beginner in SQL tuning, please help me with this

The first step is to throw out delusions like "we have a SELF-IMPOSED RESTRICTION that we cannot do X because of Y" - if you rule out things blindly - for no apparently good reason (hey, if plsql can a) create the table - which in itself is a really bad design choice, having plsql create a table like that and b) populate the table, you know what else it could do? it could do c) index the table IF it makes sense)

The second step is to realize that a full scan is correct and appropriate for processing many/most of the rows in a table.

The third step is to figure out where you are spending your time. If your full scan "flies" and doesn't wait for anything significant - the only way to make it faster will be:

a) don't do it - find a way to NOT have to do that, nothing will be faster
b) use compression - you have that as a feature since 9ir2
c) load the table with the aggregates, not the details in the first place
d) create an index that would be truly useful (I refuse to follow the "we have a constraint" line of discussion)
etc...

that is, you need to really understand what you are trying to do and what the database can do - this is less about sql tuning than about understanding what is possible

Effecient SQL

cowboy, March 19, 2010 - 5:03 pm UTC

I will appreciate your respose

suppose
table a
( fac_id number(10),id number(5), posting date, account_no number(10)
) --> table partitoned on posting date and it has 24 million records

TABLE b
(id number(5), account_no number(10), sop varchar2(2)
)
The following query performance is slow, I tried separting out the logic union and did not solve the issue


select a.*
from a, b
where fac_id = 100
and a.id = b.id
and a.ccount_no = b.account_no
and ((b.sop = '1')
OR (b.sop = 'S' AND a.posting date between
to_date('07/01/2009','mm/dd/yyyy')
and to_date ('02/28/2010','mm/dd/yyyy')
))
and b.id = 1



Tom Kyte
March 20, 2010 - 9:17 am UTC

24 million records is pretty small so I assume that table B must be gigantic?

24 million records is also entirely useless as information. So what, we know that the table is somewhere between 24mb and infinity zetabytes in size?


how slow is slow, looks pretty straightforward. I'm expecting the plan to be:


table access full of A, unless fac_id is selective and indexed, then maybe an index range scan.

probably full scan of B, unless sop or id,sop is indexed and selective and then maybe a range scan on that.

hash join.


but I'd be guessing because there is less information here then I put here:

<this space left intentionally blank :)>


Efficient SQL

cowboy, March 20, 2010 - 7:10 pm UTC

Thanks for the reply.

Table A has 24 million records. Table B is not that big, only one million records.
The query is taking 20 minutes to process
Table A is partitioned on posting date and indexed on fac_id and account_no.
Table B has index on id and account_no.
The EXPLAIN Plan shows the TABLE A -- FULL table scan
Is there is any way I can rewrite to make the TABLE A index range scan?

Thanks for the great help
Tom Kyte
March 22, 2010 - 8:33 am UTC

how many rows out of A get returned.

Look at your query:

select a.*
from a, b
where fac_id = 100
and a.id = b.id
and a.ccount_no = b.account_no
and ((b.sop = '1')
OR (b.sop = 'S' AND a.posting date between
to_date('07/01/2009','mm/dd/yyyy')
and to_date ('02/28/2010','mm/dd/yyyy')
))
and b.id = 1


the predicate on a.posting date pretty much would be useless for an index- because posting date cannot be used to find the records to be returned (the OR is there)

so that leaves fac_id = 100, how many of the 24,000,000 records are fac_id = 100 and what is the clustering factor on that index.

Why not paste the Complete Explain Plan with all the predicates??!!

A reader, March 22, 2010 - 8:21 pm UTC


that should help.

Tom Kyte
March 23, 2010 - 1:24 am UTC

how so? all of the predicates are above.

without the information I asked for - you could not look at a plan and say whether is was good or not. the plan would not be very useful right now.

what would you do with it?

SQL tuning

abhijit, March 23, 2010 - 11:42 am UTC

Hi Tom

Can you please suggest me a way to tune the follwing two query:

Query1:

select * from emp
where INSTR('101,102,103',NVL(dept,'111'))=0

It would be great if this can be tuned without the function based index.Do we have anyother workaround here.

Query 2:
What can we do to tune NVL over any column like

select * from emp
where nvl(dept,'111') != '002'

I apologize for taking the emp table but I cant post the exact code here. I hope you understand.
Tom Kyte
March 23, 2010 - 12:57 pm UTC

query number 1

select * from emp where dept not in (101,102,103);

query number 2

select * from emp where dept != 2 or dept is null;

both will almost certainly full scan, they are not really candidates for using an index - they are "nots"


if you wanted index access for those specific values, a function based index could be used.



Tuning

Abhijit, March 24, 2010 - 8:57 am UTC

Hi Tom,

Thanks a ton for the explanation. One more doubt regerding select 1, select 'x' or select NULL

which is faster for exists keyword and why?

Query 1:
select name from emp e 
where exists(
SELECT 1 FROM dept  d
where d.dept=e.dept
)


Query2:
select name from emp e 
where exists(
SELECT 'x' FROM dept  d
where d.dept=e.dept
)



Query3:
select name from emp e 
where exists(
SELECT NULL FROM dept  d
where d.dept=e.dept
)

Tom Kyte
March 26, 2010 - 10:59 am UTC

they are all internally

'select null from table'



we know you NEED NOTHING from the table, so we ..... ta-dah - select nothing. All we need to do is verify a row exists.


So, it has nothing to do with performance. It has everything to do with understanding "what is the correct way to code it"


If you use "where exists ( select null from ... "

then when people that know look at your code, they will say "ah-hah, here is finally someone that got it - they probably use select count(*) instead of select count(1) as well - this is a good developer". And people that do not know will look at it and ask "why did you do that" and you can educate them.


Plan changes and I am getting back

Vengata N Guruswamy, March 25, 2010 - 2:13 pm UTC

Hi Tom,

This is what I observed from database USER_BIND_PEEK_MISMATCH and ROLL_INVALID_MISMATCH is showing 'Y' for many of shared cursors.There is a plan change observed.Some plan changed for the better (good no issues) . But when a single plan changes to bad it brings the applications to its kneel.

Currently we are planning to flush the entire shared pool after the analyze. Else as a plan B add NO_INVALIDATE to TRUE to the analyze statement .

Can you please throw some light on this cursor invalidations?
Tom Kyte
March 26, 2010 - 3:11 pm UTC

I'm not sure what you want me to comment on? Can you please throw some light on this cursor invalidations? didn't point me to anything to comment on.

user_bind_peek_mismatch sounds like cursor sharing similar? or what is your version?

roll_invalid is what you'll see after you gather statistics, we do not invalidate everything right away, we do it slowly over time - rolling the invalidations.

Need to enforce to use more than one index on same table

Santosh, March 26, 2010 - 12:47 am UTC

Is it not possible to include an hint to enforce usage of more than one index on same table ?

select /*+ index(t,idx1) index(t,idx9) */ from table t where t.col1='A' and t.col9='1234'
Tom Kyte
March 26, 2010 - 3:27 pm UTC

Typically, we will use one index at a time to process something like that.

There are two big exceptions

a) they are bitmap indexes. We use multiple bitmaps easily and often. However, unless you are a readonly/read mostly reporting system - you cannot use bitmaps.


ops$tkyte%ORA10GR2> create table t as select * from all_objects;
Table created.

ops$tkyte%ORA10GR2> exec dbms_stats.gather_table_stats(user,'T');
PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> create bitmap index t_idx1 on t(owner);
Index created.

ops$tkyte%ORA10GR2> create bitmap index t_idx2 on t(object_type);
Index created.

ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from t where owner = 'SCOTT' and object_type = 'TABLE';

Execution Plan
----------------------------------------------------------
Plan hash value: 2789881824

---------------------------------------------------------------------------------------
| Id  | Operation                    | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |        |    62 |  5766 |    14   (0)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID | T      |    62 |  5766 |    14   (0)| 00:00:01 |
|   2 |   BITMAP CONVERSION TO ROWIDS|        |       |       |            |          |
|   3 |    BITMAP AND                |        |       |       |            |          |
|*  4 |     BITMAP INDEX SINGLE VALUE| T_IDX2 |       |       |            |          |
|*  5 |     BITMAP INDEX SINGLE VALUE| T_IDX1 |       |       |            |          |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - access("OBJECT_TYPE"='TABLE')
   5 - access("OWNER"='SCOTT')

ops$tkyte%ORA10GR2> set autotrace off



The other case with b*tree indexes is when we can do an index join, there - every column we need is present in the set of indexes we join together, for example:


ops$tkyte%ORA10GR2> drop index t_idx1;

Index dropped.

ops$tkyte%ORA10GR2> drop index t_idx2;

Index dropped.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create index t_idx1 on t(owner,object_name);

Index created.

ops$tkyte%ORA10GR2> create index t_idx2 on t(object_type, status );

Index created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select owner, object_type, object_name, status from t where owner = 'SCOTT' and object_type = 'TABLE';

Execution Plan
----------------------------------------------------------
Plan hash value: 2547943377

---------------------------------------------------------------------------------------
| Id  | Operation          | Name             | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |                  |    77 |  3619 |    22   (5)| 00:00:01 |
|*  1 |  VIEW              | index$_join$_001 |    77 |  3619 |    22   (5)| 00:00:01 |
|*  2 |   HASH JOIN        |                  |       |       |            |          |
|*  3 |    INDEX RANGE SCAN| T_IDX2           |    77 |  3619 |     9  (12)| 00:00:01 |
|*  4 |    INDEX RANGE SCAN| T_IDX1           |    77 |  3619 |    14   (8)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("OBJECT_TYPE"='TABLE' AND "OWNER"='SCOTT')
   2 - access(ROWID=ROWID)
   3 - access("OBJECT_TYPE"='TABLE')
   4 - access("OWNER"='SCOTT')

ops$tkyte%ORA10GR2> set autotrace off


and sometimes we can do bitmap tricks with them as well:

ops$tkyte%ORA10GR2>  select owner, object_type, object_name, status, last_ddl_time from t where owner = 'SCOTT' and object_type = 'TABLE';

Execution Plan
----------------------------------------------------------
Plan hash value: 2165004004

-------------------------------------------------------------------------------------------
| Id  | Operation                        | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                 |        |    77 |  4235 |    38   (6)| 00:00:01 |
|   1 |  TABLE ACCESS BY INDEX ROWID     | T      |    77 |  4235 |    38   (6)| 00:00:01 |
|   2 |   BITMAP CONVERSION TO ROWIDS    |        |       |       |            |          |
|   3 |    BITMAP AND                    |        |       |       |            |          |
|   4 |     BITMAP CONVERSION FROM ROWIDS|        |       |       |            |          |
|   5 |      SORT ORDER BY               |        |       |       |            |          |
|*  6 |       INDEX RANGE SCAN           | T_IDX2 |       |       |     8   (0)| 00:00:01 |
|   7 |     BITMAP CONVERSION FROM ROWIDS|        |       |       |            |          |
|   8 |      SORT ORDER BY               |        |       |       |            |          |
|*  9 |       INDEX RANGE SCAN           | T_IDX1 |       |       |    13   (0)| 00:00:01 |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   6 - access("OBJECT_TYPE"='TABLE')
       filter("OBJECT_TYPE"='TABLE')
   9 - access("OWNER"='SCOTT')
       filter("OWNER"='SCOTT')


here we converted btrees into bitmaps for a second to do that.

but in general - you will use ONE or the OTHER of the b*tree's, but not both.



The index you want for the above would be the index on t(col1,col9) - you want a concatenated index.

Unless you are read only/read mostly, then you want single column bitmap indexes.

OR Expansion

Abhisek, March 26, 2010 - 1:31 pm UTC

hi Tom,

I was loooking into a explain which had

select a.col1 from
table1 a
where a.col4='some_value'
AND EXISTS( SELECT 1 from table2 b
where b.col2=a.col2
or b.col3=a.col3)

Due to this part, I could see there was a concatenation in the explain plan which raised the cost of the query. Again when I tried for the NO_EXPAND hint, it started using BITMAP TO ROWID operation which is the costliest operation but CONCATENATION was solved.

Can you please suggest me a good waky to handle this. If more information is required, let me know.
Tom Kyte
March 26, 2010 - 3:45 pm UTC

a good way to handle what???

You used a hint, resulting in a different query plan - one that was probably less efficient. I don't know what you are asking to handle?

Why did a concatenation - a very good plan step in general indeed - need to be "solved"

NESTED LOOP to HASH join

Swarup, April 07, 2010 - 9:44 am UTC

Hi Tom
I am trying to force HASH-JOIN into below given query. But it is repeatedly using NESTED LOOP.
I tried USE_HASH, changed order of tables, analyzed(compute statistics) both tables, etc, but plan is still picking NESTED LOOP.

CFG_HOURS_BAND has just 10 rows.
TMP_TBL has 4 million rows and no PK or index.

SELECT tpd.c1, tpd.c2, hr.dur_id, hr.label
from (SELECT dur_id, label, (low_range * 60) low_range_mins, (high_range * 60) high_range_mins
FROM CFG_HOURS_BAND
WHERE deleted IS NULL) hr,
(SELECT c1, c2, NVL(duration, -9999) duration
from TMP_TBL) tpd
WHERE tpd.duration >= NVL(hr.low_range_mins,tpd.duration)
AND tpd.duration < NVL(hr.high_range_mins,tpd.duration+1)

------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 117K| 2865K| 2063K (1)| 06:52:48 |
| 1 | NESTED LOOPS | | 117K| 2865K| 2063K (1)| 06:52:48 |
|* 2 | TABLE ACCESS FULL| CFG_HOURS_BAND | 10 | 140 | 3 (0)| 00:00:01 |
|* 3 | TABLE ACCESS FULL| TMP_PRODUCT_DETAILS | 11736 | 126K| 206K (1)| 00:41:17 |
------------------------------------------------------------------------------------------

Please help me to get rid of NESTED LOOP.

Thanks
Swarup
Tom Kyte
April 13, 2010 - 7:28 am UTC

answer me how you would "hash" on that non-equijoin? Think about what a HASH is and does and ask "how would I set up a hash function to satisfy a >= f(x,y) and a < f(x,y+1)"


when you can supply that hash function - we'll start hashing away for you - the problem is, there is an infinite set of values between f(x,y) and f(x,y+1) - you cannot "hash" into that.

execution plan

Branka, April 13, 2010 - 3:29 pm UTC

I executed 2 version of same query, and first one has "bad" executin plan, but it execute in 3 minutes. Second one take more than one hour to execute. I do not understand where is problem. Second one is more correct. Both query return 5 rows.

--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 13652 | 1533K| 220K (5)| 00:44:03 |
|* 1 | TABLE ACCESS BY INDEX ROWID| APPLICATION_STATUS | 1 | 18 | 11 (0)| 00:00:01 |
| 2 | NESTED LOOPS | | 13652 | 1533K| 220K (5)| 00:44:03 |
|* 3 | TABLE ACCESS FULL | APC | 12869 | 1219K| 109K (10)| 00:21:57 |
|* 4 | INDEX RANGE SCAN | I_AS_FK_PC_ID | 13 | | 2 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------

---------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 575 | 18 (0)| 00:00:01 |
| 1 | NESTED LOOPS | | 5 | 575 | 18 (0)| 00:00:01 |
| 2 | TABLE ACCESS BY INDEX ROWID| APPLICATION_STATUS | 5 | 90 | 8 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | I_A | 5 | | 3 (0)| 00:00:01 |
|* 4 | TABLE ACCESS BY INDEX ROWID| APC | 1 | 97 | 2 (0)| 00:00:01 |
|* 5 | INDEX UNIQUE SCAN | APC_PK | 1 | | 1 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------------

Tom Kyte
April 14, 2010 - 8:54 am UTC

you've got to be kidding me.


Here, I have two plans:

plan 1:
loop
  pick up item from shelf
  move to other other
  exit when no more items

plan 2:
get really big box and hand cart
fill box
put box on hand cart
wheel over to other shelf
empty box
put box and cart way


plan 1 is "bad", but I can do it in 3 minutes. Plan 2 takes more than one hour to execute.

What is wrong?

When you can answer me - I'll be able to give you some ideas.

But bear in mind, no matter what you say to me, I'll say "no, that is not it" because I'll add some crucial bit of information that nullifies your idea - and I'll keep doing that over and over until you have a precise understanding of all of my situation and can come up with a reasonable answer.



execution plan

Branka, April 14, 2010 - 10:51 am UTC

I droped index I_A and now execution plan say that is would be wors than second plan, but it actualy execute in 3 minutes. It does display correct number of expected rows.
I still donot have explanation, just solution.
--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 575 | 112K (9)| 00:22:29 |
|* 1 | TABLE ACCESS BY INDEX ROWID| APPLICATION_STATUS | 1 | 18 | 3 (0)| 00:00:01 |
| 2 | NESTED LOOPS | | 5 | 575 | 112K (9)| 00:22:29 |
|* 3 | TABLE ACCESS FULL | APC | 1305 | 123K| 108K (9)| 00:21:46 |
|* 4 | INDEX RANGE SCAN | I_AS_FK_PC_ID | 13 | | 1 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------

Tom Kyte
April 14, 2010 - 3:50 pm UTC

you don't need an explanation.

You need information, data, facts.

when you can explain my problem, I can explain yours. I cannot give you an explanation for my problem - just the solution (do you see where I'm going here????)

I gave you NO information. I didn't tell you anything about the stuff on the shelf, how big it is, how heavy, how fragile, how many. I didn't tell you how far away I have to go to get this box and cart. I didn't tell you how fast I could walk from shelf to shelf and how fast the cart could go. I didn't tell you how big the box was, or how much it weighed (it would be overhead, I might not be able to fill it up)

and so on.


do you see what I'm saying??

Use of temporary tables to tune

Abhisek, April 30, 2010 - 8:10 am UTC

Hi Tom,

I have a feeling that we can create temporary table to hold the logic that is being used again and again in a package. But I am not able to conceptualize it.

Is it a good idea to keep the joined table data in a temporary table and use it for entire package or use the same join statements again and again..

If temp table idea is better, can you please give me an example and any disadvantages it has..
Tom Kyte
April 30, 2010 - 8:54 am UTC

search for

create global temporary table

on this site, many pre-existing examples.

SQL Tunings

krishna, June 15, 2010 - 5:04 am UTC

Hi Tom,

Pls, help me to tune the following SQL, as it is giving 'java.sql.SQLException: ORA-01000: maximum open cursors exceeded' exception when executing it through program.

The sub-query is yielding quite large data within the main query.

java.sql.SQLException: ORA-01000: maximum open cursors exceeded

--- Query ---

SELECT r.case_acct_num as caseAcctNum,
trim(r.case_mgmt_ref_id1) as caseMgmtRefId1,
trim(r.case_mgmt_ref_id2) as caseMgmtRefId2,
r.status as status
FROM cas_giro_receipt r
WHERE r.case_acct_num = {caseAcctNum}
and ( r.trans_cde1 = {transCde} or r.trans_cde2 = {transCde} )
and r.direct_debit_id_num in
(
SELECT p.direct_id_num
FROM cas_payer_payee_giro p
WHERE p.id_type = {idtype}
and p.id_num = {idNum}
)
order by r.case_acct_num, r.case_mgmt_ref_id1, r.case_mgmt_ref_id2


Thanks in Advance
Krishna

join big tables

Ravi B, June 22, 2010 - 6:56 pm UTC

Hi Tom,

I have SQL which joins 3 big tables. The execution plan is always a hash join irrespective of the indexes. The query takes several hours to finish. Do you have any suggestion with respect to resize any system/session parameters?

big_table1 => 8984325 rows
big_table2 => 135170286 rows
big_table3 => 893128 rows


select p.id, f.name
from big_table1 p,
big_table2 e,
big_table3 f
where p.originate_from = 2
and p.id = e.id
and p.task_id = e.task_id
and p.hostid = e.hostid
and e.task_id = f.task_id
and e.file_id = f.file_id

please let me know if you need more information.

Thanks,
Ravi
Tom Kyte
June 24, 2010 - 6:21 am UTC

... The execution plan is always a hash join
irrespective of the indexes. ...

boy, that sounds like perfection, I was worried for a minute you were going to tell me it would use indexes!! that would almost surely be *bad*


http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:6749454952894#6760861174154

go ahead, hint it to use indexes and then take a vacation while it runs.

Unless "p.orginate_from = 2" returns a very small number of rows, I would fully expect hash joins.

what is the plan for that query? with estimated row counts please.


make sure you have sufficient PGA resources available, is your pga_aggregate_target a) being used, b) set to a reasonable value?

More details ...

Ravi B, June 24, 2010 - 12:08 pm UTC

Hi Tom,

Following are the details from tkprof.

p.originate_from = 2 has 6118691 rows. Entire query returns same number of rows (6118691)
pga_aggregate_target = 2g (it was 1g, changing to 2g dint made any difference)
sort_area_size=4194304
WORKAREA_SIZE_POLICY = AUTO

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.04 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 407914 296.77 494.23 343157 602169 0 6118691
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 407916 296.78 494.27 343157 602169 0 6118691

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 104

Rows Row Source Operation
------- ---------------------------------------------------
6118691 HASH JOIN (cr=602169 pr=343157 pw=21135 time=552911898 us)
893128 TABLE ACCESS FULL big_table3 (cr=8054 pr=8043 pw=0 time=18843463 us)
6118691 HASH JOIN (cr=594115 pr=335114 pw=21135 time=360271023 us)
6118691 TABLE ACCESS FULL big_table1 (cr=64935 pr=64908 pw=0 time=91010113 us)
135170286 TABLE ACCESS FULL big_table2 (cr=529180 pr=249056 pw=0 time=1351778882 us)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 407914 0.00 3.14
db file scattered read 20214 0.37 202.63
direct path write temp 1409 0.00 0.02
direct path read temp 1410 0.00 0.03
SQL*Net message from client 407914 118.47 1252.00
latch: cache buffers lru chain 1 0.00 0.00
latch free 2 0.00 0.00
db file sequential read 2 0.03 0.04

Tom Kyte
July 06, 2010 - 9:38 am UTC

looks like most of the time is spent waiting for the client to tell us to do something (SQL*Net message from client ).

as stated, that query plan looks AWESOME (please read the link I gave you above and ponder that for a minute)


you do very little read/write to/from temp so the pga is bigger than good enough for this query.

Why a plan would change when I add an or clause with 1=2

A reader, June 30, 2010 - 12:21 pm UTC

I fail to understand why oracle is Changing Plan/Cardinality when I add an always false or clause
1=2
SQL>  SELECT prty.prty_id,
  2               prty.selr_srvr_no
  3          FROM ss_master.prty prty 
  4         WHERE (  
  5                  prty.selr_srvr_no in ( select column_value from sxukgp.i_selr_srvr_no_9 b,TABLE
(b.selr_srvr_no_9))
  6               )
  7    or 1 =2
  8  /

Execution Plan
----------------------------------------------------------
Plan hash value: 3088989436

----------------------------------------------------------------------------------------
| Id  | Operation             | Name           | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |                | 60971 |   714K|    59   (4)| 00:00:01 |
|*  1 |  FILTER               |                |       |       |            |          |
|   2 |   INDEX FAST FULL SCAN| PRTY_IX02      | 60971 |   714K|    55   (4)| 00:00:01 |
|*  3 |   TABLE ACCESS FULL   | SELR_SRVR_NO_9 |     2 |    12 |     4   (0)| 00:00:01 |
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter( EXISTS (SELECT /*+ */ 0 FROM "SXUKGP"."SELR_SRVR_NO_9"
              "SELR_SRVR_NO_9" WHERE "COLUMN_VALUE"=:B1))
   3 - filter("COLUMN_VALUE"=:B1)

Note
-----
   - dynamic sampling used for this statement

SQL>  SELECT prty.prty_id,
  2               prty.selr_srvr_no
  3          FROM ss_master.prty prty 
  4         WHERE (  
  5                  prty.selr_srvr_no in ( select column_value from sxukgp.i_selr_srvr_no_9 b,TABLE
(b.selr_srvr_no_9))
  6               )
  7    --or 1 =2
  8  /

Execution Plan
----------------------------------------------------------
Plan hash value: 2829820241

----------------------------------------------------------------------------------------
| Id  | Operation             | Name           | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT      |                |   202 |  3636 |    60   (5)| 00:00:01 |
|*  1 |  HASH JOIN RIGHT SEMI |                |   202 |  3636 |    60   (5)| 00:00:01 |
|   2 |   TABLE ACCESS FULL   | SELR_SRVR_NO_9 |   202 |  1212 |     4   (0)| 00:00:01 |
|*  3 |   INDEX FAST FULL SCAN| PRTY_IX02      | 24285 |   284K|    55   (4)| 00:00:01 |
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("PRTY"."SELR_SRVR_NO"="COLUMN_VALUE")
   3 - filter("PRTY"."SELR_SRVR_NO" IS NOT NULL)

Note
-----
   - dynamic sampling used for this statement

SQL> 

merge join cartesian

Ravi B, July 19, 2010 - 3:47 pm UTC

Hi Tom,

We have two identical system in terms of OS and database setup.

One of our queries were taking a long time in on of the systems. When i checked the explain plan the query which is taking long time is doing merge join cartesian and was consuming huge TEMP segment and errors out in about 45 mins. Where as in other system it was doing hash joins and the query comes up in few seconds.

I did analyze tables but the result was same. But, when i used the hint ORDERED, the plan came out identical and the query ran in few seconds.

Why would the optimizer use MERGE JOIN CARTESIAN? Is there anything i could have done instead of using ORDERED hint?

Thanks,
Ravi
Tom Kyte
July 23, 2010 - 6:42 am UTC

are the plans without hints showing the same estimated cardinalities. It is a bit hard to comment without any supporting data.

when you say analyze, you really mean gather statistics via dbms_stats right.

Query using temp tablespace

Nishant, August 17, 2010 - 10:18 pm UTC

HI Tom,

One of our query using huge temporary tablespace and at last it will failed with unable to extend temporary tablesapce. Could you please advice how can i avoid failing this query ? I have colleceted the table statistics using dbms_stat but not helped.

# Table involved in this query

PRCPROD> select count(1) from PRICING_ADMIN.STG_CREDIT_REQUEST_OUT;

  COUNT(1)
----------
     23947

PRCPROD> select count(1) from PRICING_ADMIN.STG_CREDIT_REQUEST_ITEM_OUT;

  COUNT(1)
----------
     55792

PRCPROD> select count(1) from PRICING_OWNER.POS_DATA;

  COUNT(1)
----------
   1354658

# Query

SELECT POS.OID , CR.QUEUE_ID , CR.DEBIT_NUM , POS.CLAIM_NUM , CRI.DISTI_INVOICE_NUM , CRI.MPN , POS.MFR_TRACKING_NUM , CRI.CREDIT_MEMO_NUM 
FROM STG_CREDIT_REQUEST_OUT CR , STG_CREDIT_REQUEST_ITEM_OUT CRI , POS_DATA POS 
WHERE CR.REMARK IS NULL AND CR.QUEUE_ID = CRI.QUEUE_ID AND CR.DEBIT_NUM = CRI.DEBIT_NUM AND CRI.DEBIT_NUM = POS.DEBIT_NUM AND CRI.MPN = POS.MPN 
AND CRI.QUANTITY = POS.SHIP_QTY AND CRI.DISTI_INVOICE_NUM = POS.INVOICE_NUM 
AND CRI.CREDIT_MEMO_NUM IS NOT NULL AND CRI.REMARK IS NULL AND POS.STATUS = 'Accepted'
/

# Failed statement's excecution plan

Plan hash value: 1875362163

------------------------------------------------------------------------------------------------------------------------------------------------------------

| Id  | Operation             | Name                        | Starts | E-Rows | A-Rows |   A-Time   | Buffers | Reads  | Writes |  OMem |  1Mem | Used-Mem |

------------------------------------------------------------------------------------------------------------------------------------------------------------

|*  1 |  HASH JOIN            |                             |      1 |      1 |      0 |00:00:00.01 |       0 |      0 |      0 |   625K|   625K|          |

|   2 |   MERGE JOIN CARTESIAN|                             |      1 |      1 |     28M|00:04:02.13 |   32439 |    218K|   8532 |       |       |          |

|*  3 |    TABLE ACCESS FULL  | STG_CREDIT_REQUEST_OUT      |      1 |      1 |     22 |00:00:00.01 |      26 |      0 |      0 |       |       |          |

|   4 |    BUFFER SORT        |                             |     22 |   1260K|     28M|00:04:02.60 |   32413 |    218K|   8532 |   149M|  3812K|   90M (0)|

|*  5 |     TABLE ACCESS FULL | POS_DATA                    |      1 |   1260K|   1298K|00:00:39.03 |   32411 |  32275 |      0 |       |       |          |

|*  6 |   TABLE ACCESS FULL   | STG_CREDIT_REQUEST_ITEM_OUT |      0 |      1 |      0 |00:00:00.01 |       0 |      0 |      0 |       |       |          |

------------------------------------------------------------------------------------------------------------------------------------------------------------


Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("CR"."QUEUE_ID"="CRI"."QUEUE_ID" AND "CR"."DEBIT_NUM"="CRI"."DEBIT_NUM" AND "CRI"."DEBIT_NUM"="POS"."DEBIT_NUM" AND

              "CRI"."MPN"="POS"."MPN" AND "CRI"."QUANTITY"="POS"."SHIP_QTY" AND "CRI"."DISTI_INVOICE_NUM"="POS"."INVOICE_NUM")

   3 - filter("CR"."REMARK" IS NULL)
   5 - filter("POS"."STATUS"='Accepted')
   6 - filter(("CRI"."REMARK" IS NULL AND "CRI"."CREDIT_MEMO_NUM" IS NOT NULL))


29 rows selected.

A reader, August 25, 2010 - 2:15 pm UTC

Sir,

The below is a paragraph from a book on 'SQL tuning' -in this book the author suggested an approach to find a better optimal execution plan for an SQL.

I could not understand completely the logic (the formula) he explained below - Can you please explain in a simple way (your excellent way of explainig the things) ?

""<:
A more subtle case arises when the end user might query on any value, but the end user is more likely to query on common values than uncommon values. For example,
if operators bring up customers by finding all customers that have the last name of the calling customer, they will bring up common last names more often than uncommon ones with a query such as:
SELECT ... FROM Customers WHERE Last_Name = 'SMITH';
Here, if you just counted distinct names, as you counted order IDs earlier, you would see an over-optimistic selectivity that assumed you were just as likely to
search for Last_Name='KMETEC' as for Last_Name='SMITH'. Each last name has a selectivity of n(i)/C, where n(i) is the count of rows with the ith nonnull last name and C
is the count of all rows in the table. If choosing any last name were equally probable, you could just average n(i)/C over all the last names. That average would equal
one over the number of distinct names. However, the probability of searching on a last name in this scenario is n(i)/C', where C' is the count of rows having nonnull last
names. Therefore, you really need the sum of the selectivities times the probability of seeing each selectivity—i.e., the sum of (n(i)/C') × (n(i)/C)—over all last names. Since C' is also the sum of the individual n(i) values, you can compute the filter selectivity
in SQL as follows:
SELECT SUM(COUNT(Last_Name)*COUNT(Last_Name))/
(SUM(COUNT(Last_Name))*SUM(COUNT(*)))
FROM Customers GROUP BY Last_Name; "
Tom Kyte
August 26, 2010 - 12:58 pm UTC

why do I get questions on things *other people* wrote, asking me to explain what they meant. This is a serious question from me - I get this a lot and I don't understand why I should be able to explain what someone else was actually trying to say??


I think they were trying to say "if you have skewed data, sometimes your query will be very selective and return few rows and sometimes it will not be very selective and will return a large number of rows".


Need GV$SQL_WAIT

Tony, August 26, 2010 - 10:47 pm UTC

Like gv$session_wait, why don't Oracle provide gv$sql_wait?
We could see sql specific wait in TKPROF but not avaliable in any dictionary views. And also cr, pr, time info for each step in the plan. If these stats gathering are resource consuming, Oracle could make it optional by
indtoducing a new init parameter.

Tom, your thoughts?

Need GV$SQL_WAIT

Tony, August 26, 2010 - 10:47 pm UTC

Like gv$session_wait, why don't Oracle provide gv$sql_wait?
We could see sql specific wait in TKPROF but not avaliable in any dictionary views. And also cr, pr, time info for each step in the plan. If these stats gathering are resource consuming, Oracle could make it optional by
indtoducing a new init parameter.

Tom, your thoughts?

SQL Fine tuning

Shiv a Ellur, September 01, 2010 - 2:35 am UTC

Tom,

In earlier version of oracle, we were using undocumented hint named /*+ BYPASS_UJVC */ for updating a table and it was pretty faster in meeting our requirements. However we have upgraded our oracle to 11g R2 and bypss hint is not supported in it. Hence re-wrote the quries in two ways and here is the test results:

update (select /*+ BYPASS_UJVC */
a.qty_bo new_qty_bo, b.qty_bo
from view_it_bo a, t_req_dt b
where a.SEQ_DELIV = b.seq_deliv
AND a.seq_d_line = b.seq_d_line
and a.qty_bo <> b.qty_bo)
set qty_bo = new_qty_bo

call elapsed rows
------- ---------- ----------
total 39.46 58048


MERGE INTO T_REQ_DT B --Alternate query 1
USING (SELECT QTY_BO, SEQ_DELIV, SEQ_D_LINE FROM VIEW_IT_BO) A
ON (A.SEQ_D_LINE = B.SEQ_D_LINE AND A.SEQ_DELIV = B.SEQ_DELIV )
WHEN MATCHED THEN
UPDATE SET B.QTY_BO = A.QTY_BO
WHERE EXISTS (
SELECT 1 FROM VIEW_IT_BO A
WHERE A.SEQ_D_LINE = B.SEQ_D_LINE
AND A.SEQ_DELIV = B.SEQ_DELIV
AND A.QTY_BO <> B.QTY_BO );

call elapsed rows
------- ---------- ----------
total 259.96 547860



UPDATE T_REQ_DT B --Alternate Query 2
SET B.QTY_BO =
(SELECT A.QTY_BO
FROM VIEW_IT_BO A
WHERE A.SEQ_D_LINE = B.SEQ_D_LINE
AND A.SEQ_DELIV = B.SEQ_DELIV)
WHERE EXISTS (
SELECT 1 FROM VIEW_IT_BO A
WHERE A.SEQ_D_LINE = B.SEQ_D_LINE
AND A.SEQ_DELIV = B.SEQ_DELIV
AND A.QTY_BO <> B.QTY_BO ) ;


call elapsed rows
------- ---------- ----------
total 495.32 602927

Could you please advice any alternative ways to acheive the best results on this?

Thanks in advance.

Regards
Shiva E
Tom Kyte
September 09, 2010 - 11:54 am UTC

use merge, never use the undocumented hint. period, end of discussion.


why do you have the where exists???
MERGE INTO T_REQ_DT B    --Alternate query 1
USING (SELECT QTY_BO, SEQ_DELIV, SEQ_D_LINE FROM VIEW_IT_BO) A
ON (A.SEQ_D_LINE = B.SEQ_D_LINE AND A.SEQ_DELIV = B.SEQ_DELIV )
WHEN MATCHED THEN
  UPDATE SET B.QTY_BO =  A.QTY_BO
WHERE EXISTS (
SELECT 1  FROM VIEW_IT_BO A
         WHERE A.SEQ_D_LINE = B.SEQ_D_LINE
           AND A.SEQ_DELIV = B.SEQ_DELIV
           AND A.QTY_BO <> B.QTY_BO );



you didn't have anything like it in the original ??????????

QUERY REWRITE

Sunny, September 13, 2010 - 4:28 am UTC

Hi Tom,

I am trying to create a materialized view on a select query.
The query contains some columns using SYSDATE and some user defined functions.Due to this I am unable to create the materialized view, problem being with the ENABLE QUERY REWRITE option in the statement.
Can you please tell the best possible way to create the materialized view using the benefit of Query rewrite option.
Also,please help me with the functionality of Query Rewrite and its necessity.

Thanks!!
Tom Kyte
September 13, 2010 - 2:29 pm UTC

if you have sysdate in the select list, please think about it.

You could never use that query for rewrite. Sysdate is a constantly moving target - it changes - a materialized view with sysdate in the select list would be stale the instant it was created.

Enable Query rewrite

Sunny, September 13, 2010 - 4:42 am UTC

Hi Tom,

Further to my above query please note that I am using Oracle 11g database.

Thanks!!

SQL Fine Tuning

Shiva Ellur, September 27, 2010 - 8:20 am UTC

Tom,

Thanks very much for your kind advice. I have used the merge statement and corrected the redundant predicate clause as shown below:

MERGE INTO T_REQ_DT B --Alternate query 1
USING (SELECT QTY_BO, SEQ_DELIV, SEQ_D_LINE FROM VIEW_IT_BO) A
ON (A.SEQ_D_LINE = B.SEQ_D_LINE AND A.SEQ_DELIV = B.SEQ_DELIV )
WHEN MATCHED THEN
UPDATE SET B.QTY_BO = A.QTY_BO
where A.QTY_BO <> B.QTY_BO
;

call elapsed rows
------- ---------- ----------
total 39.26 58048

It performs even as the original one i.e. with undocumented bypass hint.


Regards
Shiva Ellur

Performance in-view view

A reader, October 04, 2010 - 6:00 am UTC

Hi Tom,
I had a query with in-line views from the same large table with different predicates. The numbers of rows in the table are around 26M. One query returns around 1M and other returns around 700,000 rows. Second query joins with another small table (192 rows). Stats have been gathered on both tables.
We are on 10gR1 and dynamic sampling is 4. The result set has aggregate functions.
When I run queries separately, first query returns rows in around 4 Mins., and second returns rows in around 10 Mins. When I change to in-line view, the result set takes around 45 Mins.
When I put the hint parallel degree 2 for large table, in-line view query returns data in around 10 Mins.

Do you think that putting parallel hint in query is better or putting as part of create statement with degree 2?
Regards,

Tom Kyte
October 04, 2010 - 7:42 am UTC

... When I run queries separately, first query returns rows in around 4 Mins., and second returns rows in around 10 Mins. When I change to in-line view, the result set takes around 45 Mins. ....


I don't know why you compare those three different queries. Q1 returns rows in 4 mins ( but how long till the last row, that would be more relevant), Q2 returns rows in 10 mins (same comment about how long till last row) - and Q3 which does something with BOTH of Q1 and Q2 (joins them or something I would expect) returns in about 45 minutes (same comment about last rows) - but Q3 is not Q1 nor Q2 - you'd have to time what it takes to materialize Q1 and Q2 somewhere and then do the Q3 processing and so on. You are not comparing things that can be compared...


I would not want to run q1 and q2 and then do more stuff - i would just want to rn q3 which you are saying you can with parallel in 10 minutes - that seems the way to go.

Tuning

Reader, October 07, 2010 - 11:35 am UTC

Hi Tom,

You talk about three levels of tuning in one of your books.

(1) Tuning in isolation
(2) Tuning in multi-user mode.
(3) Database instance / Server tuning.

I need to test the execution speed of a query in single & multi user modes. Testing it in a single user mode is not a problem as I can populate test data of realistic volume in all the tables, run the query and time it. But how can I simulate testing execution speed in multi-user mode? Can this be done in PL/SQL or should it done using tools like load runner? Please advise.

Regards
Tom Kyte
October 11, 2010 - 10:40 am UTC

you can test multi user just by starting many sessions. I frequently use the job queues to do it.

Put the code you want to run in "multi-user mode" in a stored procedure (parameterize the stored procedure of course so that if "multiple users" were running it - they would each do their own stuff using their own inputs)

then schedule N of these - when you commit - they start running in the background.

Take a statspack/AWR snapshot when they start, take another when they finish - and you have a report of the activity when they were all going.

Or, just fire off N sqlplus scripts in the background and let them run concurrently.

Using RULE hint with 11g

Avnish, October 29, 2010 - 6:16 am UTC

Hi Tom,
I see that in your discussion you have discouraged the use of RULE hint. But I see this hint being used in a sizable number of Oracle application 11i queries (code is written by oracle).
Also I have seen it couple of times developers using this hint to speed up the query which is running slow using CBO.
See example below. This query was running slow after we upgraded our Oracle apps DB from 9i to 11.1.0.7. The developer simply used the RULE hint to ran it faster. In such a situation it is difficult to convince a developer that using RULE hint is not good and is going to be desupported.
All the tables being used below were last analyzed on 24-OCT-10. We generate statistics weekly.

SELECT /*+ RULE */
count(*)
FROM OKC_K_HEADERS_B OAHV,
OKC_K_VERS_NUMBERS OKVN,
OKC_K_ITEMS OKI,
OKC_K_ITEMS OKI1,
CSI_ITEM_INSTANCES CII,
MTL_SYSTEM_ITEMS MSIB,
MTL_SYSTEM_ITEMS MSIB1,
OKC_K_LINES_B OKLB,
OKC_K_LINES_B OKLB3,
HZ_PARTIES HP,
OKC_K_PARTY_ROLES_B OKPRB,
HR_OPERATING_UNITS HOU
WHERE OKPRB.DNZ_CHR_ID = OAHV.ID
AND HP.PARTY_ID = OKPRB.OBJECT1_ID1
AND OAHV.ID = OKVN.CHR_ID
AND OKI.DNZ_CHR_ID = OAHV.ID
AND OKLB.DNZ_CHR_ID = OAHV.ID
AND OKI.CLE_ID = OKLB.ID
AND OKI.JTOT_OBJECT1_CODE IN ('OKX_CUSTPROD', 'OKX_COVITEM')
AND CII.INSTANCE_ID = OKI.OBJECT1_ID1
AND CII.INVENTORY_ITEM_ID = MSIB.INVENTORY_ITEM_ID
and CII.serial_number = :SERIAL_NUMBER
AND MSIB1.inventory_item_id = :warr_inv_itm_id
and MSIB.inventory_item_id = :inv_id
and CII.LAST_VLD_ORGANIZATION_ID = MSIB.ORGANIZATION_ID
AND OKLB3.ID = OKLB.CLE_ID
AND OKI1.CLE_ID = OKLB3.ID
AND OKI1.DNZ_CHR_ID = OAHV.ID
AND OKI1.OBJECT1_ID1 = MSIB1.INVENTORY_ITEM_ID
AND OKI1.OBJECT1_ID2 = MSIB1.ORGANIZATION_ID
AND HOU.ORGANIZATION_ID = OAHV.AUTHORING_ORG_ID;

Rows COST Plan
---------- ---------- ---------------------------------------------------------------------
SELECT STATEMENT
SORT AGGREGATE
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS

Rows COST Plan
---------- ---------- ---------------------------------------------------------------------
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
NESTED LOOPS
TABLE ACCESS FULL OKC_K_PARTY_ROLES_B
INDEX UNIQUE SCAN HZ_PARTIES_U1
TABLE ACCESS BY INDEX ROWID OKC_K_HEADERS_B ----> table being accessed through index
INDEX UNIQUE SCAN OKC_K_HEADERS_B_U1 ----> Please note the usage of this index
INDEX UNIQUE SCAN HR_ORGANIZATION_UNITS_PK
INDEX UNIQUE SCAN HR_ALL_ORGANIZATION_UNTS_TL_PK

Rows COST Plan
---------- ---------- ---------------------------------------------------------------------
INDEX UNIQUE SCAN OKC_K_VERS_NUMBERS_U1
INDEX RANGE SCAN HR_ORGANIZATION_INFORMATIO_FK2
TABLE ACCESS BY INDEX ROWID HR_ORGANIZATION_INFORMATION
INDEX RANGE SCAN HR_ORGANIZATION_INFORMATIO_IX1
TABLE ACCESS BY INDEX ROWID CSI_ITEM_INSTANCES
INDEX RANGE SCAN CSI_ITEM_INSTANCES_N05
INDEX UNIQUE SCAN MTL_SYSTEM_ITEMS_B_U1
TABLE ACCESS BY INDEX ROWID OKC_K_ITEMS
INDEX RANGE SCAN OKC_K_ITEMS_N3
INDEX UNIQUE SCAN OKC_K_LINES_B_U1
INDEX UNIQUE SCAN MTL_SYSTEM_ITEMS_B_U1

Rows COST Plan
---------- ---------- ---------------------------------------------------------------------
TABLE ACCESS BY INDEX ROWID OKC_K_LINES_B
INDEX RANGE SCAN OKC_K_LINES_B_N2
TABLE ACCESS BY INDEX ROWID OKC_K_ITEMS
AND-EQUAL
INDEX RANGE SCAN OKC_K_ITEMS_N3
INDEX RANGE SCAN OKC_K_ITEMS_N1

39 rows selected.
=========================================

## Removed the RULE hint ##

SELECT
count(*)
FROM OKC_K_HEADERS_B OAHV,
OKC_K_VERS_NUMBERS OKVN,
OKC_K_ITEMS OKI,
OKC_K_ITEMS OKI1,
CSI_ITEM_INSTANCES CII,
MTL_SYSTEM_ITEMS MSIB,
MTL_SYSTEM_ITEMS MSIB1,
OKC_K_LINES_B OKLB,
OKC_K_LINES_B OKLB3,
HZ_PARTIES HP,
OKC_K_PARTY_ROLES_B OKPRB,
HR_OPERATING_UNITS HOU
WHERE OKPRB.DNZ_CHR_ID = OAHV.ID
AND HP.PARTY_ID = OKPRB.OBJECT1_ID1
AND OAHV.ID = OKVN.CHR_ID
AND OKI.DNZ_CHR_ID = OAHV.ID
AND OKLB.DNZ_CHR_ID = OAHV.ID
AND OKI.CLE_ID = OKLB.ID
AND OKI.JTOT_OBJECT1_CODE IN ('OKX_CUSTPROD', 'OKX_COVITEM')
AND CII.INSTANCE_ID = OKI.OBJECT1_ID1
AND CII.INVENTORY_ITEM_ID = MSIB.INVENTORY_ITEM_ID
and CII.serial_number = :SERIAL_NUMBER
AND MSIB1.inventory_item_id = :warr_inv_itm_id
and MSIB.inventory_item_id = :inv_id
and CII.LAST_VLD_ORGANIZATION_ID = MSIB.ORGANIZATION_ID
AND OKLB3.ID = OKLB.CLE_ID
AND OKI1.CLE_ID = OKLB3.ID
AND OKI1.DNZ_CHR_ID = OAHV.ID
AND OKI1.OBJECT1_ID1 = MSIB1.INVENTORY_ITEM_ID
AND OKI1.OBJECT1_ID2 = MSIB1.ORGANIZATION_ID
AND HOU.ORGANIZATION_ID = OAHV.AUTHORING_ORG_ID;


Rows COST Plan
--------- ---------- ----------------------------------------------------------------------
1 5359 SELECT STATEMENT
1 SORT AGGREGATE
1 5359 NESTED LOOPS
1 5358 NESTED LOOPS
1 5357 NESTED LOOPS
1 5356 NESTED LOOPS
1 5354 NESTED LOOPS
1 5351 NESTED LOOPS
1 5350 NESTED LOOPS
1 5348 NESTED LOOPS
1 5345 HASH JOIN

Rows COST Plan
--------- ---------- ----------------------------------------------------------------------
1 10 NESTED LOOPS
1 10 NESTED LOOPS
1 9 NESTED LOOPS
1 9 MERGE JOIN CARTESIAN
1 5 NESTED LOOPS
1 4 TABLE ACCESS BY INDEX ROWID CSI_ITEM_INSTANCES
1 3 INDEX RANGE SCAN CSI_ITEM_INSTANCES_N05
1 1 INDEX UNIQUE SCAN MTL_SYSTEM_ITEMS_B_U1
1 8 BUFFER SORT
1 4 TABLE ACCESS BY INDEX ROWID HR_ORGANIZATION_INFORMATION

Rows COST Plan
--------- ---------- ----------------------------------------------------------------------

18 1 INDEX RANGE SCAN HR_ORGANIZATION_INFORMATIO_IX1
1 0 INDEX UNIQUE SCAN HR_ORGANIZATION_UNITS_PK
1 1 INDEX RANGE SCAN HR_ORGANIZATION_INFORMATIO_FK2
1 0 INDEX UNIQUE SCAN HR_ALL_ORGANIZATION_UNTS_TL_PK
478330 5330 TABLE ACCESS FULL OKC_K_HEADERS_B ---> FTS is there,the unique index not getting used
1 3 TABLE ACCESS BY INDEX ROWID OKC_K_ITEMS
15 2 INDEX RANGE SCAN OKC_K_ITEMS_N3
1 2 TABLE ACCESS BY INDEX ROWID OKC_K_ITEMS
15 2 INDEX RANGE SCAN OKC_K_ITEMS_N3
1 1 INDEX UNIQUE SCAN OKC_K_VERS_NUMBERS_U1

Rows COST Plan
--------- ---------- ----------------------------------------------------------------------
2 3 TABLE ACCESS BY INDEX ROWID OKC_K_PARTY_ROLES_B
2 2 INDEX RANGE SCAN OKC_K_PARTY_ROLES_B_N1
1 2 TABLE ACCESS BY INDEX ROWID OKC_K_LINES_B
1 1 INDEX UNIQUE SCAN OKC_K_LINES_B_U1
1 1 INDEX UNIQUE SCAN OKC_K_LINES_B_U1
1 1 INDEX UNIQUE SCAN MTL_SYSTEM_ITEMS_B_U1
1 1 INDEX UNIQUE SCAN HZ_PARTIES_U1

Tom Kyte
November 01, 2010 - 6:46 am UTC

Also I have seen it couple of times developers using this hint to speed up the
query which is running slow using CBO


which could probably run even faster using a FIRST_ROWS(25) hint. RBO is "index happy", indicates to me that they wanted to optimize for initial response time.

lots and lots of legacy queries in apps - and remember, just because someone works for Oracle - does not mean they know how to spell database either...


and is going to be desupported.


you used future tense, should be past tense. it HAS been desupported.

select .. for update.. query

Manoj Kaparwan, November 02, 2010 - 12:53 am UTC

Hi Tom,

Thanks for your time.

 
From Statspack...( 20 mins duration, 16 cpus)

   
....
                                                      CPU      Elapsd
  Buffer Gets    Executions  Gets per Exec  %Total Time (s)  Time (s) Hash Value
--------------- ------------ -------------- ------ -------- --------- ----------
        713,798           18       39,655.4    1.7    74.20    104.83 2094014514
Module: java@host-A (TNS V1-V3)
SELECT objid FROM t1 WHERE  group2function =  :P3216 AND  child2group_inst =  :P3217 AND  
iter_seqno =  :P3218 FOR UPDATE

        713,798           18       39,655.4    1.7    70.80     97.93 2425113719
Module: java@host-A (TNS V1-V3)
SELECT objid FROM t1 WHERE  group2function =  :P3816 AND  child2group_inst =  :P3817 AND 
iter_seqno =  :P3818 FOR  UPDATE
 ......
 
 
 
 
 
Autotrace is: 
 
 SQL> SELECT objid FROM t1 WHERE  group2function =  4 AND  child2group_inst =  123 AND
  iter_seqno =32   
    ;

no rows selected
Elapsed: 00:00:00.03

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=5 Card=1 Bytes=19)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 't1' (Cost=5 Card=1 Bytes=19)
   2    1     INDEX (RANGE SCAN) OF 'C2GI9757' (NON-UNIQUE) (Cost=4 Card=1)

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          3  physical reads
          0  redo size
        300  bytes sent via SQL*Net to client
        460  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          0  rows processed

    
    ---------------
    
Other details:

C2GI9757 is Index on t1 ( CHILD2GROUP_INST )
count(*) t1 - 70000000
There is Primary key on t1(objid)


Quetions 

1) Where does 39,655.4  blocks reads per executions coming from ?
   as we can see in autotrace very less consistent & physical reads
2) do  'for update' clause is  adding something to (1) above?
3) a composite index on t1(group2function,child2group_inst,iter_seqno,objid) will do good ?
   thus avoiding table scans.

   


Tom Kyte
November 02, 2010 - 6:30 am UTC

1) i would presume in real life you don't get zero rows back, why not use values that the application used?

2) yes, for update will find and lock ALL records before the first record is returned to the client. So, for example, if that query "finds" 100,000 records but the application was written to fetch just the first one - the for update would make us find all 100,000 before returning the first fetched one (you would use and rownum=1 to "fix" that).

in general for update would double the number of buffer gets - we have to do all of the buffer gets to lock the rows first - and then we in general re-fetch those rows again during the select phase.

3) who said it was table scanning? It isn't if there are 70,000,000 records in there - the buffer gets are too low. But an index that had all of the where clause attributes would tend to lead to the most efficient table accesses.

..contd select .. for update.. query

Manoj Kaparwan, November 02, 2010 - 8:47 am UTC

Tom,
Thank you so much. 

Further,

1)
Please find below the trace with real life data.( 1 row processed)

SQL> set autotrace traceonly;
SQL> select objid from t1 where group2function=3098 and child2group_inst=16726734 and 
iter_seqno=0;

Elapsed: 00:00:01.02

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=FIRST_ROWS (Cost=5 Card=1 Bytes=19)

   1    0   TABLE ACCESS (BY INDEX ROWID) OF 't1' (Cost=5 Card=1 Bytes=19)

   2    1     INDEX (RANGE SCAN) OF 'C2GI9757' (NON-UNIQUE) (Cost=4 Card=1)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          7  consistent gets
          5  physical reads
          0  redo size
        209  bytes sent via SQL*Net to client
        276  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed


SQL> explain plan for
  2  select objid from t1 where group2function=3098 and child2group_inst=16726734 and iter_seqno=0;

Explained.

Elapsed: 00:00:00.02
SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------------

---------------------------------------------------------------------------------
| Id  | Operation                   |  Name             | Rows  | Bytes | Cost  |
---------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                   |     1 |    19 |     5 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| t1      |     1 |    19 |     5 |
|*  2 |   INDEX RANGE SCAN          | C2GI9757          |     1 |       |     4 |
---------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("t1"."GROUP2FUNCTION"=3098 AND
              "t1"."ITER_SEQNO"=0)
   2 - access("t1"."CHILD2GROUP_INST"=16726734)

Note: cpu costing is off


also Tom, I can safely use select.. for UPDATE  to know the explain plan. 
we cannot find the actual trace until we use FOR UPDATE ?


2)
Locks are attributes of data itself in Oracle ( a big plus) . 
So would it not be more efficient if the same 
cannot be done in one go?
I mean locking the rows and fetching  and avoiding the re-fetch.
    


3)
I agree. very low  very low buffer gets and doesnt looks like even there is a table scan with 70,000,000 rows.

we will have index on all where clause attributes  

I was just thinking to include the objid column ( which is a select attribute ) also in the index.
hence have index on
 t1(group2function,child2group_inst,iter_seqno,objid)  
                                                ^^^ select column
            others keys are where clause attributes
              
            

Tom Kyte
November 02, 2010 - 11:22 am UTC

1) I didn't see any traces? or tkprofs, just explain plans

are you using the values the query used in 'real life' or just some value that happens to return a single row for you.

the values matter. can you get an actual TKPROF from the real system - running these queries - so we can see the row source operation.

consider, both of these return ONE ROW - one does a ton more work than the other given the distribution of data
ops$tkyte%ORA11GR2> /*
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> drop table t;
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create table t
ops$tkyte%ORA11GR2> as
ops$tkyte%ORA11GR2> select mod(rownum,3) child2group, rownum group2function, rownum iter_seqno, rpad('*',800,'*') data
ops$tkyte%ORA11GR2>   from all_objects;
ops$tkyte%ORA11GR2> insert into t
ops$tkyte%ORA11GR2> select rownum+1000 child2group, rownum group2function, rownum iter_seqno, rpad('*',800,'*') data
ops$tkyte%ORA11GR2>   from all_objects;
ops$tkyte%ORA11GR2> commit;
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create index t_idx on t(child2group);
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> exec dbms_stats.gather_table_stats( user, 'T' );
ops$tkyte%ORA11GR2> */
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> column g2f new_val g2f
ops$tkyte%ORA11GR2> select max(group2function) g2f from t where child2group = 1;

       G2F
----------
     71788

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set autotrace traceonly
ops$tkyte%ORA11GR2> select * from t where child2group = 1 and group2function = &g2f and iter_seqno = &g2f;
old   1: select * from t where child2group = 1 and group2function = &g2f and iter_seqno = &g2f
new   1: select * from t where child2group = 1 and group2function =      71788 and iter_seqno =      71788


Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |     1 |   815 |     2   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| T     |     1 |   815 |     2   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |     2 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("GROUP2FUNCTION"=71788 AND "ITER_SEQNO"=71788)
   2 - access("CHILD2GROUP"=1)


Statistics
----------------------------------------------------------
          1  recursive calls
          0  db block gets
      18005  consistent gets
      18001  physical reads
          0  redo size
       1431  bytes sent via SQL*Net to client
        419  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA11GR2> select * from t where child2group = 1001 and group2function=1 and iter_seqno = 1;


Execution Plan
----------------------------------------------------------
Plan hash value: 470836197

-------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |     1 |   815 |     2   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| T     |     1 |   815 |     2   (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |     2 |       |     1   (0)| 00:00:01 |
-------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("GROUP2FUNCTION"=1 AND "ITER_SEQNO"=1)
   2 - access("CHILD2GROUP"=1001)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          2  physical reads
          0  redo size
       1428  bytes sent via SQL*Net to client
        419  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

ops$tkyte%ORA11GR2> set autotrace off


2) no, it cannot be done in a single go. We have to lock a consistent set of rows BEFORE we can return to you that consistent set of rows.

Normally, with just a select - you get the data as of the point in time the query began. We can return the data to you immediately without getting the last row. That is because we'll roll back any changed data to it's before image.

Now, with a select for update (say "select * from t where x = 5 FOR UPDATE", we have to return to you a consistent set of rows that all have the value X as of the query begin time. Suppose we are reading that table T and we hit a row whose X value was X when your query began. YOU NEED THAT ROW - it is part of your consistent set of x=5 values. But suppose that row is currently locked (so we cannot lock it). your select for update blocks - and when it unblocks it discovers the row is not x=6 (someone updated it). We cannot lock that row and give it to you (it is after all now x=6 - we lock in CURRENT mode, it doesn't make sense to lock the 'old version'). But conversely we cannot NOT give it to you (it formed your consistent set of x=5 values after all). We will RESTART your query - give up all of the locks we gathered so far and start it over - trying to get a consistent set of x=5 values

read
http://asktom.oracle.com/Misc/something-different-part-i-of-iii.html
http://asktom.oracle.com/Misc/part-ii-seeing-restart.html
http://asktom.oracle.com/Misc/part-iii-why-is-restart-important-to.html

for a better understanding of this restart process.


If we were to return to you data BEFORE LOCKING IT ALL - we would not be able to restart (since we cannot "unfetch" a row from you...)

3) we still need to visit the table. We won't be able to skip it. We have to go to the row to lock it. It would make sense to have the three columns in the predicate in the index to avoid hitting the table unnecessarily though.


query very slow after migration from 9.2.0 to 11.2

Jouini, November 03, 2010 - 2:24 am UTC

3 rows selected.

Execution Plan
----------------------------------------------------------
0 SELECT STATEMENT Optimizer Mode=CHOOSE (Cost=5089 Card=1 Bytes=162)
1 0 SORT UNIQUE (Cost=5000 Card=1 Bytes=162)
2 1 HASH JOIN (Cost=4911 Card=1 Bytes=162)
3 2 VIEW VVEVER.EV_BETEILIGTE_BROWSER (Cost=16 Card=15 Bytes=1 K)
4 3 UNION-ALL
5 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_VERSICHERUNGSNEHMER (Cost=1 Card=1 Bytes=56)
6 5 INDEX RANGE SCAN VVEVER.VN_VER_FK_FRGN (Cost=1 Card=1)
7 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_VERSICHERUNGSNEHMER (Cost=1 Card=1 Bytes=56)
8 7 INDEX RANGE SCAN VVEVER.VN_VER_FK_FRGN (Cost=1 Card=1)
9 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_VERSICHERTE (Cost=1 Card=3 Bytes=222)
10 9 INDEX RANGE SCAN VVEVER.VT_TPOS_FK_FRGN (Cost=1 Card=3)
11 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_BEGUENSTIGTE (Cost=1 Card=1 Bytes=80)
12 11 INDEX RANGE SCAN VVEVER.BEGU_VER_FK_FRGN (Cost=1 Card=1)
13 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_BEVOLLMAECHTIGTE (Cost=1 Card=1 Bytes=57)
14 13 INDEX RANGE SCAN VVEVER.BEVO_VER_FK_FRGN (Cost=1 Card=1)
15 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_LETZTWILLIGVERFUEGTE (Cost=1 Card=1 Bytes=63)
16 15 INDEX RANGE SCAN VVEVER.LWVF_VER_FK_FRGN (Cost=1 Card=1)
17 4 NESTED LOOPS
18 17 NESTED LOOPS (Cost=2 Card=1 Bytes=74)
19 18 TABLE ACCESS BY INDEX ROWID VVEVER.EV_PFANDVERTRAEGE (Cost=1 Card=1 Bytes=14)
20 19 INDEX RANGE SCAN VVEVER.PFAV_VER_FK_FRGN (Cost=1 Card=1)
21 18 INDEX RANGE SCAN VVEVER.PFAG_PFAV_FK_FRGN (Cost=1 Card=1)
22 17 TABLE ACCESS BY INDEX ROWID VVEVER.EV_PFANDGLAEUBIGER (Cost=1 Card=1 Bytes=60)
23 4 NESTED LOOPS
24 23 NESTED LOOPS (Cost=2 Card=2 Bytes=142)
25 24 TABLE ACCESS BY INDEX ROWID VVEVER.EV_PFANDVERTRAEGE (Cost=1 Card=1 Bytes=14)
26 25 INDEX RANGE SCAN VVEVER.PFAV_VER_FK_FRGN (Cost=1 Card=1)
27 24 INDEX RANGE SCAN VVEVER.PFAS_PFAV_FK_FRGN (Cost=1 Card=2)
28 23 TABLE ACCESS BY INDEX ROWID VVEVER.EV_PFANDSCHULDNER (Cost=1 Card=2 Bytes=114)
29 4 FILTER
30 29 TABLE ACCESS BY INDEX ROWID VVEVER.EV_VERSICHERER (Cost=1 Card=1 Bytes=52)
31 30 INDEX RANGE SCAN VVEVER.VR_VER_FK_FRGN (Cost=1 Card=1)
32 4 TABLE ACCESS BY INDEX ROWID VVEVER.EV_ZUSTELLADRESSEN_CH (Cost=1 Card=1 Bytes=56)
33 32 INDEX RANGE SCAN VVEVER.ZUCH_VER_FK_FRGN (Cost=1 Card=1)
34 4 NESTED LOOPS
35 34 NESTED LOOPS (Cost=2 Card=1 Bytes=82)
36 35 TABLE ACCESS BY INDEX ROWID VVEVER.EV_RUECKVERSICHERUNGEN (Cost=1 Card=1 Bytes=56)
37 36 INDEX RANGE SCAN VVEVER.RUE_VER_FK_FRGN (Cost=1 Card=1)
38 35 INDEX RANGE SCAN VVEVER.RV_RVV_FK_FRGN (Cost=1 Card=1)
39 34 TABLE ACCESS BY INDEX ROWID VVEVER.EV_RUECKVERSICHERER (Cost=1 Card=1 Bytes=26)
40 4 NESTED LOOPS
41 40 NESTED LOOPS (Cost=3 Card=1 Bytes=128)
42 41 NESTED LOOPS (Cost=2 Card=1 Bytes=115)
43 42 TABLE ACCESS BY INDEX ROWID VVEVER.EV_LEISTUNGEN (Cost=1 Card=1 Bytes=32)
44 43 INDEX RANGE SCAN VVEVER.LE_LEISTET_VER_FK_FRGN (Cost=1 Card=6)
45 42 TABLE ACCESS BY INDEX ROWID VVEVER.EV_LEISTUNGSZST (Cost=1 Card=1 Bytes=83)
46 45 INDEX RANGE SCAN VVEVER.LEZ_LE_FK_FRGN (Cost=1 Card=1)
47 41 INDEX UNIQUE SCAN VVEVER.ZAHL_PK (Cost=1 Card=1)
48 40 TABLE ACCESS BY INDEX ROWID VVEVER.ZAHLUNGSVERKEHR (Cost=1 Card=1 Bytes=13)
49 2 VIEW GRPART.PARTNERANGABEN (Cost=4889 Card=1 M Bytes=69 M)
50 49 MERGE JOIN (Cost=4889 Card=1 M Bytes=116 M)
51 50 TABLE ACCESS BY INDEX ROWID GRPART.PERSONS (Cost=795 Card=1 M Bytes=104 M)
52 51 INDEX FULL SCAN GRPART.PERS_PK (Cost=28 Card=1 M)
53 50 SORT JOIN (Cost=4094 Card=1 M Bytes=12 M)
54 53 TABLE ACCESS FULL GRPART.PARTNERKEYS (Cost=738 Card=1 M Bytes=12 M)

Statistics
----------------------------------------------------------
6 user calls
0 physical read total multi block requests
7487488 physical read total bytes
7487488 cell physical IO interconnect bytes
0 commit cleanout failures: block lost
0 IMU commits
0 IMU Flushes
0 IMU contention
0 IMU bind flushes
0 IMU mbu flush
3 rows processed

tuning sql statements

SQL training, January 11, 2011 - 7:47 pm UTC

Tuning SQL statements cracks my mind. It'so hard to understand. The you need a logic booster.
Tom Kyte
January 12, 2011 - 10:16 am UTC

replace "tuning sql statements" with "anything" and you still have a valid statement.

"writing good code"
"providing a specification that can be used to generate code"
"designing an algorithm"
"etc...."

they are all true - until you have education and experience


what I'm trying to say is... everyone can do SQL, if they apply themselves - just like everyone can write Java,....

Bind Variable Peeking causes issue in Siebel database

Vengata Guruswamy, February 20, 2011 - 8:13 pm UTC

Dear Tom,

Recently after the question I posed for the plan changes earlier ,we started to observe a peculiar behavior in the Siebel database. The SQL started to execute always slower with a bad plan whenever executed from application and started to take days to complete. Whenever the same sql is ran from the sqlplus or any other third party utility it is within seconds. After much followups with Support we found the bind variable peeking was not happening from the application. This was confirmed with two test cases.We flushed the shared pool and then made the _optim_peek_user_binds to be true on the application session (using set_bool_param_in_session) which produced the results within seconds.Also from our sqlplus session we made the _optim_peek_user_binds to be false(after flushing shared pool) and we are able to reproduce the slowness. Then as a work around we had to use a outline to fix the plan stability. The support cannot file a bug as we were still in 10.2.0.2.0 . This is one of our lessons learned and might help any reader.

sql query tuning

supriya, March 01, 2011 - 12:14 am UTC

Respected Tom,

I have a select query which filter out the data with the help of some "and" and "in" ,"exists"
condition from another remote database tables.basically you are using the following query in side a
package for report generation.while I ran that corresponding report it took very long time (inside
the report this is the only one select statement used) ,i then ran this report from sql prompt and
even it is taking more than 4 days and still running.
I study the sql query and found some in conditions are twice
written ( i thought to miniminse the query) for better performance .

please guide me how to modify the query so it will take little time.

specially the query uses 4 tables(service_agrrement,service,language_keys,subscriber).


THE CODE:


select distinct substr(subscriber_no,-8) msisdn, ban
from user.service_agreement
where (ban, subscriber_no) in ( select ban, subscriber_no
from user.service_agreement
where soc like 'XPRESS3%'
and service_type = 'P'
and (expiration_date >= sysdate or expiration_date is null or
expiration_date = to_date('31-12-4700','DD-MM-YYYY'))
)
and (ban, subscriber_no) not in ( select ban, subscriber_no
from user.service_agreement
where --soc like 'GPRS%' and soc <> 'GPRSDAWAP'
soc in ( select ltrim(b.language_key,'s') soc
from services a, language_keys b
where a.language_key = b.language_key
and a.language = b.language
and a.soc_type <> 'P'
and service_carrier_group_code like '%GPRS%'
)
and soc <> 'GPRSDAWAP'
and service_type <> 'P'
and (expiration_date >= sysdate or expiration_date is
null or expiration_date = to_date('31-12-4700','DD-MM-YYYY'))
and (ban, subscriber_no) in ( select ban,
subscriber_no
from
user.service_agreement
where soc like
'XPRESS3%'
and service_type = 'P'
and (expiration_date >=
sysdate or expiration_date is null or expiration_date = to_date('31-12-4700','DD-MM-YYYY'))
)
)
and exists ( select 1
from user.subscriber
where customer_id = ban
and subscriber_no = subscriber_no
and sub_status in ('A','S')
)
and service_type <> 'P'
and (expiration_date >= sysdate or expiration_date is null or expiration_date =
to_date('31-12-4700','DD-MM-YYYY'));



long live Tom,
regards,
supriya

Tom Kyte
March 01, 2011 - 9:12 am UTC

sorry, but without intimate knowledge of your schema (all constraints, everything), of data volumes (very specific knowledge), tuning a huge query isn't something I'm going to do. It is not that I'm asking you for that stuff, I'm just saying it would take me a long while just to reverse engineer your query.

I can say, stuff like this:

(expiration_date >= sysdate or
expiration_date is null or
expiration_date = to_date('31-12-4700','DD-MM-YYYY'))

is pretty scary. If I'm not mistaken, that could probably just be

expiration_date >= sysdate

because it looks like someone is using 31-dec-4700 instead of null and that date is certainly greater than "today" for the foreseeable future.

just saying...


oracle

A reader, March 02, 2011 - 3:16 am UTC

Hi Tom

I am trying to fine tune this query .This takes almost 50 seconds need to get that down.

Select distinct PA.PersonAddress_IDX, AT.Name AddressType,
A.Line1 Address1, A.Line2 Address2, A.City, A.State,
A.County, A.Country, A.PostalCode, A.AllowPostalSoftYN,
PA.ChangedBy,
PA.ChangedDT, PA.DeletedYN ,PA.Person_Key, PA.Address_Key,
PA.AddressType_Key
FROM PersonAddress_h PA,Address_h A,AddressType_h AT,
(select max(CHANGEDDT)
maxchdt,Person_key,AddressType_Key,Address_Key
from PersonAddress_h
group by Person_key,AddressType_Key,Address_Key) X
where PA.AddressType_Key IN (1,2,3) AND AT.AddressType_IDX =
PA.AddressType_Key
And A.Address_IDX = PA.Address_Key and PA.DeletedYN = 0
and PA.Person_KEY in (SELECT PERSON_KEY FROM INSURED_h I where
I.insured_idx=592374 )
and PA.CHANGEDDT=X.maxchdt
and PA.AddressType_Key=X.AddressType_Key
and PA.Address_Key=X.Address_Key
and AT.CHANGEDDT=(select max(CHANGEDDT) from AddressType_h
where AddressType_IDX = PA.AddressType_Key)
and A.CHANGEDDT= (Select max(CHANGEDDT) from Address_h
where Address_IDX = PA.Address_Key and
(CHANGEDDT-to_date('10/22/2003
18:02:30','mm/dd/yyyy hh24:mi:ss'))<=0.001 )

The exaplain plan now is

Rows Row Source Operation
------- ---------------------------------------------------
3 SORT UNIQUE
8 FILTER
20 SORT GROUP BY
4256 TABLE ACCESS BY INDEX ROWID ADDRESS_H
8513 NESTED LOOPS
4256 NESTED LOOPS
1120 HASH JOIN
1120 HASH JOIN
560 HASH JOIN
560 TABLE ACCESS BY INDEX ROWID PERSONADDRESS_H
617 NESTED LOOPS
56 TABLE ACCESS BY INDEX ROWID INSURED_H
56 INDEX RANGE SCAN INDX_INSURED_H_IDX_EDATE_CDATE
(object id 35548)
560 INDEX RANGE SCAN INDX_PRSNADDR_PRSN_ADDR_H (object
id 56328)
3 VIEW
3 SORT GROUP BY
6 INDEX FAST FULL SCAN CI_ADDRESSTYPE_H (object id
34443)
6 TABLE ACCESS FULL ADDRESSTYPE_H
459380 VIEW
459380 SORT GROUP BY
462919 TABLE ACCESS FULL ADDRESS_H
4256 INDEX RANGE SCAN INDX_PRSNADDR_ALL (object id 56331)
4256 INDEX RANGE SCAN CI_ADDRESS_H (object id 34445)

what baffles me is why the full table scans on ADDRESSTYPE_H and
ADDRESS_H

The tables ADDRESSTYPE_H and ADDRESS_H contain 464080 and 8 records
respectively

Is ther a better way to rewrite this query.A hint or a pointer would be enough to set of the
direction.Also i tried the manuals to understand the plan..the manuals are way to simplistic..was
just wunderin if you can take some time out to explain what the query id tryin to do in tom speak
:-)

performance tuning

A reader, March 02, 2011 - 3:38 am UTC

DearTom,
please discard my previous mail.
I am new to this performance tuning.

Could you please provide some link for performance tuning and also please give some softwares name by which we can tune the query.
and give some idea how to do the tune.

regards,
hyuki
Tom Kyte
March 02, 2011 - 7:42 am UTC

http://docs.oracle.com/docs/cd/E11882_01/server.112/e16638/toc.htm


for automatic tuning - suggesting indexing strategies, profiling sql, suggesting rewrites, etc - Enterprise Manager has a tuning pack


http://docs.oracle.com/docs/cd/E11882_01/license.112/e10594/options.htm#CIHFIHFG

long time query

Supriya Mishra, March 03, 2011 - 11:20 am UTC

Hi Tom,

I made a not of that date line and i just removed the last part and now it looks like "(expiration_date >= sysdate or expiration_date is null)" .

I just convert the "not in" to "not exists" and also used the "with" clause and executed and it is still running.

I am basically running it from toad and before running the query i checked with the toad bult in explain plan (there are some thing cost ,byte and cardinality ) but i did not understand from that.

the service_agreement table is having 34 lakhs record. and the other tables are having few records (arround 3000 to 4000 records).And one more thing the (ban and subscriber_no columns index is created , coz at explain plan it is showing index scan and i also checked manually that index is created)

Could you please tell me "with claude " will tune the query for better performance(I mean I created the repeated query as with clause table and replace the inner query with the "with clause table".

I am hope less Sir.
regards supriya.


Tom Kyte
March 03, 2011 - 1:06 pm UTC

.. I made a not of that date line and i just removed the last part and now it
looks like "(expiration_date >= sysdate or expiration_date is null)" . ..


are you sure you have nulls, when I see a funky date like that, it indicates to me that developers where afraid of nulls and use a fake date instead.

... Could you please tell me "with claude " will tune the query for better
performance(I mean I created the repeated query as with clause table and
replace the inner query with the "with clause table".
...

you should know what my answer will be if you've read any of my stuff before:

it depends
maybe yes, maybe no
it depends.


do you refer to the same subquery more than once in the query? If so, maybe yes, if not probably not. It would just make the query more readable perhaps.

long time query

Supriya Mishra, March 03, 2011 - 9:27 pm UTC

HI Tom,
Actually what happens if the date is null then also we consider that as sysdate(i will see if the date field is not null) then surely i will make to that singe >= condition and .yes that subquery is used 3 times in the whole query so i think "with clause" will definitely help. Thanks anyway.

And I will be sending the xplain plan out put of each query and please guide me which will take less time.

I like to be a giant in plsql and in performance tuning,i determined myself to give all my effort to mastery in performance tuning,but i need your blessing Tom sir.

God bless you.
Regards

long running query

supriya, March 08, 2011 - 4:18 am UTC

Hi Tom,

In reference to my previous post.
actually table is having 34230626 records.
I ran the query and it took 10 mins to completed and after 30 mins I ran the same query and it is running,running and running from last 10 hours and still running.
I checked simultenously and the records in that table is same 34230626.

why the same query is taking like 10 mins sometimes and 1 days to finished another time.

Is it due to the heavy load in database,or some other reason. Though it is a "select" query I dont think any lock is made .

Please guide me.

Regards,
Supriya
Tom Kyte
March 08, 2011 - 12:48 pm UTC

v$session_event / v$session_wait would be interesting views to query - if you have access to the Active Session History data (ASH) - part of tuning pack - it would be very very interesting to query.

to see what you are waiting on.


Is it due to the heavy load in database

very likely yes, it could be contention for a resource (IO for example), or it cold be that you got a very small workarea (memory) because the number of active sessions was high when you started your query, it could be that you ran out of Temp and the DBA enabled 'resumable operations' - etc.

But the V$ information would help you discover what you are waiting on.

Bitmap index

Prince, March 15, 2011 - 1:32 am UTC

which one is more efficient ??
Individual bitmap indexes on each column or a single composite bitmap index on those columns ??
Tom Kyte
March 15, 2011 - 8:17 am UTC

How many people can answer this in the way I would answer it for me by now? A lot of readers hopefully.

The answer is of course:

IT DEPENDS.


If you are 100% ad-hoc, you have no clue, no idea what columns, what sort of predicates the user will be using - then a bunch of single column bitmaps would probably be "best". That way - no matter what set of columns they choose - we can take the bitmaps on each and AND/OR them together to get the bitmap that represents their result set.


If you KNOW that when the uses query X, they ALWAYS query Y. Or that A,B,C are *always* involved. Or (etc - column groups are well known), then it would save us the work of putting the bitmaps together if you created a concatenated index on those columns.

So, as always, it depends...

Need help in tuning query

Ramu, March 16, 2011 - 4:02 pm UTC

I need help in tuning below query, I tried my best but I could not, explain plan shows full table scans on multiple tables, but for all these tables/columns used in this query has indexes but still query is not using indexes. Request you to help me tuning this.

SELECT ct.trx_number trx_number, ct.trx_date trx_date,
ct.invoice_currency_code invoice_currency_code,
UPPER (al_class.meaning) invoice_type,
ct.purchase_order po_number, ct.waybill_number waybill_number,
SUM (DECODE (ps.amount_due_remaining,
0, NULL,
TRUNC (SYSDATE) - ps.due_date
)
) days_past_due,
MIN (ps.due_date) due_date,
ps.amount_due_original amount_due_original,
ps.amount_due_remaining amount_due_remaining,
ps.amount_line_items_original amount_line_items_original,
ps.tax_original tax_original,
ps.freight_original freight_original,
ps.amount_adjusted amount_adjusted,
ps.amount_applied amount_applied,
ps.amount_credited amount_credited,
ps.discount_taken_earned discount_taken_earned,
ct.ship_via ship_via, acct.party_id party_id,
ct.customer_trx_id customer_trx_id,
acct.cust_account_id cust_account_id, ct.created_by created_by,
ol.header_id header_id
FROM ar_payment_schedules_all ps,
ra_customer_trx_all ct,
ar_lookups al_class,
hz_cust_accounts acct,
ra_customer_trx_lines_all ctl,
oe_order_lines_all ol,
oe_order_headers_all oh
WHERE ps.customer_trx_id = ct.customer_trx_id
AND ps.gl_date_closed = ps.gl_date_closed
AND ps.CLASS = al_class.lookup_code
AND al_class.lookup_type = 'INV/CM'
AND acct.cust_account_id = ct.bill_to_customer_id
AND ct.customer_trx_id = ctl.customer_trx_id
AND ( ctl.interface_line_attribute1 = TO_CHAR(oh.order_number) OR ctl.interface_line_attribute1 IS NULL )
AND oh.header_id = ol.header_id
AND ctl.interface_line_attribute6 = TO_CHAR(ol.line_id)
AND ct.batch_source_id != 8
GROUP BY ct.customer_trx_id,
ct.trx_number,
ct.trx_date,
ct.invoice_currency_code,
al_class.meaning,
ct.purchase_order,
ct.waybill_number,
ct.ship_via,
acct.party_id,
ps.amount_due_remaining,
ps.due_date,
ps.amount_due_original,
ps.amount_due_remaining,
ps.amount_line_items_original,
ps.tax_original,
ps.freight_original,
ps.amount_adjusted,
ps.amount_applied,
ps.amount_credited,
ps.discount_taken_earned,
acct.cust_account_id,
ct.created_by,
ol.header_id;

==========================================================
SELECT STATEMENT ALL_ROWSCost: 523,066 Bytes: 107,315,812 Cardinality: 468,628
15 HASH GROUP BY Cost: 523,066 Bytes: 107,315,812 Cardinality: 468,628
14 HASH JOIN Cost: 499,846 Bytes: 107,315,812 Cardinality: 468,628
1 TABLE ACCESS FULL TABLE AR.HZ_CUST_ACCOUNTS Cost: 210 Bytes: 236,150 Cardinality: 23,615
13 HASH JOIN Cost: 499,633 Bytes: 102,629,532 Cardinality: 468,628
3 TABLE ACCESS BY INDEX ROWID TABLE APPLSYS.FND_LOOKUP_VALUES Cost: 4 Bytes: 57 Cardinality: 1
2 INDEX RANGE SCAN INDEX (UNIQUE) APPLSYS.FND_LOOKUP_VALUES_U1 Cost: 3 Cardinality: 1
12 HASH JOIN Cost: 499,620 Bytes: 253,719,054 Cardinality: 1,566,167
4 TABLE ACCESS FULL TABLE AR.AR_PAYMENT_SCHEDULES_ALL Cost: 13,977 Bytes: 62,318,360 Cardinality: 1,198,430
11 HASH JOIN Cost: 472,947 Bytes: 172,396,950 Cardinality: 1,567,245
9 HASH JOIN Cost: 438,453 Bytes: 68,958,780 Cardinality: 1,567,245
7 HASH JOIN Cost: 326,735 Bytes: 76,108,325 Cardinality: 3,044,333
5 TABLE ACCESS FULL TABLE ONT.OE_ORDER_HEADERS_ALL Cost: 11,484 Bytes: 9,133,020 Cardinality: 702,540
6 TABLE ACCESS FULL TABLE ONT.OE_ORDER_LINES_ALL Cost: 310,925 Bytes: 36,531,996 Cardinality: 3,044,333
8 TABLE ACCESS FULL TABLE AR.RA_CUSTOMER_TRX_LINES_ALL Cost: 95,919 Bytes: 134,389,470 Cardinality: 7,073,130
10 TABLE ACCESS FULL TABLE AR.RA_CUSTOMER_TRX_ALL Cost: 25,892 Bytes: 79,150,830 Cardinality: 1,199,255

Tom Kyte
March 16, 2011 - 4:16 pm UTC

I'd be very upset if it used many indexes. Why do you think indexes to retrieve hundreds of thousands of rows would be good?

look at what indexes can do to you:

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:6749454952894#6760861174154

when inappropriately used.


see also
http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:3132601400346750293

Mostly NULL column values

Manoj Kaparwan, March 23, 2011 - 10:27 am UTC

Tom

Thanks for your time.

 
SQL> explain plan for
  2  SELECT t3.title, t1.entry_time, t1.act_code, t2.login_name, t4.description,
  3         t4.internal, t1.addt4_info
  4    FROM t1  , t2  , t3  ,
  5         t4 
  6   WHERE t1.act_entry2user = t2.objid
  7     AND t1.entry_name2gbst_elm = t3.objid
  8     AND t1.act_entry2notes_log = t4.objid(+)
  9     AND t1.x_act_entry2x_problem = 268435457;

Explained.

SQL> select * from table(dbms_xplan.display);

PLAN_TABLE_Ot2TPt2T
---------------------------------------------------------------------------------------------------------------------------

---------------------------------------------------------------------------------
| Id  | Operation            |  Name            | Rows  | Bytes |TempSpc| Cost  |
---------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |                  |   995K|   206M|       | 11924 |
|*  1 |  HASH JOIN           |                  |   995K|   206M|       | 11924 |
|   2 |   TABLE ACCESS FULL  | t2         |   356 |  6408 |       |     3 |
|*  3 |   HASH JOIN          |                  |  1024K|   195M|       | 11878 |
|   4 |    TABLE ACCESS FULL | t3      |  1024 | 24576 |       |     4 |
|*  5 |    HASH JOIN OUTER  |                  |  1024K|   171M|     94M| 11778 |
|*  6 |     TABLE ACCESS FULL| t1      |  1024K|    83M|       | 10144 |
|   7 |     TABLE ACCESS FULL| t4      | 23931 |  2126K|       |    86 |
---------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("t1"."t1"="t2"."OBJID")
   3 - access("t1"."ENTRY_NAME2GBST_ELM"="t3"."OBJID")
   5 - access("t1"."ACT_ENTRY2NOTES_LOG"="t4"."OBJID"(+))
   6 - filter("t1"."X_ACT_ENTRY2X_PROBLEM"=268435457)

Note: cpt2 costing is off

23 rows selected. 




SQL> select count(*), count(distinct x_act_entry2x_problem ) from t1

 COUNT(*)   COUNT(DISTINCTX_ACT_ENTRY2X_PROBLEM)
 5,585,400    5

  
SQL> select count(*)  NULL_CNT   from t1 where x_act_entry2x_problem IS NULL

 NULL_CNT
 4,62,771


  
- we created INDEX on t1 ( x_act_entry2x_problem, 0)
Gathered stats

- exec dbms_stats.gather_table_stats ( user, 'T1',cascade=>TRUE, method_opt=>'FOR ALL HIDDEN COLUMNS')
  
- Objid is the primary key column in each table and rest of the columns in predicate section of the query are indexed ( normal b*tree) 
 
- t1.act_entry2notes_log = t4.objid(+)
 we need outer join here. though primary key but there could be some child on t1 table act_entry2notes_log  without parent ( we  use application level constraints - not a true primary key/ foriegn key model ) 
 
SQL> set autotrace traceot4y
SQL> 
SQL> set timing on
SQL>
SQL> SELECT t3.title, t1.entry_time, t1.act_code, t2.login_name, t4.description,
  2         t4.internal, t1.addt4_info
  3    FROM t1  , t2  , t3 ,
  4         t4  
  5   WHERE t1.act_entry2user = t2.objid
  6     AND t1.entry_name2gbst_elm =t3.objid
  7     AND t1.act_entry2notes_log = t4.objid(+)
  8     AND t1.x_act_entry2x_problem = 268435457
  9  /

Elapsed: 00:06:56.06

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=11924 Card=995286 Bytes=216972348)

   1    0   HASH JOIN (Cost=11924 Card=995286 Bytes=216972348)
   2    1     TABLE ACCESS (FULL) OF 't2' (Cost=3 Card=356 Bytes=6408)

   3    1     HASH JOIN (Cost=11878 Card=1024696 Bytes=204939200)
   4    3       TABLE ACCESS (FULL) OF 't3' (Cost=4 Card=1024 Bytes=24576)

   5    3       HASH JOIN (OUTER) (Cost=11778 Card=1024696 Bytes=180346496)

   6    5         TABLE ACCESS (FULL) OF 't1' (Cost=10144    Card=1024696 Bytes=87099160)

   7    5         TABLE ACCESS (FULL) OF 't4' (Cost=86 Card=23931 Bytes=2177721)





Statistics
----------------------------------------------------------
          0  recursive calls
          0  db blockgets
     106404  consistentgets
      91866  physical reads
          0  redo size
        907  bytes sent via SQL*Net to client
        304  bytes received via SQL*Net from client
          6  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          4  rows processed

    
    
  
  
  SQL> show parameter _area

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
bitmap_merge_area_size               integer     1048576
create_bitmap_area_size              integer     8388608
hash_area_size                       integer     209715200
sort_area_retained_size              integer     0
sort_area_size                       integer     104857600
workarea_size_policy                 string      AUTO
SQL>

SQL> show parameter pga

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target                 big integer 629145600
SQL>


Questions
a)
How to resolve ? 
|*  6 |     TABLE ACCESS FULL| t1      |  1024K|    83M|       | 10144 |

( we have  t1.x_act_entry2x_problem = 268435457  predicate  and expected rows from this filter are very few awlays single digit) 

here i understand mostly null is playing a role here but we have cured that using (col,0) index and gathered stats on ALL hidden col

b)
OUTER HASH JOIN opertaion shows temp tablespace use.


 
 
 regards
 


Tom Kyte
March 23, 2011 - 11:14 am UTC

here i understand mostly null is playing a role here but we have cured that
using (col,0) index and gathered stats on ALL hidden col


No it isn't and no you didn't.


This is the issue:

select count(*), count(distinct x_act_entry2x_problem ) from t1

    COUNT(*)         COUNT(DISTINCTX_ACT_ENTRY2X_PROBLEM)
    5,585,400             5


You have 5 distinct values, we'll therefore retrieve 20% of the table (assuming no histograms, or histograms but uniform distribution).

I don't know what to make of this:

select count(*)  NULL_CNT   from t1 where x_act_entry2x_problem IS NULL

    NULL_CNT
    4,62,771


Unless you are trying to tell me that there are 4.5 million (you posted a non-number in that "cut and paste") and hence there are only 1,000,000 records that are non-null and hence only about 250,000 records would come back.

If that is the case, only 250k records, then you are looking to generate a histogram on that column. No games with a function based index - it won't help.

On the other hand, if we are going to get 20% of the table - it is almost surely better to full scan.

see
https://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:6749454952894#6760861174154

so, which is it?

o really 250k rows - then histogram
o really 1,000,000 rows - then you have the right plan
there is NO WAY you want to do over 1,000,000 index reads into that table.

..Mostly NULL column values

Manoj Kaparwan, March 23, 2011 - 11:42 am UTC

Tom
Apologies of pasting a number ( in non number format)

Here goes the right format:

select count(*), count(distinct x_act_entry2x_problem ) from t1

COUNT(*) COUNT(DISTINCTX_ACT_ENTRY2X_PROBLEM)
5585400 5



select count(*) NULL_CNT from t1 where x_act_entry2x_problem IS NULL

NULL_CNT
462771



Sequence of events

at time T1 : table t1 count - 5585380
at time T2 : table t1 we added a new column x_act_entry2x_problem
at time T3 : we created the index function based on t1 (x_act_entry2x_problem, 0) and gathered stats on HIDDEN COls.
at time T4 : new entrires started flowing into t1
at time T5 : we seen count(*) in t1 - 5585400 ( increased by just 20 from the time T1 so other values of this column remains NULL) and query resulting into above plan

agreed here we are even going to get less than 20% of the table. So full scan a better way.

next

to optmize it?

a) as we have workarea_size_policy AUTO and tempSpec appearing in plan do we need to increase the pga_aggregate_target?






Tom Kyte
March 23, 2011 - 1:22 pm UTC

just because you see temp space in the plan - it does not mean you WILL definitely use temp space.

Given what you've told me - full scan is the right plan.

Unless you are going after the null values for that column - you do NOT NEED nor want the 'function based index' - and you probably don't want an index at all.


Query tuning.

Prince, April 08, 2011 - 4:06 am UTC

Hi Tom,
I need to update a local table selecting data from remote table which is performing very bad.
driving_site hint is working for only select stmt not for update stmt.

sample Query is like :
UPDATE ABCD x SET col1 = (SELECT col2 FROM EFGH y WHERE y.col3= x.col4);

The EFGH is the remote table which having more than 1000000 rows.
Please suggest ...its urgent.

Thanks
Prince
Tom Kyte
April 12, 2011 - 1:41 pm UTC

driving site only works for selects - not for modification DML's


how big is abcd
how big is efgh (i know you think you told me, but you haven't, 1,000,000 rows is meaningless - 1tb is meaningful...)

what is the current plan

how long is it taking
how long do you think it should take

query tunning

jawad, April 13, 2011 - 5:37 am UTC

can u shorten this query
SELECT
SUBSCRIBER_NO,
SUM(NO_OF_COPIES)SUM_COPIES,
DISTRIBUTION_DATE
FROM
(
SELECT DISTINCT(A.SUBSCRIPTION_NO),
B.DISTRIBUTION_START_DATE START_DATE,
B.DISTRIBUTION_END_DATE END_DATE,
A.SUBSCRIBER_NO,
GET_SUBSCRIBER_NAME(A.SUBSCRIBER_NO) SUBSCRIBER_NAME,
GET_SUBSCRIBER_MOBILE_NO(A.SUBSCRIBER_NO) SUBSCRIBER_MOBILE_NO ,
(
CASE
WHEN TO_CHAR(TO_DATE('02/03/2011','DD/MM/RRRR'),'D') BETWEEN 1 AND 5 THEN NVL(B.NORMAL_NO_OF_COPIES,0)
WHEN TO_CHAR(TO_DATE('02/03/2011','DD/MM/RRRR'),'D') = 6 THEN NVL(THI_NO_OF_COPIES,0)
WHEN TO_CHAR(TO_DATE('02/03/2011','DD/MM/RRRR'),'D') = 7 THEN NVL(FRI_NO_OF_COPIES,0)
END
) NO_OF_COPIES,
GET_SUBSCRIPER_TEL_NO(A.SUBSCRIBER_NO) TEL_NO,
GET_SUBSCRIBER_ADDRESS(A.SUBSCRIBER_NO) SUBSCRIBER_ADDRESS,
DECODE(A.MODE_OF_PAYMENT,0,NULL,5,B.NOTE_NO,A.RECEIPT_VOUCHER_NO) INVOICES_NO,
PAYMENT_DESC(A.MODE_OF_PAYMENT) MODE_OF_PAYMENT,
GET_WAT_REGION_NO(GET_SUBSCRIBER_BRANCH_ID(A.SUBSCRIBER_NO),A.SUBSCRIBER_NO) REGION_NO,
B.BRANCH_NO,
TO_DATE('02/03/2011')DISTRIBUTION_DATE
FROM SUBSCRIPTIONS A,
SUBSCRIPTION_DETAIL B
WHERE A.SUBSCRIPTION_NO = B.SUBSCRIPTION_NO AND
A.MARKED_FOR_DELETE ='N' AND B.MARKED_FOR_DELETE ='N' AND
(
(TO_DATE('02/03/2011','DD/MM/RRRR') BETWEEN TO_DATE(B.DISTRIBUTION_START_DATE,'DD/MM/RRRR') AND TO_DATE(B.DISTRIBUTION_END_DATE,'DD/MM/RRRR'))
OR
(
(A.SUBSCRIPTION_STATUS = 4 AND A.RENEWED_SUB_NO IS NULL AND TO_DATE('02/03/2011','DD/MM/RRRR') BETWEEN TO_DATE(B.DISTRIBUTION_START_DATE,'DD/MM/RRRR') AND TO_DATE(B.DISTRIBUTION_END_DATE,'DD/MM/RRRR'))
OR (A.SUBSCRIPTION_STATUS IN (5) AND A.TERMINATION_DATE > TO_DATE('02/03/2011','DD/MM/RRRR'))
)
)
AND GET_SUBSCRIBER_TYPE_CODE (A.SUBSCRIPTION_NO) = 8
AND to_date('02/03/2011','dd/mm/rrrr') >= B.DISTRIBUTION_START_DATE
) GROUP BY SUBSCRIBER_NO,SUBSCRIBER_NAME,DISTRIBUTION_DATE;
Tom Kyte
April 13, 2011 - 10:04 am UTC

You'd have to find someone named "U" I guess - I don't have that name and I don't know of anyone working here that has that name.


This looks very very very suspicious:

TO_DATE(B.DISTRIBUTION_START_DATE,'DD/MM/RRRR')

is that column really a varchar2? or is it a date?


This looks really bad:

GET_SUBSCRIBER_TYPE_CODE (A.SUBSCRIPTION_NO)

a getter function? called from SQL? really? do you really truly need to call plsql from sql, why can't you JUST JOIN????

I see more getter functions in there - that is a really horrible idea.

A reader, April 13, 2011 - 9:02 am UTC

> can u shorten this query

Yes, use a smaller font size.
Tom Kyte
April 13, 2011 - 10:06 am UTC

ok, you made me laugh out loud.

I can turn it into this however:

select * from v;

I should have thought of that above! create view v as <your big select>;

now you just have to type select * from v;

Prince, April 13, 2011 - 12:59 pm UTC

Hi,
Thanks a lot for your reply.
I have done it.Its running smoothly now.
Thanks a lot again.

Prince.

Martin Rose, April 14, 2011 - 5:05 am UTC

> a getter function? called from SQL? really? do you really truly need to call plsql from sql, why can't you JUST JOIN????

> I see more getter functions in there - that is a really horrible idea.


In his defence, it is easier to just call a pre-written function to do the job than it is to possibly hunt down the relevant filter conditions etc. that go to form the SELECT inside that function (especially so for any entry-level developers who may be new to the job).

Sure, it might be slower to execute, but it does allow for more rapid development by not having to re-invent the wheel each time. It is a pain-free way (at least for the initial developers) to get the results they want quickly without having to keep worrying about the details. Also, there may be more than just pure SQL in those functions; you do not know....


Lastly, I'd like to say that application code tuning should be a separate process apart from the initial development of it.

Frequently at the time of initial development it is not known precisely what the client wants. Even the most formally defined of specs. are liable to change over time, so the attitude of management can be to just get it out there & modify what it does on-the-fly in a form of interative feedback loop with the client.

Therefore tuning at too early a stage is not so wise since it may be undone & wiped out by a subsequent change of functionality.
Tom Kyte
April 14, 2011 - 9:54 am UTC

In his defence, it is easier to just call a pre-written function to do the job than it is to possibly hunt down the relevant filter conditions etc. that go to form the SELECT inside that function (especially so for any entry-level developers who may be new to the job).

That is not a defense, that is an excuse :)

It is slower
It uses a TON more resources
If the developer cannot be bother to learn their data model (heck, how did they learn what FUNCTION to call???) - then they shouldn't be writing any SQL against this data.
And if you really want to hide it, use a view.


Also, there may be more than just pure SQL in those functions; you do not know....

I know that, it happens maybe 0.01% of the time (or less). Pretty much almost every time I look under the covers, it isn't true.

I asked "why didn't you just join", if there is a justification - I'd be glad to entertain it - and then offer a different way again.


Lastly, I'd like to say that application code tuning should be a separate process apart from the initial development of it.




I disagree pretty much 100% here. I'm not talking about premature optimization - I'm talking about avoiding patterns that send you down a death spiral every time you use them - this is one of those patterns.


Use a view, no need at all for this getter junk - I hate them, I see no use for them.

Martin Rose, April 15, 2011 - 7:50 am UTC

> It is slower
> It uses a TON more resources

Yes. We know that bit. ;-)


> If the developer cannot be bother to learn their data model (heck, how did they learn what FUNCTION to call???) - then they shouldn't be writing any SQL against this data.

I remember in one of my first jobs there was a horrendous history clause that needed to be added to each query made against a certain table. It went something like this:

SELECT whatever
FROM   a
WHERE
AND (((NOT EXISTS (SELECT NULL
                   FROM   b
                   WHERE  b.PK = a.PK)
OR     EXISTS.....       SELECT MAX(DATE)  )
OR     blah blah blah                      )
Except on a Sunday when it should do this, but not if it was also a full-moon when it should do that)

Well I don't remember it all; it was 20 years ago now !

Now if that had been encapsulated in a function, we wouldn't have got it wrong every time we wrote it out, spending days debugging the bloody thing, and realising that all it was was a misplaced bracket somewhere.

Speed of execution is not an issue if you can't get your system to do what you want it to do in the first place.

i). It should do what it is supposed to do today,
ii). It should do what it is supposed to do tomorrow (given that requirements will likely have changed over time),
iii). It should do points i). + ii). above as quickly as possible.

In order to comply with point ii). the code must also have been originally written (in point i).) in a way that is flexible enough to withstand regular change without breaking down.

So as you can see, speed is the last thing on my (theoretical) menu.


> And if you really want to hide it, use a view.

Well, i). views have their own performance issues as I'm sure you know, when joining multiple ones together - especially when nested, so not a global panacea.

ii). you could end up writing massive views, only to have the developers call a small part of it in any one query. Would this really be more beneficial than lots of smaller disparate functions? Please demo.


> I asked "why didn't you just join", if there is a justification - I'd be glad to entertain it - and then offer a different way again.

I'd hazard a guess they're trying to keep complexity down.


>> Lastly, I'd like to say that application code tuning should be a separate process apart from the initial development of it.

> I disagree pretty much 100% here. I'm not talking about premature optimization - I'm talking about avoiding patterns that send you down a death spiral every time you use them - this is one of those patterns.

Oh my, we are melodramatic today. A 'death spiral'. Lol. <Reaches for the Prozac>.

Well I don't disagree theoretically, but it depends on the size of your app. for one thing.

If you're going to write a major huge eBusiness-sized app. then, yes I'll agree with you. But then I wouldn't want beginners working on that. I'd want a very formally spec'ed project with very good people working on it from the start.

But if you're only building tiny little projects with a minimal number of concurrent users, those functions aren't going to make a dent on performance, but they WILL help the developers develop more quickly & more bug-free because they have to think less & indeed know less about the implementation details.


> Use a view, no need at all for this getter junk - I hate them, I see no use for them.

Will that really solve it either? Lots of little functions can be used anywhere all over the place, but any views would have to be more generic and are 'tied down' to one part(s) of the system.

But please demo. this in case I have misunderstood you.



I would also like to say that I reckon you are mostly called in to companies to fix systems whose performance is causing issues. That is the latter stages of development when most of the donkey-work has been done and functionality is stable. Therefore you only ever get to see systems that cause serious performance headaches, and you might not appreciate that the use of functions was made to precipitate the building of applications in the first place.

I'm not saying I would choose to build that way (coz I don't), but I am saying that speed is not the primary goal for new systems, but rather 'getting it working first' is. Companies also want their systems up & running quickly in order to get payback from them quickly. If this is at the expense of some loss of speed, some companies will gladly take the hit (and sure, they will have to pay the price later). Again, this isn't my personal methodology of working (because I can develop quickly and make it work quickly), but it can be to some companies. I am just reporting back how I see things in the field.
Tom Kyte
May 12, 2011 - 11:21 am UTC

Now if that had been encapsulated in a function, we wouldn't have got it wrong every time we wrote it out, spending days debugging the bloody thing, and realising that all it was was a misplaced bracket somewhere.

can you tell me why a VIEW would not have worked???? It would be a ton more performant then a user defined function by far.


*views* are the way to encapsulate logic in SQL. *views*


Well, i). views have their own performance issues as I'm sure you know, when joining multiple ones together - especially when nested, so not a global panacea

preferred to FUNCTIONS by far. And further - you can create views that are joins as well - you need not join views to views to views if you don't want to.

ii). you could end up writing massive views, only to have the developers call a small part of it in any one query. Would this really be more beneficial than lots of smaller disparate functions? Please demo.

the calling of functions is so horribly expensive, I don't need a demo here. The performance hit is way too high. Period.

And you should create views that are like subroutines, they do what they need to do - you don't NEED to use a massive "one size fits all" view for everyone and everything (people do and that is wrong). Just as you would not code one giant general purpose subroutine that can do everything for everyone.


Oh my, we are melodramatic today. A 'death spiral'. Lol. <Reaches for the Prozac>.

If you have seen it as often as I do, you would call it a death spiral as well - it is what I call an "anti-pattern", something to avoid - something to stay far far far away from.


I'd hazard a guess they're trying to keep complexity down.


right back to square one, it is called...... A VIEW


But if you're only building tiny little projects with a minimal number of concurrent users, those functions aren't going to make a dent on performance, but they WILL help the developers develop more quickly & more bug-free because they have to think less & indeed know less about the implementation details.

and when these guys grow up, do you know what they keep on doing? That anti-pattern, over and over and over again - because they've done it that way forever.


But please demo. this in case I have misunderstood you

You do not need or want a single "one size fits all view", you can "modularize" our views just like you do code.


I would also like to say that I reckon you are mostly called in to companies to fix systems whose performance is causing issues

Yes, I rarely see the successes, I see the anti-patterns that lead to problems.

I am predominantly a software developer - not a DBA - I do code. I know the function argument - I just don't buy into it. It causes problems way more than solves them.


but I am saying that speed is not the primary goal for new systems, but rather 'getting it working first' is.

and then fixing them is - and if they had done it differently in the first place (a programmer is a programmer, they can all program - writing a view is not any harder than coding a bunch of little getter functions) - we could skip that step and still be as productive.



I have to be consistent in what I say - and I've been consistent on this. I don't like 'TAPIs' (table apis) and I really don't like getter functions like this.



Martin Rose, April 15, 2011 - 8:01 am UTC

But I wonder if we cannot have our cake and eat it here.

Could an enhanced version of Oracle help make functions more efficient in SQL ?

If a pragma were introduced into the function (declaring it to be pure SQL and no PL/SQL other than the RETURN), could the optimiser not realise that it is to be merged with the query calling it, instead of executing it in its own right?

But I guess that might be as difficult to come up with as it is presently to merge views together.
Tom Kyte
April 15, 2011 - 11:11 am UTC

The problem is the P in PL/SQL - not the integration between the two (there is a measurable overhead in calling plsql from sql - but the main culprit is the "p")

let's say you have a query such as:


select get_fname(empno), get_lname(empno), get_addr(empno), get_this(empno), get_that(empno), ....
from emp_something...
where ....;


Now, each of those getter routines does something like:

select fname into l_fname from emp where empno = ?;

and returns it. That query is probably 3 IO's via the index plus one against the table. Each of the getters has one of those.

We have five get calls - 5x4 = 20. That is 20 extra IO's per row.

But if you just joined, it would be much less - like probably less than 1 IO per row on a multi-row result set.


the procedural code is not "mergable" with the sql statement - it cannot recognize what the procedural code does and "merge" it into the statement like we can with views.

Another thing - that many people don't realize - is that you break read consistency this way:

http://www.oracle.com/technetwork/issue-archive/2010/10-nov/o60asktom-176254.html

(look for "Now, let’s suppose you are executing a simple query such as select a, b, c, f(x) from t, where a, b, c, and x are columns of a table t and f is a PL/SQL function you’ve written that contains its own SQL statements.")


The SQL that is executed in PLSQL is all read consistent - but only with "itself". By calling the SQL in PLSQL - you'll get inconsistent results.

Inserting performing poor.

Prince, April 18, 2011 - 1:19 am UTC

Hi Tom,
I have an Sql like
Insert into Local_table(col1,col2...col20)
select R1.col1,R2.col5...R5.col18
from Remote_table1 R1,Remote_table2 R2,...Remote_table5 R5
where R1.col1=R2.col2 and R3.col5=R4.col10 and ...

The problem is that the Select stmt is runing fine but the insert stmt is performing very very poor.
Pls Suggest me what alls may be the problems ???
Also suggest me how to tune this ?

Prince
Tom Kyte
April 18, 2011 - 10:33 am UTC

I assume when you say:

"The problem is that the Select stmt is runing fine but the insert stmt is
performing very very poor."

you are comparing the SELECT by itself to the INSERT as SELECT - if so, compare the plans, are they different?

Any chance of getting a view created on the remote site so you can simply:

insert into local select * from remote_view;


that'll have the select optimized on the remote site - which is probably where it needs to be optimized.

An Addition To The Language

Martin Rose, April 18, 2011 - 8:05 am UTC

> The problem is the P in PL/SQL - not the integration between the two (there is a measurable overhead in calling plsql from sql - but the main culprit is the "p")

I think you're misunderstanding my suggestion.

No matter how loud you shout to the contrary, people will keep using functions to encapsulate. For as long as this remains syntactically permissible, people will keep doing it.

My suggestion is 'to go with the flow'. Ie; introduce a mechanism whereby people can still keep using functions, but reduce the performance overhead associated with them.

Staying with your example,
select get_fname(empno), get_lname(empno), get_addr(empno), get_this(empno), get_that(empno), .... 
from emp_something... 
where ....;

I was proposing that Oracle Corp. could introduce a new pragma thus:
FUNCTION get_fname (p_empno emp.empno%TYPE) RETURN VARCHAR2 IS
PRAGMA MERGEABLE_SQL;   <---
--
temp_fname  emp.fname%TYPE;
--
BEGIN
  SELECT FNAME
  INTO   temp_fname  
  FROM   EMP
  WHERE  EMPNO = (p_empno);
  --
  RETURN (temp_fname);
END get_fname;

The pragma would tell the optimiser that the SQL code inside the function was 'textually' mergeable into a main SQL query.

It could be as simple as this to achieve the merge at the textual level (ie; not deep-down inside the optimiser, but at a coarser higher level):
select (SELECT FNAME
        FROM   EMP
        WHERE  EMPNO = empno), get_lname(empno), get_addr(empno), get_this(empno), get_that(empno), .... 
from emp_something... 
where ....;

Ie; the optimiser could simply take the text inside the function and plonk it into the main query. The new pragma tells it that the query may only have one column in the SELECT-list, and that any other PL/SQL inside the function should be ignored during the merging.

And Voilà, you get to keep the functions, and still have decent performance. None of those expensive I/Os associated with getting each row individually, since the SQL inside the function is incorporated into the main query.

(Yes, I appreciate that queries in SELECT-columns are still not currently as efficient as when in the base query, but that's a matter for future versions of the optimiser).


Such a new pragma would enable the performance-tuner developer to come along and rocket the performance of newbie code by simply adding in the pragma (and possibly jiggling around the rest of the function code so as to comply with the other conditions of the pragma). AND, this wouldn't prevent the function from being called under other circumstances from PL/SQL.
Tom Kyte
April 18, 2011 - 10:38 am UTC

Nope, don't like that at all.

That would simply turn things into scalar subqueries - which definitely have their place - but not in general. It would suffer the same logical IO nightmare I described. it would cut out a very small amount of context switch overhead - but would still do excessive IO's.


Martin Rose, April 18, 2011 - 8:11 am UTC

Oh, and no problems with read-consistency either with this method.
Tom Kyte
April 18, 2011 - 10:41 am UTC

I'm right back with one word....


VIEW


and if I shout loud enough and long enough and rail against the people that write books promoting this 'construct' and show evidence of its poor performance and show how it is a bad idea - maybe I'll affect some percentage of programmers out there and have their change their way (or never learn the bad way to begin with)

and that will be a good thing.


And to the ones that do it, they learn fast when shown how bad it is - and how it is the root cause of many of their performance issues. Developers (for the most part) love to learn.

Martin Rose, April 19, 2011 - 7:19 am UTC

> That would simply turn things into scalar subqueries - which definitely have their place - but not in general. It would suffer the same logical IO nightmare I described. it would cut out a very small amount of context switch overhead - but would still do excessive IO's.

So, are you saying that scalar sub-queries perform almost as badly as using functions? I'm in a state of shock!
I never knew that. I knew they were slower, but not that much slower.

The optimiser should be ashamed of itself for not being able to make more out of it than that.


I would suggest that there might be some transformations that could be routinely done at the textual level, but it gets quite complicated when you remember you could have DECODEs (and COALESCEs and any other number/combination of SQL functions in there), thus:

SELECT COALESCE (QM.column2, DECODE(QM.column1, 'Y', (SELECT column
                                                      FROM   table_X
                                                      WHERE  filter_column = MQ_col),
                                                     (SELECT column
                                                      FROM   table_Y
                                                      WHERE  filter_column = MQ_col)))
FROM   MAIN_QUERY MQ

Hmm, maybe it shouldn't be too ashamed after all.... ;-)
Tom Kyte
April 19, 2011 - 6:46 pm UTC

they are not as bad as functions - in fact, I counsel to use scalar subqueries whenever you call a function - in short, do not do:

select f(x) from t;

but rather do:

select (select f(x) from dual) from t;

to take advantage of scalar subquery caching (search this site for that term to read what that means)

the optimizer is pretty advanced, getting more so all of the time, it is likely a matter of time before SOME scalar subqueries can be merged

Martin Rose, April 19, 2011 - 7:47 am UTC

> I'm right back with one word....
> VIEW

You keep saying that, but I'm not convinced.

What if you have a view that has its own sub-query, which in turn has predicates that are not returned in the main query SELECT-list, like this:
CREATE VIEW ABC AS
  SELECT *
  FROM   XYZ
  WHERE  EXISTS (SELECT NULL
                 FROM   QPR
                 WHERE  QPR.JOIN_COLUMN_1 = XYZ.JOIN_COLUMN_1
                 AND    QPR.ATTR_COLUMN_1 = (col1)         <---
                 AND    QPR.ATTR_COLUMN_2 = (col2))        <---

How are you going to join that view into a main query? Views don't take parameters, otherwise I would see how it could work.

Ie; You can't do this because you cannot get ABC.ATTR_COLUMN_1 and ABC.ATTR_COLUMN_2 exposed in the SELECT-list of the view in order to be able to join with them:
SELECT *
FROM   MAIN_QUERY MQ, ABC
WHERE  MQ.Join_Column = ABC.Join_Column
AND    MQ.Col1        = ABC.ATTR_COLUMN_1 
AND    MQ.Col2        = ABC.ATTR_COLUMN_2 

(Hope I've explained that right. It's getting a bit tricky now).

Tom Kyte
April 19, 2011 - 6:51 pm UTC

give me a real world case where this would need to be done - where the function would need inputs to the where exists subquery like that.

that is, give me the SPECS, the goal, the requirement. Then, I can perhaps tell you how to accomplish it.

I don't see how a function with that query in it, since it would return MORE THAN one record in general, would be a function callable from SQL....

A reader, April 20, 2011 - 7:17 am UTC

> give me a real world case where this would need to be done - where the function would need inputs to the where exists subquery like that.

> that is, give me the SPECS, the goal, the requirement. Then, I can perhaps tell you how to accomplish it.

You're on ! Next time I get a problem like that, I'll post back here and defer the problem to you -- though I bet my query begins with "Tom, I've got this problem with functions, but I can't alter the database design (or change the spec.), and we've got this draconian DBA who just won't....."

how to understand explain result

nmgzw, April 20, 2011 - 9:24 pm UTC

After I run explain ,I get below result,but I can't understand "id=(19,20)".
"SYS_C0013988" is an global index on table "TB_ORI_0004".
MY question:
Why it access index "IDX2618978“ before access table "TB_ORI_0004".

Thanks in advance.

This is full explain(sorry for not tidy,some row too long though i delete column time):
PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------------
Plan hash value: 1034630036

-----------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 774 | 399K| 12971| | |
|* 1 | VIEW | | 774 | 399K| 12971| | |
|* 2 | WINDOW SORT PUSHED RANK | | 774 | 209K| 12971| | |
|* 3 | HASH JOIN | | 774 | 209K| 12964| | |
|* 4 | TABLE ACCESS FULL | TB_INDEX_0055 | 74 | 2590 | 6| | |
|* 5 | HASH JOIN | | 11020 | 2604K| 12958| | |
|* 6 | HASH JOIN | | 515 | 112K| 12032| | |
| 7 | NESTED LOOPS | | | | | | |
| 8 | NESTED LOOPS | | 515 | 96305 | 11994| | |
| 9 | NESTED LOOPS | | 606 | 87870 | 10175| | |
| 10 | VIEW | | 2033 | 38627 | 4073| | |
| 11 | HASH GROUP BY | | 2033 | 69122 | 4073| | |
|* 12 | INDEX RANGE SCAN | SYS_C0013988 | 419K| 13M| 4049| | |
| 13 | SORT AGGREGATE | | 1 | 8 | | | |
| 14 | INDEX FULL SCAN (MIN/MAX) | IDX_76_01 | 9516 | 76128 | 2| | |
|* 15 | TABLE ACCESS BY GLOBAL INDEX ROWID| TB_ORI_0004 | 1 | 126 | 3| ROWID | ROWID |
|* 16 | INDEX UNIQUE SCAN | SYS_C0013988 | 1 | | 2| | |
| 17 | SORT AGGREGATE | | 1 | 8 | | | |
| 18 | INDEX FULL SCAN (MIN/MAX) | IDX_76_01 | 9516 | 76128 | 2| | |
|* 19 | INDEX UNIQUE SCAN | SYS_C0013988 | 1 | | 2| | |
| 20 | TABLE ACCESS BY GLOBAL INDEX ROWID | TB_ORI_0004 | 1 | 42 | 3| ROWID | ROWID |
| 21 | INDEX FAST FULL SCAN | IDX2618978 | 12098 | 425K| 38| | |
| 22 | TABLE ACCESS BY INDEX ROWID | TB_INDEX_0056 | 45572 | 845K| 925| | |
|* 23 | INDEX RANGE SCAN | IDX83882807 | 45572 | | 247| | |
| 24 | SORT AGGREGATE | | 1 | 8 | | | |
| 25 | INDEX FULL SCAN (MIN/MAX) | IDX83882807 | 14M| 113M| 4| | |
-----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("NO_"<31)
2 - filter(ROW_NUMBER() OVER ( ORDER BY "F0004_028N"-"F0004_028N" DESC )<31)
3 - access("F0055_001N"="F0056_002N")
4 - filter("F0055_003V"='ÐÂÉêÍòÒ»¼¶')
5 - access("F0056_003V"="F0005_001V")
6 - access("F0004_003V"="F0005_007V" AND "F0004_004V"="F0005_005V" AND "F0004_005V"="F0005_001V")
12 - access("F0004_001D"= (SELECT MAX("F0076_001D") FROM "MF"."TB_ORI_0076" "TB_ORI_0076"))
15 - filter("F0004_014N"<>0)
16 - access("F0004_001D"= (SELECT MAX("F0076_001D") FROM "MF"."TB_ORI_0076" "TB_ORI_0076") AND
"F0004_002V"="T"."F0004_002V" AND "F0004_003V"="T"."F0004_003V" AND "F0004_004V"="T"."F0004_004V" AND
"F0004_005V"="T"."F0004_005V")
19 - access("F0004_001D"="F0004_001D" AND "F0004_002V"=TO_CHAR(TO_DATE("T"."F0004_002V",'HH24mi')-10,'HH24mi')
AND "F0004_003V"="T"."F0004_003V" AND "F0004_004V"="T"."F0004_004V" AND "F0004_005V"="T"."F0004_005V")
23 - access("F0056_001D"= (SELECT MAX("F0056_001D") FROM "MF"."TB_INDEX_0056" "TB_INDEX_0056"))

TABLE ACCESS FULL

reader, May 05, 2011 - 2:13 pm UTC


Is there a way to query AWR (10.2.0.4.0) to get information on what sqlids do Full table scan (TABLE ACCESS FULL)?

Thanks.
Tom Kyte
May 06, 2011 - 10:17 am UTC

why, did you want to find the most performant queries? Full scans are awesome.

Why don't you use AWR to look for HIGH LOAD SQL???? It does that natively and naturally. Those are the queries you want to look at.

Looking for full scans is short sighted and just plain WRONG.

(yes you can, look at the dba_hist_* views, there is one with sql plans there, but that is all I'm going to say. If you've read a book that says "look for full scans and tune them", you've read the WRONG book :) )

Quert Tunning

Sambhav, May 11, 2011 - 11:33 am UTC

Dear Tom,

I am new in Sql tuning. Need your help.

SELECT DISTINCT
circle.circle_name AS "Circle",
state.region_state_name AS "Region/State",
loc.location_name AS "Wharehouse",
caf.mobile_number AS "CELL No",
caf.caf_number AS "CAF No",
'O'||caf.sim_number AS "SIM No",
title.title_name || ' ' || postcust.customer_first_name || ' ' || postcust.customer_last_name || ' ' || postcust.customer_middle_name AS "CUSTOMER NAME",
scheme.scheme_name AS "Scheme Name",
scheme.scheme_desc AS "Scheme Desc",
scheme.security_deposit AS "Security Deposit",
invoice.invoice_number AS "Invoice No",
caf.SALE_DATE AS "Sale Date",
caf.created_date AS "Created Date",
person.first_name || ' ' || person.last_name AS "Invoice Created By",
invoicedtl.invoice_dtl_id,
invoicedtl.invoice_id

FROM
cpos_cmn_mst_circle circle,
cpos_cmn_mst_region_state state,
cpos_cmn_mst_location loc,
CPOS_CMN_ENT_LOC_ASSO locEnt,
cpos_crs_trn_caf caf,
cpos_crs_trn_postpaid_customer postcust,
cpos_crs_mst_title title,
cpos_sale_trn_invoice invoice,
cpos_sale_trn_invoice_dtl invoicedtl,
cpos_cmn_mst_ent_person person,
cpos_crs_mst_scheme scheme

WHERE
circle.circle_id = state.circle_id
AND state.region_state_id = loc.region_state_id
AND loc.LOCATION_ID = locEnt.LOCATION_ID
AND locEnt.ENT_ORG_ID = caf.primary_entity_id
AND locEnt.ENT_PERSON_ID =person.person_ent_id(+)
AND caf.postpaid_customer_id = postcust.postpaid_customer_id
AND title.title_id(+) = postcust.title_id
AND caf.scheme_id(+) = scheme.scheme_id

AND invoicedtl.sim_no(+) = caf.sim_number
AND invoicedtl.invoice_id = invoice.invoice_id(+)
AND circle.is_active = 'Y'
AND state.is_active = 'Y'
AND caf.is_active = 'Y'
AND postcust.is_active = 'Y'
AND (title.IS_ACTIVE='Y' OR title.TITLE_ID is null)
AND (scheme.is_active = 'Y' OR scheme.scheme_id is null)
AND circle.CIRCLE_ID = 4
AND nvl(caf.CAF_DATE,'') BETWEEN nvl( TO_DATE('04/01/2011','MM/DD/YYYY'),nvl(caf.CAF_DATE,sysdate))
AND nvl(TO_DATE('04/10/2011','MM/DD/YYYY'),nvl(caf.CAF_DATE,sysdate))


This Query is taking 8 minutes while executing.
Could you please let me know how can we tune this query.

Thanks in Advance
Tom Kyte
May 11, 2011 - 11:45 am UTC

nope.

read the above original answer.


(I can say that whoever wrote the query did not understand the data they were working with. My evidence is:

caf.scheme_id(+) = schema.scheme_id
...
AND caf.is_active = 'Y'
....


think about what an outer join means - and what value caf.is_active could have if we had to make up a record for the outer join - and what the outcome of caf.is_active = 'Y' would be in that case....




OH MY

AND nvl(caf.CAF_DATE,'') BETWEEN nvl( 
TO_DATE('04/01/2011','MM/DD/YYYY'),nvl(caf.CAF_DATE,sysdate)) 
  AND  nvl(TO_DATE('04/10/2011','MM/DD/YYYY'),nvl(caf.CAF_DATE,sysdate))


what does nvl(caf.caf_date,'') do.... think about that. it'll be the same as:

nvl(caf.caf_date, to_date(NULL))

which is.....

caf.caf_date - ta-dah.


and then we:

nvl(TO_DATE('04/01/2011','MM/DD/YYYY'),nvl(caf.CAF_DATE,sysdate))

which is the same as...

O_DATE('04/01/2011','MM/DD/YYYY') - ta-dah

and then

nvl(TO_DATE('04/10/2011','MM/DD/YYYY'),nvl(caf.CAF_DATE,sysdate))

which is of course:

TO_DATE('04/10/2011','MM/DD/YYYY') - getting repetitious...



but hey, if caf.caf_date between those two dates - has to be true - we are back to "outer join"??? why???

A reader, May 12, 2011 - 7:53 am UTC

Thanks Tom for Quick response.
As always you are Excellent.


Few concern :

1) caf.scheme_id(+) = schema.scheme_id
AND caf.is_active = 'Y'
i guess matched records from the condition above after that it will filter out those records
Having caf,is_active = 'Y'

Can we use caf.is_active(+) = 'Y' insead of caf.is_active.
What doesit means exactly. here in caf.is active is having value like Y & N.

2) caf.scheme_id(+) = schema.scheme_id
AND AND caf.is_active = 'Y'

Means

caf.scheme_id = schema.scheme_id
AND AND caf.is_active = 'Y' ..??

IS it correct

Because when i checked the data count and removed AND caf.is_active = 'Y' condition count is coming greater than previous Query.


May be these from some basics stuffs,i am not good in Sql tunning and not in outer joins.

It will be great if you can suggest any Query tunning book written by you.

Many thanks Tom,

Tom Kyte
May 12, 2011 - 11:19 am UTC

1) no, you should just drop the (+) on the join, it cannot be necessary - it is semantically wrong.

It won't change the performance as the optimizer is already smart enough in most all cases to 'fix' this for you. It just makes the person who coded the query look bad.


2) Yes, instead of

caf.scheme_id(+) = scheme.scheme_id and caf.is_active = 'Y'

just code:

caf.scheme_id = scheme.scheme_id and caf.is_active = 'Y'


and not in
outer joins.


then perhaps you need a mentor at work to work through this with you and educate you on this - if you don't get outer joins, you shouldn't be coding a query like this - you sort of need to understand SQL.


Re-read my original answer as far as a query tuning book goes. That original answer is my answer to query tuning.

Sambhav, May 12, 2011 - 10:37 am UTC

Thanks a lot

Sambhav, May 12, 2011 - 11:44 am UTC


Thanks a lot once again Tom, Your comments really help me to tune the query and now i have good idea about outer join.
Really appreaciate you help.

Could you please suggest some latest 10g query tunning good books.

Many thanks

Tuning query

Tony, May 18, 2011 - 7:13 am UTC

Hi Tom,

I have the below script

SQL*Plus: Release 9.2.0.1.0 - Production on Wed May 18 17:30:48 2011

Copyright (c) 1982, 2002, Oracle Corporation.  All rights reserved.


Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.1.0 - 64bit Production
With the Partitioning, Oracle Label Security, OLAP, Data Mining
and Real Application Testing options

SQL>
SQL> create table customers (
  2  cust_no number(20) primary key
  3  );

Table created.

SQL> Insert into CUSTOMERS (CUST_NO) Values (1234);

1 row created.

SQL> Insert into CUSTOMERS (CUST_NO) Values (5678);

1 row created.

SQL> create table bills (
  2  cust_no number(20) references customers (cust_no),
  3  bill_no varchar2(30) primary key,
  4  bill_amt number(25,5)
  5  );

Table created.

SQL> Insert into BILLS (CUST_NO, BILL_NO, BILL_AMT) Values (1234, 'B1', 150);

1 row created.

SQL> Insert into BILLS (CUST_NO, BILL_NO, BILL_AMT) Values (1234, 'B2', 140);

1 row created.

SQL> Insert into BILLS (CUST_NO, BILL_NO, BILL_AMT) Values (5678, 'B3', 90);

1 row created.

SQL> Insert into BILLS (CUST_NO, BILL_NO, BILL_AMT) Values (5678, 'B4', 60);

1 row created.

SQL> create table bill_details (
  2  bill_no varchar2(30) references bills(bill_no),
  3  charge_code varchar2(5),
  4  amt number(25,5)
  5  );

Table created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B1', 'CH1', 50);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B1', 'CH2', 40);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B1', 'CH3', 40);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B2', 'CH1', 60);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B2', 'CH5', 70);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B3', 'CH6', 20);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B3', 'CH3', 50);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B4', 'CH4', 30);

1 row created.

SQL> Insert into BILL_DETAILS (BILL_NO, CHARGE_CODE, AMT) Values ('B4', 'CH9', 15);

1 row created.

SQL>
SQL> select
  2  C.cust_no,
  3  count(*) no_of_bills,
  4  sum(B.bill_amt) bill_amt,
  5  sum((select sum(amt) from bill_details D where D.bill_no = B.bill_no)) amt
  6  from customers C,
  7       bills B
  8  where C.cust_no = B.cust_no
  9  group by C.cust_no;

   CUST_NO NO_OF_BILLS   BILL_AMT        AMT
---------- ----------- ---------- ----------
      1234           2        290        260
      5678           2        150        115

SQL>

Is there any better way of writing the above query. I thought, if there are a lot of records in customers and bills table, the scalar subquery might cause a performance issue since it will be executed for each record in bills

Tom Kyte
May 18, 2011 - 10:32 am UTC

ops$tkyte%ORA11GR2> select C.cust_no, count(*) no_of_bills, sum(B.bill_amt) bill_amt, sum(b.amt) amt
  2    from customers C,
  3         (select sum(d.amt) amt, b1.bill_amt, b1.cust_no
  4            from bills B1, bill_details d
  5           where b1.bill_no = d.bill_no
  6           group by b1.bill_amt, b1.cust_no, b1.bill_no ) B
  7   where C.cust_no = B.cust_no
  8   group by C.cust_no
  9  ;

   CUST_NO NO_OF_BILLS   BILL_AMT        AMT
---------- ----------- ---------- ----------
      5678           2        150        115
      1234           2        290        260






A reader, May 18, 2011 - 9:05 pm UTC

Hi Tom,

since cust_no in bills reference(foriegn Key) to customers for every custno in bills table there must be custno present in bills having said that one way of doing this is as below


select max(cust_no), max(cnt), max(bill_sum) as bill_amt, sum(y.amt) as amt
from
(
select cust_no, bill_no,sum(bill_amt)over(partition by cust_no) as bill_sum,
count(*)over(partition by cust_no) as bill_cnt
from bills
)x,
bill_details y
where x.BILL_NO=y.BILL_NO
Group by cust_no


Thanks

A reader, May 18, 2011 - 9:58 pm UTC

continue... from above post

Also scaler query by op means IF there is no record in the bill_detials for a given cust_no
in bills the amt will be null, don't you think you need to use left join between bills and bill_details

or may be

select x.cust_no, count(*) as no_of_bills, sum(x.bill_amt) as bill_amt, sum(y.tot_amt) as amt
from
bills x
Left Join
(
select bill_no, sum(amt) as tot_amt
from bill_details
group by bill_no
)y
ON x.bill_no=y.bill_no
group by x.cust_no

Thanks
Tom Kyte
May 19, 2011 - 12:53 am UTC

it depends, it could be necessary depending on what they actually want as output and if rows exists in bills with no details.

delete charge transaction records for orders with invalid vault ids

karthic, May 26, 2011 - 6:27 pm UTC

I tried to run this in VDEV enveronment but the query is not completing and it ran about 16 hrs before I cancelled it. Can you optimize the query.


DELETE FROM yfs_charge_transaction
WHERE charge_type = 'AUTHORIZATION'
AND status = 'CHECKED'
AND user_exit_status != 'INVOKED'
AND order_header_key IN
( SELECT order_header_key
FROM yfs_charge_transaction
WHERE charge_type = 'AUTHORIZATION'
AND status = 'CHECKED'
AND user_exit_status != 'INVOKED'
GROUP BY order_header_key
HAVING COUNT ( * ) > 10);


Could you give an insight of this sql of what you have changed and what could be the reason for it running for 16 hrs

I really appericate if i get this ASAP.
Tom Kyte
May 26, 2011 - 6:30 pm UTC

VDEV environment is meaningless to anyone that doesn't work with you.


you do not tell us

a) how big in bytes this table is
b) how many rows this table is
c) how many rows you believe you'll have to delete
d) what sort of situation index wise we are in


It doesn't look like a very hard plan - but seeing the plan would be useful as well.

who about this?

A reader, May 27, 2011 - 11:00 pm UTC

Delete
from
(
select rowid, order_header_key, count(*)over(partition by order_header_key) as cnt
from
yfs_charge_transaction
WHERE charge_type = 'AUTHORIZATION' AND status = 'CHECKED'
AND user_exit_status != 'INVOKED'
)X where cnt>10
Tom Kyte
May 31, 2011 - 9:37 am UTC

ops$tkyte%ORA11GR2> delete from
  2  (select rowid, empno, count(*) over (partition by empno) cnt
  3    from scott.emp
  4  )
  5  where cnt > 10;
(select rowid, empno, count(*) over (partition by empno) cnt
*
ERROR at line 2:
ORA-01732: data manipulation operation not legal on this view

Bytes column in Explain Plan

Amit Kulkarni, June 02, 2011 - 10:09 am UTC

I'm new in Oracle arena after spending 5 years in objectivity.. for a telecom domain project.
Rarly see such an informative collection of wast topics.

I'm trying my hand on CBO concepts.

Need help on

In a description PLAN_TABLE Columns
Bytes: is decribes as ===>
"Estimate by the cost-based approach of the number of bytes accessed by the operation."

Can you though some light on how CBO calculates this?
Is it related to number of blocks of corrospnding table? Or related to MBRC of the system stat?

Regards,
Amit
Tom Kyte
June 02, 2011 - 10:59 am UTC

it is based on the estimated cardinality (number of rows) and the estimated width of the row source (not the average width of a row in general - if you only select 1 column from a multi-column table - the estimated bytes will be smaller then if you select all of the columns)

ops$tkyte%ORA11GR2> create table t as select * from all_objects;

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select object_id from t;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      | 89106 |  1131K|   288   (1)| 00:00:04 |
|   1 |  TABLE ACCESS FULL| T    | 89106 |  1131K|   288   (1)| 00:00:04 |
--------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement (level=2)

<b>that is the estimated size of 90k numbers...</b>


ops$tkyte%ORA11GR2> select object_name from t;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      | 89106 |  1479K|   288   (1)| 00:00:04 |
|   1 |  TABLE ACCESS FULL| T    | 89106 |  1479K|   288   (1)| 00:00:04 |
--------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement (level=2)

<b>90k varchar2's of varying widths is a little larger...</b>

ops$tkyte%ORA11GR2> select * from t;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      | 89106 |    13M|   289   (1)| 00:00:04 |
|   1 |  TABLE ACCESS FULL| T    | 89106 |    13M|   289   (1)| 00:00:04 |
--------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement (level=2)

<b> getting 90k rows - full rows - is larger yet</b>

ops$tkyte%ORA11GR2> select * from t where rownum = 1;

Execution Plan
----------------------------------------------------------
Plan hash value: 508354683

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |     1 |   158 |     3  (34)| 00:00:01 |
|*  1 |  COUNT STOPKEY     |      |       |       |            |          |
|   2 |   TABLE ACCESS FULL| T    | 89106 |    13M|     3  (34)| 00:00:01 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(ROWNUM=1)

Note
-----
   - dynamic sampling used for this statement (level=2)

<b>going after one row - very small - 158 bytes, but the table size is estimated to be 13mb - but the count stopkey shows we won't really be hitting all of that - so the query final output is 158bytes</b>

ops$tkyte%ORA11GR2> select * from t where rownum <= 10;

Execution Plan
----------------------------------------------------------
Plan hash value: 508354683

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |    10 |  1580 |     3  (34)| 00:00:01 |
|*  1 |  COUNT STOPKEY     |      |       |       |            |          |
|   2 |   TABLE ACCESS FULL| T    | 89106 |    13M|     3  (34)| 00:00:01 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(ROWNUM<=10)

Note
-----
   - dynamic sampling used for this statement (level=2)

<b>10 rows, 10 times as much estimated data...</b>


ops$tkyte%ORA11GR2> set autotrace off

Enrique Aviles, June 07, 2011 - 12:42 pm UTC

There's a debate that originated in Twitter about the merits of SQL.

Care to join the conversation?

http://iggyfernandez.wordpress.com/2011/06/05/why-sql-loses-and-nosql-wins/

The title is a bit misleading because it doesn't make a case for NoSQL but for a completely new language.


sql tuning requirement

A reader, June 21, 2011 - 11:56 am UTC

Hi,
I have tuning requiremnet as follows with sample data,

I have two tables and sample data as follows..


create table usr(uid varchar2(100),cid number(10));

insert into usr('abc',1);

insert into usr('def',2);

insert into usr('ghe',3);

insert into usr('ijk'4);

insert into usr('lmn',5);

insert into usr('opq',6);

------


create table conf(id number(10),type varchar2(20),name varchar2(20));


insert into conf(1,'x','y');

insert into conf(2,'xy','yz');

insert into conf(4,'xyz','mno');

insert into conf(10,'xyza','mnop');


My query is as follows

select uid from usr where cid in (select id from conf where type='x' and name='y');---here type and name columns are variable

The above query is called in java code and it is called many times from java env..and at times the query is slow...

for this I am asked to write a packaged function which is called from java code instead of this query..

My idea of implementing the function is as follws..


create or replace type typ1 as table of varchar2(100);

create or replace type typ2 as table of varchar2(100);



create or replace package tst as

type r_cur is ref cursor;

function tstfunc(ptype typ1,pname typ2) return r_cur

end;
/


create or replace package body tst as



function tstfunc(ptype typ1,pname typ2) return r_cur
is
c r_cur;
begin
open c for
select uid bulk collect into rec_var from usr a.cnf b where usr.cid=conf.id
and type in (select * from table(cast ptype as typ1)) and name in (select * from table(cast pname as typ2));
return c;
end tstfunc;
end tst;


Am i going in a write direction or is there any way to improve the performance of the above sql called from java env repeatedly??
Tom Kyte
June 21, 2011 - 1:10 pm UTC

I don't follow your logic at all, you start by stating:

select uid from usr where cid in (select id from conf where type='x' and
name='y');---here type and name columns are variable

which I assume means the query is using bind variables in place of 'x' and 'y', but you are using equality.


Then you psuedo code a function using IN? And it seems like you are sending a pair of arrays - so that you would get all of the records for many pairs - that is, instead of executing

select uid from usr where cid in (select id from conf where type=? and name=?)

over and over, you would send two arrays down to the procedure and just do one select?

If that is correct, your implementation would be very wrong -

where type in (set1) and name in (set2)

is very very very different from what you have as singleton queries over and over again.

What you need is:

select uid 
  from usr 
 where cid in (select id 
                 from conf 
                where (type,name) in (set) )



You have to keep the pairing together. You could do something like this:





ps$tkyte%ORA11GR2> create table usr("UID" varchar2(100),cid number(10));

Table created.

ops$tkyte%ORA11GR2> insert into usr values('abc',1);

1 row created.

ops$tkyte%ORA11GR2> insert into usr values('def',2);

1 row created.

ops$tkyte%ORA11GR2> insert into usr values('ghe',3);

1 row created.

ops$tkyte%ORA11GR2> insert into usr values('ijk',4);

1 row created.

ops$tkyte%ORA11GR2> insert into usr values('lmn',5);

1 row created.

ops$tkyte%ORA11GR2> insert into usr values('opq',6);

1 row created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> exec dbms_stats.gather_table_stats( user, 'USR' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create table conf(id number(10),type varchar2(20),name varchar2(20));

Table created.

ops$tkyte%ORA11GR2> insert into conf values (1,'x','y');

1 row created.

ops$tkyte%ORA11GR2> insert into conf values (2,'xy','yz');

1 row created.

ops$tkyte%ORA11GR2> insert into conf values (4,'xyz','mno');

1 row created.

ops$tkyte%ORA11GR2> insert into conf values (10,'xyza','mnop');

1 row created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> exec dbms_stats.gather_table_stats( user, 'CONF' );

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> variable txt varchar2(4000)
ops$tkyte%ORA11GR2> exec :txt := 'x/y,xyz/mno'

PL/SQL procedure successfully completed.

<b>those represent your "pairs" - comma separated.  We can then turn them into our set:</b>


ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> with data
  2  as
  3  (
  4  select substr( token, 1, instr(token,'/')-1) type,
  5         substr( token, instr(token,'/')+1) name
  6    from (
  7  select /*+ cardinality( t 10 ) */
  8    trim( substr (txt,
  9          instr (txt, ',', 1, level  ) + 1,
 10          instr (txt, ',', 1, level+1)
 11             - instr (txt, ',', 1, level) -1 ) )
 12      as token
 13     from (select ','||:txt||',' txt
 14             from dual) t
 15   connect by level <=
 16      length(:txt)-length(replace(:txt,',',''))+1
 17         )
 18  )
 19  select *
 20    from data;

TYPE                 NAME
-------------------- --------------------
x                    y
xyz                  mno


<b>and then use them in a subquery</b>


ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> with data
  2  as
  3  (
  4  select substr( token, 1, instr(token,'/')-1) type,
  5         substr( token, instr(token,'/')+1) name
  6    from (
  7  select /*+ cardinality( t 10 ) */
  8    trim( substr (txt,
  9          instr (txt, ',', 1, level  ) + 1,
 10          instr (txt, ',', 1, level+1)
 11             - instr (txt, ',', 1, level) -1 ) )
 12      as token
 13     from (select ','||:txt||',' txt
 14             from dual) t
 15   connect by level <=
 16      length(:txt)-length(replace(:txt,',',''))+1
 17         )
 18  )
 19  select *
 20    from usr
 21   where cid in (select id
 22                   from conf
 23                                  where (type,name) in (select * from data) )
 24  /

UID                         CID
-------------------- ----------
abc                           1
ijk                           4


Note that you would use the cardinality hint to tell us "about how many" you TYPICALLY expect - meaning - pick a number, a reasonable number, and use it for ALL queries, do not put in an exact number for each and every query execution (the default cardinality would be something like 8168 if you had an 8k block size - 10 is probably a good starting place)... Or, if you sometimes have a lot and sometimes have few I would recommend - where a lot is A LOT (wouldn't fit into a varchar2(4000) string - use a global temporary table, have the java app BULK/BATCH insert the type/name pairs into the global temporary table and use that as the subquery. You would use dbms_stats to lock stats on the global temporary table to tell us a representative size.


Bind friendly, performant (assuming correct indexes in place and reasonable numbers of items to be selected)...

A reader, June 22, 2011 - 9:47 am UTC

superb tom,thanks a lot for your valuable time.i am fascinated by the way u turn any requirement to a beautiful sql.I started liking oracle sql after visting this site.Thanks for everything.

A reader, June 23, 2011 - 1:47 pm UTC

Hi Tom,

Two questions on the above requirement..

1.In the above requirement if the logical operator is or i.e
select uid from usr where cid in (select id from conf where type='x' or name='y')

How can I implement that??

2.If data is large you suggested to use global temporary table and use that in the subquery.Can you please elaborate it through some sample code i.e gist.

Thanks for your valuable time.

Tom Kyte
June 23, 2011 - 2:30 pm UTC

1) that would be your query - two different IN clauses - with an OR between them.

where type in (select ...) or name in (select ....)


2) create global temporary table gtt ( type varchar2(10), name varchar2(10) ) on commit delete rows;

and then the client application would insert into that table all of the pairs.

and then you would reference it in the query instead of my DATA view I had.


Nothing really magic, just as straight forward as it sounds.

Hi...

Sam, June 24, 2011 - 5:58 am UTC

Hi Tom,

Scenario :

I have 2 table A and table B

Table A is having 3 columns Start_sr_no,end_sr_no and quantity.

Data like start_sr_no : 12345
end_sr_no = 12350 and quantity = 5.

Table B is having column : serial_no.

Table A is having combination of accepted and rejected serial no .

and table b is having only rejected serial no say like

12346, and 12347.


I want a query which will show only accepted serial no.

so what i want table A - Table b serial no.

Bt in my table A intial serial start no n and no are there ...so i am not able expected output.

Need your help in this

thanks



Tom Kyte
June 24, 2011 - 9:30 am UTC

no create
no inserts
not going to look

I don't know if you can or cannot do what you want - all I know is I have no data to work with


this doesn't make sense to me: "Bt in my table A intial serial start no n and no are there "

Hiii

Sam, June 26, 2011 - 8:00 am UTC

Dear Tom,

Please find the data below.

CREATE TABLE a (srart_sr_no NUMBER,
end_sr_no NUMBER,
qty NUMBER);


CREATE TABLE b (serial_no NUMBER);


insert into a values(12345,12350,6);

INSERT INTO b
(SELECT 12346
FROM DUAL
UNION
SELECT 12347
FROM DUAL);


commit;

In table A only start serial no and end serial no columns are there and its qty .

So i have serial no like
12345
12346
12347
12348
12349
12350.


Table is having serial no which in rejectd.
i.e = 12346 and 12347.

I want a query which shows output of only selected serial no
I.e

12345
12348
12349
12350.

Need ypur help on this.

Best Regards
Sam
Tom Kyte
June 26, 2011 - 11:30 am UTC

do you REALLY have qty in that table??? really??? think about the "not smartness" of that concept.

but anyway - just to make it interesting, I added a row to A to test with and here you go:

ops$tkyte%ORA11GR2> CREATE TABLE a (srart_sr_no NUMBER,
  2                  end_sr_no   NUMBER,
  3                  qty         NUMBER);

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> CREATE TABLE b (serial_no NUMBER);

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> insert into a values(12345,12350,6);

1 row created.

ops$tkyte%ORA11GR2> insert into a values(1234,1236,3);

1 row created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> INSERT INTO b
  2     (SELECT 12346
  3        FROM DUAL
  4      UNION
  5      SELECT 12347
  6        FROM DUAL);

2 rows created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> commit;

Commit complete.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> select *
  2    from a, table( cast( multiset( select a.srart_sr_no+level-1 sn
  3                                     from dual
  4                                  connect by level <= end_sr_no-srart_sr_no+1 ) as sys.odciNumberList ) )
  5   where not exists ( select null from b where b.serial_no = COLUMN_VALUE )
  6  /

SRART_SR_NO  END_SR_NO        QTY COLUMN_VALUE
----------- ---------- ---------- ------------
      12345      12350          6        12345
      12345      12350          6        12348
      12345      12350          6        12349
      12345      12350          6        12350
       1234       1236          3         1234
       1234       1236          3         1235
       1234       1236          3         1236

7 rows selected.

Thanks

Sam, June 27, 2011 - 10:02 am UTC

Hi Tom,

Thanks for the help. you are great.

Hi...

Sam, June 28, 2011 - 1:35 am UTC

Dear Tom,

As per the above question, i am getting some issue.
kindly help me.

insert into A values('899186002444001128
','899186002444001135
',8);

but when i run the
SELECT column_value
FROM A a,
TABLE (CAST (MULTISET (SELECT a.start_sr_no + LEVEL - 1 sn
FROM DUAL
CONNECT BY LEVEL <= end_sr_no - start_sr_no + 1) AS SYS.odcinumberlist
)
)

i m getting column_value like 8.99186002444001E17.

how can i get the exact serial no.

Many thanks in advance
Tom Kyte
June 28, 2011 - 11:51 am UTC

select to_char( column_value, '999999999999999999999999999999999999' ) from ...


use an explicit format, do not let sqlplus use ITS default formatting rules. Be explicit - convert the number to a string in the manner you would like to see it.

Hi..

Sam, June 29, 2011 - 7:45 am UTC

Thanks for your quick response Tom.

In My requirement i have select only those rows where the input serial number is in between start serila no and end serial no.

when i run this query

SELECT column_value
FROM cpos_sale_trn_inc_inv_srn a,
TABLE (CAST (MULTISET (SELECT a.start_sr_no + LEVEL - 1 sn
FROM DUAL
CONNECT BY LEVEL <= end_sr_no - start_sr_no + 1) AS
SYS.odcinumberlist
)
)
Where to_char(column_value) = 899186002444001128


i am getting invalid number.

How can i check that in where clause.
Like i only need to take only those row where start_sr_no and end_sr_no is between my given input.

I have tried with below query

SELECT to_char(column_value)
FROM cpos_sale_trn_inc_inv_srn a,
TABLE (CAST (MULTISET (SELECT a.start_sr_no + LEVEL - 1 sn
FROM DUAL
CONNECT BY LEVEL <= end_sr_no - start_sr_no + 1) AS
SYS.odcinumberlist
)
)
Where '899186002444001130' between a.start_sr_no and a.end_sr_no

but getting wrong output. This may be because in am using between clause with String.

Need your help on this. thnx
Tom Kyte
June 29, 2011 - 12:19 pm UTC

why are you converting the number to a string to compare? why are you comparing strings to numbers????

you have numbers - please just use numbers and nothing else. Get rid of the to_char() (especially since you didn't use a number format as suggested), get rid of the Where '899186002444001130' between a.start_sr_no and a.end_sr_no


if you want me to help you write a complete query - I always need create tables, insert into tables and so on to work with.

Followup

Sam, June 29, 2011 - 1:21 pm UTC

create table a (start_sr_no varchar2(30),
end_sr_no varchar2(30),
qty NUMBER);




Insert into A
(START_SR_NO, END_SR_NO, QTY)
Values
('9186002456', '9186002464', 9);
Insert into A
(START_SR_NO, END_SR_NO, QTY)
Values
('9186002445', '9186002452', 8);
Insert into A
(START_SR_NO, END_SR_NO, QTY)
Values
('123456', '123464', 9);
Insert into A
(START_SR_NO, END_SR_NO, QTY)
Values
('899186002444001128', '899186002444001135', 8);
Insert into A
(START_SR_NO, END_SR_NO, QTY)
Values
('899186002444001112', '899186002444001120', 9);
COMMIT;




In table A start serial no ,end serial no and its qtantity is there.

User is giving input parameter as serial number.
I want to check the serial number is present in this table or not.

I want query for the same.

Provided input serial number is also a string.


I am trying with following Query but it is giving correct output for some case but wrong for some case.

SELECT to_char(column_value)
FROM a,
TABLE (CAST (MULTISET (SELECT a.start_sr_no + LEVEL - 1 sn
FROM DUAL
CONNECT BY LEVEL <= end_sr_no - start_sr_no + 1) AS
SYS.odcinumberlist
)
)
Where '899186002444001130' between a.start_sr_no and a.end_sr_no
and rownum <2


Please let me know that if we can use this query.

2) The column_value is number so
Can we check data directly like

SELECT to_char(column_value)
FROM a,
TABLE (CAST (MULTISET (SELECT a.start_sr_no + LEVEL - 1 sn
FROM DUAL
CONNECT BY LEVEL <= end_sr_no - start_sr_no + 1) AS
SYS.odcinumberlist
)
)
where column_value in ('9186002457','899186002444001131','899186002444001116')


Please suggest,many thanks in advance
Tom Kyte
June 29, 2011 - 3:08 pm UTC

why are you using strings to store numbers?

Hi...

Sam, June 29, 2011 - 9:22 pm UTC

That was the existing table structure. we can't change it.

Can we get query which i asked for.
Tom Kyte
June 30, 2011 - 1:38 pm UTC

please do not EVER say "we can't change it"

the correct and only phrasing that applies would be:

"we WON'T change it even though we know it is wrong"
"we consciously have decided to do this in this bad fashion"

It is not that you cannot change it, it is that you have made a conscious decision knowing all of the fact NOT TO change it.


Just saying. Also "can we get query which I asked for" is fairly presumptuous sounding - don't you think? I never really promised to write code for you.


Your query is trivial:

select * from a where to_number(:USER_INPUTS) between to_number(start_sr_no) and to_number(end_sr_no);


it literally is that simple. However, due to your improper use of a string to store a number (and that qty field!!! ugh, that is just piling on - the entire wrongness of it all) - but however, due to your improper use of a string to store a number, the performance of that query is going to be as bad as it looks.

You cannot compare strings as you attempted. The string '8' is greater and then string '20' you see (with numbers, that is not so...) You'd have to store your numbers in fixed width strings padded with leading zeroes or something if you wanted to use a string comparison.

so many things done wrong here, so many.

and there are only three columns!

SQL statements with same explain plan but slow on one server,

A reader, June 30, 2011 - 10:38 am UTC

Hello,

We have two databases on two different set of clusters. The database size and the table which we are quering are almost same on both the databases. However, the run time is varying a lot even though explain plan is quite similar. I also did a 10046 trace and here are some of the details:

SELECT ISSUEID, OS_VERSION, FOUND_IN_BUILD, PROJECT_NAME, STATE,
SEVERITY, to_char(SUBMITDATE,'dd-MON-YYyy') as SUBMITDATE, TARGET_IC,
SUBMITTER, SUBMITTERS_PROJECT, TITLE, ISSUETYPE, DUPLICATE_OF
FROM QUIX.BO_QX_CR
WHERE SUBMITTERS_PROJECT = 'hpux.test.standards' AND
MINOR_OS_VERSION = '0809' OR
SUBMITTERS_PROJECT = 'hpux.test.standards' AND
FOUND_IN_BUILD LIKE '%326x%'
ORDER BY
SUBMITDATE DESC, SUBMITTER

********************************************************************************

On fast database....
Plan hash value: 796847641

-------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 324 | 42952 (2)| 00:08:36 |
| 1 | SORT ORDER BY | | 2 | 324 | 42952 (2)| 00:08:36 |
|* 2 | TABLE ACCESS FULL| BO_QX_CR | 2 | 324 | 42951 (2)| 00:08:36 |
-------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("SUBMITTERS_PROJECT"='hpux.test.standards' AND
("FOUND_IN_BUILD" LIKE '%326x%' OR "MINOR_OS_VERSION"='0809'))

tkprof output.........
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.02 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 5.21 37.64 221201 225989 0 1
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 4 5.23 37.66 221201 225989 0 1

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: SYS

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT AGGREGATE (cr=225989 pr=221201 pw=0 time=0 us)
4 TABLE ACCESS FULL BO_QX_CR (cr=225989 pr=221201 pw=0 time=0 us cost=42951 size=26 card=2)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
KJC: Wait for msg sends to complete 1 0.00 0.00
library cache pin 1 0.00 0.00
rdbms ipc reply 1 0.00 0.00
SQL*Net message to client 2 0.00 0.00
enq: KO - fast object checkpoint 2 0.00 0.00
reliable message 1 0.00 0.00
direct path read 13702 0.09 15.01
db file sequential read 2119 0.02 1.18
SQL*Net message from client 2 0.00 0.00


BLOCKS NUM_ROWS DEGREE LAST_ANALYZED PAR
---------- ---------- ---------------------------------------- -------------------- ---
220160 1177777 1 29-may-2011 11:56:09 NO

********************************************************************************

On slow database.............
Plan hash value: 796847641

-------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 324 | 55831 (1)| 00:11:10 |
| 1 | SORT ORDER BY | | 2 | 324 | 55831 (1)| 00:11:10 |
|* 2 | TABLE ACCESS FULL| BO_QX_CR | 2 | 324 | 55830 (1)| 00:11:10 |
-------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("SUBMITTERS_PROJECT"='hpux.test.standards' AND
("FOUND_IN_BUILD" LIKE '%326x%' OR "MINOR_OS_VERSION"='0809'))

tkprof output...........
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 1 20.00 329.98 368346 437268 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 3 20.00 330.00 368346 437268 0 0

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: SYS

Rows Row Source Operation
------- ---------------------------------------------------
0 SORT AGGREGATE (cr=0 pr=0 pw=0 time=0 us)
4 TABLE ACCESS FULL BO_QX_CR (cr=172706 pr=170016 pw=0 time=0 us cost=55830 size=26 card=2)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 1 0.00 0.00
enq: KO - fast object checkpoint 2 0.02 0.04
reliable message 1 0.01 0.01
db file sequential read 123972 0.16 262.88
gc current block 2-way 1 0.00 0.00
gc cr multi block request 4 0.00 0.01
db file parallel read 1 0.00 0.00
direct path read 30563 0.11 51.98
gc cr block 2-way 8 0.01 0.02
SQL*Net break/reset to client 1 0.00 0.00


BLOCKS NUM_ROWS DEGREE LAST_ANALYZED PAR
---------- ---------- ---------------------------------------- -------------------- ---
252896 1216460 1 25-jun-2011 03:31:51 NO

********************************************************************************

One difference I notieced is parallel_max_servers on slow database is set to 160 and on fast database it is set to 8.

How to troubleshoot this problem? Why it is doing a lot of db file sequential read on slow database even though explain plan sys FT scan?

Thanks,

Tom Kyte
July 01, 2011 - 8:55 am UTC

those tables are not even remotely near the same size. Not from what I see as far as IO's go.

this does not appear to be using parallel query at all. I'd expect to see a parallel plan in the tkprof

you are doing a ton more physical IO on one machine versus the other.

And something is causing the single block IO's to go through the roof (db file sequential read). Is the table unusually chained for some reason?

Follow up

Sam, June 30, 2011 - 11:26 pm UTC


First thing thanks for let me know how to write and what to write.

Second , what i wanna point that we can't change the column because its is existing table structure and i know it was the wrong way of storing the data.

But if we change it to number ,its impacting so many places.

Anyways thanks a lot for your valuable time.

Tom Kyte
July 01, 2011 - 9:04 am UTC

Please - you are saying it wrong again:


what you should write is:


what I want to point out is that we HAVE CHOSEN NOT TO change the column



If you change it to a number, it will fix so many things for you.

Thanks for your time - and remember - you have CHOSEN NOT TO change the column, it is not that you cannot change the column. That is an important semantic difference, it changes everything.


chosen not to

not "cannot" - because of course you *can*, there is no technical reason you could not fix this issue.


and you are welcome.

follow up,

A reader, July 01, 2011 - 10:01 am UTC

"And something is causing the single block IO's to go through the roof (db file sequential read). Is the table unusually chained for some reason? "

I guess chained rows was the cause. I read a note in Metalink about this. We decided to rebuild the table on the slow database and later the query returned back within 20 seconds with no db file sequential read.

But what I don't understand is, why it was chained? Internally, how Oracle reads chained rows. Is it always one block at a time? Are the contents of each row split in more than one block?

There may be other tables as well that needs a similar treatment. We are picking tables that are in slow queries.

Thanks,
Tom Kyte
July 01, 2011 - 11:50 am UTC

why was it chained? I can only guess - given I don't know the history of the table.

I would make the following guess (based on the fact that a reorganization 'fixed' the issue):

the rows were inserted 'small' on the 'slow' database and later updated to be large. This could potentially cause a lot of rows to migrate (chain) because they no longer fit on the block they were inserted on. This wasn't true on the 'fast' database.



There are two types of chained rows:

a) migrated rows - I believe you had migrated rows since the reorganization 'fixed' them.

b) chained rows - rows that either are too large to fit on a single block (so reorganizing them won't do anything - they'll still be too bit) or that contain 255 or more columns (we store those rows in row pieces - up to 4 row pieces - each accessed via single block gets when we need to retrieve them)



You can use the analyze table list chained rows command to see if a table is currently heavily chained or not.

Index Tunning for sqls

Scudeler, July 04, 2011 - 7:13 am UTC

Tom,

In my company Schema, there are several tables that have their
primary key composed of the foreign key from other tables.

Example:

TABLE0001

 Name             Type         Nullable Default Comments 
 ---------------- ------------ -------- ------- -------- 
 CDFIELD1         NUMBER(10)                             
 CDFIELD2         NUMBER(10)                             
 CDFIELD3         NUMBER(10)                             
 CDFIELD4         NUMBER(10)                             
 CDFIELD5         NUMBER(10)                             
 CDFIELD6         NUMBER(10)                             
 CDREADING        NUMBER(10)                             
 VLREADING        NUMBER(18,8) Y                            

Constraints of TABLE0001
 
 Name           Type     Fields 
 -------------- -------- ---------------------------------------------------------------
 SYS_C00879280  Primary  CDFIELD1,CDFIELD2,CDFIELD3,CDFIELD4,CDFIELD5,CDFIELD6,CDREADING
 FKTABLE001_002 Foreign  CDFIELD1,CDFIELD2,CDFIELD3,CDFIELD4,CDFIELD5,CDFIELD6,
 

Indexes of TABLE0001 

 Name   Type     Fields 
 -------------- -------- ---------------------------------------------------------------
 SYS_C00879280  Primary  CDFIELD1,CDFIELD2,CDFIELD3,CDFIELD4,CDFIELD5,CDFIELD6,CDREADING
 IXTABLE001_002 Unique   CDFIELD1,CDFIELD2,CDFIELD3,CDFIELD4,CDFIELD5,CDFIELD6



In my opinion, i can drop Index "IXTABLE001_002", and i will start to use "SYS_C00879280"
in existing sqls, because the leading columns are the same.

-> Is there any reason to keep the index "IXTABLE001_002"? am i missing something?



If the same table, were a little bit different:

TABLE0002

 Name             Type         Nullable Default Comments 
 ---------------- ------------ -------- ------- -------- 
 CDFIELD1         NUMBER(10)                                                                                  
 CDREADING        NUMBER(10)                             
 VLREADING        NUMBER(18,8) Y    

Constraints of TABLE0002
 
 Name        Type         Fields 
 ----------------   -----------  --------------------
 SYS_C00879280      Primary      CDFIELD1, CDREADING
 FKTABLE0001_0002   Foreign      CDFIELD1
 

Indexes of TABLE0002

 Name        Type         Fields 
 ----------------   -----------  --------------------
 SYS_C00879280      Primary      CDFIELD1, CDREADING
 IXTABLE0001_0002   Unique       CDFIELD1


-> In this other scenario, i have the same question, may i drop index
"IXTABLE0001_0002" and use "SYS_C00879280"?

There are a lot of tables in this situation here, i would like to understand,
if would be safe to drop this overlapping indexes.
Will i have some significant performance gains by querying the primary key instead
of the regular index?

Best Regards,
Scudeler
Tom Kyte
July 05, 2011 - 9:10 am UTC

In my opinion, i can drop Index "IXTABLE001_002", and i will start to use "SYS_C00879280"
in existing sqls, because the leading columns are the same.


probably NOT - see how it is a unique index? If it is being used instead of a unique constraint - you need it.

do you have a unique constraint on those columns? If you did - it could use the primary key index to enforce uniqueness (and then you could drop that index)


if you use constraints - we'd have the smallest set of indexes - for example:

ops$tkyte%ORA11GR2> create table t ( x int, y int, z int );

Table created.

ops$tkyte%ORA11GR2> alter table t add constraint t_unique unique(x,y) using index (create index t_idx on t(x,y,z));

Table altered.

ops$tkyte%ORA11GR2> alter table t add constraint t_pk primary key(x,y,z);

Table altered.

ops$tkyte%ORA11GR2> pause

ops$tkyte%ORA11GR2> @desc t
ops$tkyte%ORA11GR2> @sset
ops$tkyte%ORA11GR2> store set &SETTINGS rep
Wrote file /tmp/xtmpx2011070236388.sql
ops$tkyte%ORA11GR2> set verify off
ops$tkyte%ORA11GR2> set linesize 72
ops$tkyte%ORA11GR2> set pagesize 9999
ops$tkyte%ORA11GR2> set feedback off
ops$tkyte%ORA11GR2> set echo off
Datatypes for Table t

                               Data                 Data
Column Name                    Type                 Length     Nullable
------------------------------ -------------------- ---------- --------
X                              NUMBER                          not null
Y                              NUMBER                          not null
Z                              NUMBER                          not null


Indexes on t

Index                          Is
Name                           Unique COLUMNS
------------------------------ ------ --------------------------------
T_IDX                          No     X, Y, Z


Triggers on t
ops$tkyte%ORA11GR2> 



that one index can be used to enforce both constraints now


any performance gains will be had by not having to maintain two indexes - it won't really materially affect retrieval, it will affect your insert/update/delete performance (as the index does not exist to be maintained)

Simple SQL Tuning

Greg, July 04, 2011 - 3:12 pm UTC

Tom, I read one of those small O'Reilly books on tuning SQL. The guy seemed talented. His ultimate conclusion was *most* SQL statements can be tuned by: using nested loops to drive into tables, and going into those tables via an index where the join column is the leading column on the index. I wonder what you think of this.


Tom Kyte
July 05, 2011 - 11:58 am UTC

I think that is rather simplistic.

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:6749454952894#6760861174154


I disagree that most sql statements can be tuned by such an approach. Unless you have a system where most sql statements read one record from one table and get a few detail records from another table - simple two table joins of a master detail. If you have just queries like that - sure, but then they are so simple the optimizer would get them right without any work on anyones part (meaning - we don't have to tune those queries in the first place).

If what he said were true, the rule based optimizer would be what we all use - since that was its simplistic approach.

Index Tunning for sqls 2

Scudeler, July 05, 2011 - 3:18 pm UTC

Tom,

Thank you for the valuable answer, it helped me a lot with one of my other doubt.

But I think i messed up my real point of the question, when i was changing the column names of my company schema. Im sorry, my fault!

Here is the real structure:

SQL> create table table0001(cdfield1 number(10),cdfield2 number(10), cdfield3 number(10), cdfield4 number(10), nmfields varchar(255));

SQL> alter table table0001 add constraint t0001_pk primary key(cdfield1,cdfield2,cdfield3,cdfield4);

SQL> create table table_fk(cdfield1 number(10),cdfield2 number(10), cdfield3 number(10),dsfields varchar(50));

SQL> alter table table_fk add constraint tfk_pk primary key(cdfield1,cdfield2,cdfield3);

SQL> alter table table0001 add constraint t0001_tfk_fk foreign key(cdfield1,cdfield2,cdfield3) references table_fk(cdfield1,cdfield2,cdfield3);

SQL> create index index_t0001_tfk on table0001(cdfield1,cdfield2,cdfield3);

SQL> exec dbms_stats.gather_table_stats('MYSCHEMA','TABLE0001');

SQL> exec dbms_stats.gather_table_stats('MYSCHEMA','TABLE_FK');

SQL> set linesize 1000
SQL> set autotrace on
SQL> select *
  2    from myschema.table0001 a
  3        ,myschema.table_fk  b
  4   where a.cdfield1 = b.cdfield1
  5     and a.cdfield2 = b.cdfield2
  6     and a.cdfield3 = b.cdfield3;

no rows selected.

Execution Plan
----------------------------------------------------------
------------------------------------------------------------------------------------------------
| Id  | Operation                    | Name            | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |                 |     1 |   247 |     2   (0)| 00:00:01 |
|   1 |  NESTED LOOPS                |                 |       |       |            |          |
|   2 |   NESTED LOOPS               |                 |     1 |   247 |     2   (0)| 00:00:01 |
|   3 |    TABLE ACCESS FULL         | TABLE_FK        |     1 |    66 |     2   (0)| 00:00:01 |
|*  4 |    INDEX RANGE SCAN          | INDEX_T0001_TFK |     1 |       |     0   (0)| 00:00:01 |
|   5 |   TABLE ACCESS BY INDEX ROWID| TABLE0001       |     1 |   181 |     0   (0)| 00:00:01 |
------------------------------------------------------------------------------------------------

Statistics
----------------------------------------------------------
         62  recursive calls
          0  db block gets
         24  consistent gets
          0  physical reads
          0  redo size
        904  bytes sent via SQL*Net to client
        509  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          0  rows processed
   
SQL> drop index myschema.index_t0001_tfk;

SQL> exec dbms_stats.gather_table_stats('MYSCHEMA','TABLE0001');

SQL> exec dbms_stats.gather_table_stats('MYSCHEMA','TABLE_FK');

SQL> select *
  2    from myschema.table0001 a
  3        ,myschema.table_fk  b
  4   where a.cdfield1 = b.cdfield1
  5     and a.cdfield2 = b.cdfield2
  6     and a.cdfield3 = b.cdfield3;

no rows selected.

Execution Plan
----------------------------------------------------------
------------------------------------------------------------------------------------------
| Id  | Operation                    | Name      | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |           |     1 |   247 |     2   (0)| 00:00:01 |
|   1 |  NESTED LOOPS                |           |       |       |            |          |
|   2 |   NESTED LOOPS               |           |     1 |   247 |     2   (0)| 00:00:01 |
|   3 |    TABLE ACCESS FULL         | TABLE_FK  |     1 |    66 |     2   (0)| 00:00:01 |
|*  4 |    INDEX RANGE SCAN          | T0001_PK  |     1 |       |     0   (0)| 00:00:01 |
|   5 |   TABLE ACCESS BY INDEX ROWID| TABLE0001 |     1 |   181 |     0   (0)| 00:00:01 |
------------------------------------------------------------------------------------------

Statistics
----------------------------------------------------------
         82  recursive calls
          0  db block gets
         28  consistent gets
          0  physical reads
          0  redo size
        904  bytes sent via SQL*Net to client
        509  bytes received via SQL*Net from client
          1  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
          0  rows processed


In my simple example above, when i drop index index_t0001_tfk and update de statistics, Oracle started to use the primary key index (Which is unique, and i didnt create that.).
The FK constraint tfk_pk(cdfield1, cdfield2, cdfield3) in table0001 aren't unique, because the primary key has cdfield4 too.

Question: can i drop index_t0001_tfk and start to use T0001_PK in sqls? isnt index T0001_PK better than INDEX_T0001_TFK?

I still think index index_t0001_tfk is overlapping the primary key index.

Best Regards,
Scudeler
Tom Kyte
July 05, 2011 - 4:32 pm UTC

if the index is not there to implicitly enforce a constraint that is not defined as a constraint - eg: as long as someone didn't create the index to ensure those columns are unique without also defining a unique constraint - you can drop whatever you like.

Yes, if you have an index on (a,b,c,d) and on (a,b,c) there is a HIGH probability that the index on (a,b,c) (especially if it is non-unique) is not needed - the index on (a,b,c,d) would suffice just as well.

Sql Tuning

Arup, July 07, 2011 - 3:38 pm UTC

Hey Tom please help me to rewrite the sql in robust way the sql is given below

Reviewer: Arup from USA
Hey Tom please help me to rewrite the sql in robust way the sql is given below

SELECT y.offeringname offering, collection_centre,
NVL (SUM (renewalpaymentamount), 0.0) renewalpaymentamount,
NVL (SUM (newregistrationpaymentamount),
0.0
) newregistrationpaymentamount,
SUM (renewaluser) renewaluser,
SUM (newregistrationuser) newregistrationuser
FROM (SELECT x.offeringname, x.collection_centre,
DECODE (x.paymenttype,
'RENEWALPAYMENT', SUM (x.chargeamount)
) renewalpaymentamount,
DECODE
(x.paymenttype,
'NEWREGISTRATIONPAYMENT', SUM (x.chargeamount)
) newregistrationpaymentamount,
DECODE (x.paymenttype,
'RENEWALPAYMENT', SUM (x.serviceno)
) renewaluser,
DECODE (x.paymenttype,
'NEWREGISTRATIONPAYMENT', SUM (x.serviceno)
) newregistrationuser
FROM (SELECT /*+index(c cc_accountsrvc_prodlinid_ndx)*/
COUNT (DISTINCT b.serviceno) serviceno,
g.offeringname,
cc.costcentre_name AS collection_centre,
SUM (DISTINCT a.paymentamount) chargeamount,
(CASE
WHEN (b.offeringtypeid = 5)
THEN 'RENEWALPAYMENT'
ELSE 'NEWREGISTRATIONPAYMENT'
END
) paymenttype
FROM (SELECT g.costcentre_id, g.costcentre_code,
g.costcentre_name
FROM gl_costcentre g
WHERE g.parent_costcentre_id IN (
SELECT costcentre_id
FROM gl_costcentre x
WHERE ( x.parent_costcentre_id =
TO_NUMBER (-1)
OR (-1) = -1
))) cc,
ap_payment a,
ap_invoicepayment e,
ap_invoice f,
ap_accountnrc b,
cc_accountservice c,
pk_offering d,
cc_accountserviceoffering g
WHERE a.locationid = cc.costcentre_id
AND b.serviceno = e.serviceno
AND e.invoiceid = f.invoiceid
AND f.invoiceno = b.invoiceno
AND e.paymentid = a.paymentid
AND c.serviceinstanceid = g.serviceinstanceid
AND g.offeringtypeid = 12
AND g.stopdate IS NULL
AND b.accountno = c.accountno
AND b.serviceno = c.serviceno
AND b.offeringid = d.offeringid
AND b.offeringtypeid <> 2
AND a.allocationtype IN (0, 1, 2, 3)
AND a.paymentstatus IN (1, 2)
AND TRUNC (a.paymentdate)
BETWEEN TO_DATE ('15/05/2011', 'DD/MM/YYYY')
AND TO_DATE ('14/06/2011', 'DD/MM/YYYY')
AND TRUNC (b.chargedate) BETWEEN TO_DATE
('15/05/2011',
'DD/MM/YYYY'
)
AND TO_DATE
('14/06/2011',
'DD/MM/YYYY'
)
AND c.productlineid = 29
GROUP BY g.offeringname,
cc.costcentre_name,
b.offeringtypeid,
b.invoiceno
UNION ALL
SELECT /*+index(c cc_accountsrvc_prodlinid_ndx)*/
COUNT (DISTINCT b.serviceno) serviceno,
g.offeringname,
cc.costcentre_name AS collection_centre,
SUM (DISTINCT a.paymentamount) chargeamount,
(CASE
WHEN (b.offeringtypeid = 5)
THEN 'RENEWALPAYMENT'
ELSE 'NEWREGISTRATIONPAYMENT'
END
) paymenttype
FROM (SELECT g.costcentre_id, g.costcentre_code,
g.costcentre_name
FROM gl_costcentre g
WHERE g.parent_costcentre_id IN (
SELECT costcentre_id
FROM gl_costcentre x
WHERE ( x.parent_costcentre_id =
TO_NUMBER (-1)
OR (-1) = -1
))) cc,
ap_payment a,
ap_invoicepayment e,
ap_invoice f,
ap_accountnrc b,
cc_accountservice c,
pk_offering d,
cc_accountserviceoffering g
WHERE a.locationid = cc.costcentre_id
AND b.serviceno = e.serviceno
AND e.invoiceid = f.invoiceid
AND f.invoiceno = b.invoiceno
AND e.paymentid = a.paymentid
AND c.serviceinstanceid = g.serviceinstanceid
AND g.offeringtypeid = 12
AND c.status = 4
AND b.accountno = c.accountno
AND b.serviceno = c.serviceno
AND b.offeringid = d.offeringid
AND b.offeringtypeid <> 2
AND a.allocationtype IN (0, 1, 2, 3)
AND a.paymentstatus IN (1, 2)
AND TRUNC (a.paymentdate)
BETWEEN TO_DATE ('15/05/2011', 'DD/MM/YYYY')
AND TO_DATE ('14/06/2011', 'DD/MM/YYYY')
AND TRUNC (b.chargedate) BETWEEN TO_DATE
('15/05/2011',
'DD/MM/YYYY'
)
AND TO_DATE
('14/06/2011',
'DD/MM/YYYY'
)
AND c.productlineid = 29
GROUP BY g.offeringname,
cc.costcentre_name,
b.offeringtypeid,
b.invoiceno) x
GROUP BY x.collection_centre, x.offeringname, x.paymenttype
ORDER BY x.collection_centre, x.offeringname, paymenttype) y
GROUP BY collection_centre, offeringname
ORDER BY collection_centre, offeringname
Tom Kyte
July 08, 2011 - 2:26 pm UTC

thanks, but I'll pass on this one.

This is not "have tom rewrite my query"

this is "ask tom a well formed question about a concept, a way to do something, how something works"

A reader, July 07, 2011 - 4:13 pm UTC

SELECT g.costcentre_id, g.costcentre_code,
g.costcentre_name
FROM gl_costcentre g
WHERE g.parent_costcentre_id IN
(
SELECT costcentre_id
FROM gl_costcentre x
WHERE ( x.parent_costcentre_id = TO_NUMBER (-1) OR (-1) = -1 )

)


your above WHERE clause does not make sense since the condition (-1) = -1 is always true which means you want all costcentre_id

which in turn select all rows from gl_costcentre which is simply

select g.costcentre_id, g.costcentre_code,
g.costcentre_name
FROM gl_costcentre g

-1 clarifiaction

Arup, July 08, 2011 - 7:54 am UTC

Thanks for your reply
but the -1 is actually a parameter i have given the sql after puting the parameter, to select all the costcentre parameter is -1 or to select particular costcentre the parameter is a costcentre id.
hope you undertand.
the actual query seems to be like this as follows
where P_COSTCENTRE_ID is the input parameter.Thanks in advance.
SELECT g.costcentre_id, g.costcentre_code,
g.costcentre_name
FROM gl_costcentre g
WHERE g.parent_costcentre_id IN
(
SELECT costcentre_id
FROM gl_costcentre x
WHERE ( x.parent_costcentre_id = TO_NUMBER (P_COSTCENTRE_ID) OR (P_COSTCENTRE_ID) = -1 )

)

Tuning of select statement

raju, July 12, 2011 - 7:18 am UTC

Hi Tom hope doing well,
I wanted to tune below sql statement and this is designed in such a way some external system is to receive the responce.So we can not modify the where conditions which are in the where clause.
SELECT DISTINCT Oha.Header_id, Oha.Orig_sys_document_ref, Oha.Attribute15
FROM Oe_order_headers_all Oha, Oe_order_lines_all Ola, Wsh_delivery_details Wdd
WHERE
(('''||p_order_status||''' IS NULL) OR (UPPER ('''||p_order_status||''') = DECODE(Oha.Flow_status_code,'||'''CANCELLED'''||','||'''COMPLETED'''||','||'''CLOSED'''||','||'''COMPLETED'''||','||'''OPEN'''||')))
AND (('''||p_return_approval_state||''' IS NULL) OR (Oha.Attribute18 = '''||p_return_approval_state||'''))
AND (('''||p_sales_channel||''' IS NULL) OR (Oha.Sales_channel_code = '''||p_sales_channel||'''))
AND (('''||l_from_date||''' IS NULL) OR (Oha.Creation_date >= '''||l_from_date||'''))
AND (('''||l_to_date||''' IS NULL) OR (Oha.Creation_date - 1 < '''||l_to_date||'''))
AND Oha.ORG_ID = DECODE('''||p_country_code||''','||'''SE'''||',''2'',''47'')
AND Oha.Orig_sys_document_ref IS NOT NULL
AND Oha.Header_id = Ola.Header_id
AND (('''||p_orig_sys_line_ref||''' IS NULL) OR (Ola.Orig_sys_line_ref = '''||p_orig_sys_line_ref||'''))
AND Ola.Order_source_id = Fnd_profile.VALUE('||'''XX_CRM_IMPORT_SOURCE'''||')
AND Ola.Line_id = Wdd.Source_line_id
AND Ola.Header_id = Wdd.Source_header_id;

Could you please help me to tune the above query
Tom Kyte
July 13, 2011 - 1:47 pm UTC

if you cannot modify it, what is the point of asking anything? think about that for a minute, if you write "so we can not (sic) modify the here conditions..."


All I see is a dynamic sql statement that is constructed in such a manner that I cannot believe I'm even seeing it.

You are using dynamic sql - but you might as well have.


I see no bind variables - I see something subject to SQL INJECTION in a huge big way (this query should be outlawed - period, I would never let it be done that way in any stored procedure, it is so broken, it isn't even funny).


you probably want to read this:

http://www.oracle.com/technetwork/issue-archive/2009/09-jul/o49asktom-090487.html

and use that technique. sql injection SAFE and builds the best query - but - will require changes.

more cost for a table

A reader, July 17, 2011 - 6:15 am UTC

Hi tom,
am having a table OE_ORDER_HEADERS_ALL which gives more cost 63000 even after computing columns,indexes statistics also. Could you tell me how can i reduce this cost.
Tom Kyte
July 18, 2011 - 10:27 am UTC

why? it is not like the cost = time exactly.

If I reduce the cost of a query, but the plan doesn't change - have I made it any faster?


You are likely scanning that table and it is big, changing the cost isn't necessarily going to do anything for you here.

outer join alternative

Tony, July 26, 2011 - 1:41 pm UTC

Tom,
Thanks for sharing your wonderful(beautiful) mind with us, I have a query (part of about 16 unions but this is the one taking most of the time)

select l_ld as Mmy_id, round(sum( Sdenor ),2) as Denor from(
SELECT DISTINCT
s.s_num,
dummy2.l_ld,
NVL(dummy1.kms,99) *s.t_val AS
Sdenor
FROM
s_tab s,
(SELECT CONCAT(CONCAT(d_tab.point_a, d_tab.pnt_a_cd),
CONCAT(d_tab.point_b, d_tab.pnt_b_cd)) AS pt_a_b, d_tab.kms
FROM d_tab)
dummy1,
(SELECT DISTINCT lld.s_id,
lld.l_ld,
CONCAT(CONCAT(lld.frm_pnt, lld.frm_cd),
CONCAT(lld.to_pnt, lld.to_cd)) AS
pt_f_t
FROM ldetail_tab lld
WHERE lld.l_ld NOT IN
(SELECT g.l_ld
FROM g_tab glt where l_ld is not null)
)
dummy2
WHERE dummy1.pt_a_b(+) = pt_f_t
AND s.s_id = dummy2.s_id)
group by l_ld;

it's doing full table scan on about 10M rows table, I'm trying to tune it and come up with :

select l_ld as Mmy_id, round(sum( Sdenor ),2) as Denor from(
SELECT DISTINCT
s.s_num,
dummy2.l_ld,
NVL(dummy1.kms,99) *s.t_val AS
FROM
s_tab s,
d_tab dummy1,
ldetail_tab lld
WHERE
s.s_id = lld.s_id AND
((dummy1.point_a = lld.frm_pnt) AND ( dummy1.pnt_a_cd = lld.frm_cd) )) AND
((dummy1.point_b = lld.to_pnt) AND ( dummy1.pnt_b_cd = lld.to_cd) )) AND
lld.l_ld NOT IN
(SELECT g.l_ld
FROM g_tab glt where l_ld is not null) ) group by l_id;

But not getting what I need i.e not sure how to implement "dummy1.pt_a_b(+) = pt_f_t" part. btw the new query is very fast (avoids full table scan)

Thanks a lot.
Regards

SQL tuning

tilak, August 05, 2011 - 9:18 am UTC

Hi Tom,
i am unable to tune this bit of sql , which is taking longer than expected.
the table transactions is around 160 million and that was the only big one, it has got good amount of indexes though,
but still it take more than an hour to run, is there anyway to get around this.
the query is

SELECT *
FROM (WITH q1
AS (SELECT /*+ materialize */
acc1.acc_account_no,
acc1.acc_subacc_no,
acc1.acc_soc_seqno,
acc1.acc_gact_type,
acc1.acc_incep_date,
acc1.acc_closure_date,
nvl((select pe1.accpea_balance_os
from accounts_pe_afs pe1
where pe1.accpea_account_no = acc1.acc_account_no
and pe1.accpea_subacc_no = acc1.acc_subacc_no
and pe1.accpea_period = to_date('31-DEC-2010','DD-MON-YYYY')),0) acc_balance_bfwd,
nvl((select 'SSBS'
from account_xrefs
where axref_target_account_no = acc1.acc_account_no
and axref_target_subacc_no = acc1.acc_subacc_no
and rownum = 1),'CBS') orig_source,
nvl((select pe1.accpea_balance_os
from accounts_pe_afs pe1
where pe1.accpea_account_no = acc1.acc_account_no
and pe1.accpea_subacc_no = acc1.acc_subacc_no
and pe1.accpea_period = to_date('31-DEC-2009','DD-MON-YYYY')),0) start_bal,
acc1.acc_balance_os end_bal
FROM accounts acc1, societies
WHERE acc1.acc_process_status < 4 or NVL (acc1.acc_closure_date, TRUNC (SOC_WCAL_PRIMARY_DATE)) > '31-DEC-2008'),
q2
AS ( SELECT /*+ materialize */
t1.tran_account_no,
t1.tran_subacc_no,
t1.tran_soc_seqno,
sum(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' then 0 else 1 end) number_of_trans,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE DECODE(NVL(tran_amount_db,0),0,
DECODE(SIGN(NVL(tran_amount_cr,0)),-1,tran_amount_cr*-1,tran_amount_db),tran_amount_db) END) tranAmountDB,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE NVL((DECODE(SIGN(NVL(tran_amount_cr,0)),-1,0,tran_amount_cr)),0) END) tranAmountCR,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE DECODE(NVL(tran_bal_int_db,0),0,
DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,tran_bal_int_cr*-1,tran_bal_int_db),tran_bal_int_db) END) tranAmountIntDB,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE NVL((DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,0,tran_bal_int_cr)),0) END) tranAmountIntCR,
sum(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' then 1 else 0 end) number_of_ACI_trans,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN DECODE(NVL(tran_bal_int_db,0),0,
DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,tran_bal_int_cr*-1,tran_bal_int_db),tran_bal_int_db) ELSE 0 END) ACItranAmountIntDB,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN NVL((DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,0,tran_bal_int_cr)),0) ELSE 0 END) ACItranAmountIntCR,--
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE DECODE(TO_CHAR(TRAN_AUDIT_DATE,'YYYY'),TO_CHAR(SOC_WCAL_PRIMARY_DATE,'YYYY'),DECODE(NVL(tran_amount_db,0),0,
DECODE(SIGN(NVL(tran_amount_cr,0)),-1,tran_amount_cr*-1,tran_amount_db),tran_amount_db),0) END) YTD_tranAmountDB,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE DECODE(TO_CHAR(TRAN_AUDIT_DATE,'YYYY'),TO_CHAR(SOC_WCAL_PRIMARY_DATE,'YYYY'),NVL((DECODE(SIGN(NVL(tran_amount_cr,0)),-1,0,tran_amount_cr)),0),0) END) YTD_tranAmountCR,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE DECODE(TO_CHAR(TRAN_AUDIT_DATE,'YYYY'),TO_CHAR(SOC_WCAL_PRIMARY_DATE,'YYYY'),DECODE(NVL(tran_bal_int_db,0),0,
DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,tran_bal_int_cr*-1,tran_bal_int_db),tran_bal_int_db),0) END) YTD_tranAmountIntDB,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN 0 ELSE DECODE(TO_CHAR(TRAN_AUDIT_DATE,'YYYY'),TO_CHAR(SOC_WCAL_PRIMARY_DATE,'YYYY'),NVL((DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,0,tran_bal_int_cr)),0),0) END) YTD_tranAmountIntCR,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN DECODE(TO_CHAR(TRAN_AUDIT_DATE,'YYYY'),TO_CHAR(SOC_WCAL_PRIMARY_DATE,'YYYY'),DECODE(NVL(tran_bal_int_db,0),0,
DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,tran_bal_int_cr*-1,tran_bal_int_db),tran_bal_int_db),0) ELSE 0 END) YTD_ACItranAmountIntDB,
SUM(CASE WHEN TRANS_BAL_OS = '0'
AND TRANS_FOR_INT_GROSS = 'C' THEN DECODE(TO_CHAR(TRAN_AUDIT_DATE,'YYYY'),TO_CHAR(SOC_WCAL_PRIMARY_DATE,'YYYY'),NVL((DECODE(SIGN(NVL(tran_bal_int_cr,0)),-1,0,tran_bal_int_cr)),0),0) ELSE 0 END) YTD_ACItranAmountIntCR
FROM transaction_types, transactions t1, societies
WHERE t1.tran_audit_date > TO_DATE ('31-DEC-2009', 'DD-MON-YYYY')
AND (trans_bal_os IN ('1', '2') OR (TRANS_BAL_OS = '0' AND TRANS_FOR_INT_GROSS = 'C'))
AND trans_code = decode(t1.tran_trans_code,'SC ','SC',t1.tran_trans_code)
AND trans_soc_seqno = t1.tran_soc_seqno
GROUP BY t1.tran_account_no, t1.tran_subacc_no, t1.tran_soc_seqno)
SELECT q1.acc_account_no,
q1.acc_subacc_no,
q1.acc_soc_seqno,
q1.orig_source,
q1.acc_gact_type,
q1.acc_incep_date,
q1.acc_closure_date,
nvl(q2.number_of_trans,0) number_of_trans,
start_bal,
end_bal,
nvl(end_bal,0) - nvl(start_bal,0) balance_movement,
(nvl(TranAmountDB,0) + nvl(TranAmountIntDB,0) - nvl(TranAmountCR,0) - nvl(TranAmountIntCR,0)) *
CASE WHEN q1.acc_gact_type IN ('M','I','L','SU') THEN 1 ELSE -1 END transactions_movement,
(nvl(end_bal,0) - nvl(start_bal,0)) -
((nvl(TranAmountDB,0) + nvl(TranAmountIntDB,0) - nvl(TranAmountCR,0) - nvl(TranAmountIntCR,0)) *
CASE WHEN q1.acc_gact_type IN ('M','I','L','SU') THEN 1 ELSE -1 END) MisBalance,
q1.acc_balance_bfwd,
nvl(end_bal,0) - nvl(q1.acc_balance_bfwd,0) YTD_balance_movement,
(nvl(YTD_TranAmountDB,0) + nvl(YTD_TranAmountIntDB,0) - nvl(YTD_TranAmountCR,0) - nvl(YTD_TranAmountIntCR,0)) *
CASE WHEN q1.acc_gact_type IN ('M','I','L','SU') THEN 1 ELSE -1 END YTD_transactions_movement,
nvl(end_bal,0) - nvl(q1.acc_balance_bfwd,0) -
((nvl(YTD_TranAmountDB,0) + nvl(YTD_TranAmountIntDB,0) - nvl(YTD_TranAmountCR,0) - nvl(YTD_TranAmountIntCR,0)) *
CASE WHEN q1.acc_gact_type IN ('M','I','L','SU') THEN 1 ELSE -1 END) YTD_MisBalance,
nvl(q2.number_of_ACI_trans,0) number_of_ACI_trans,
nvl(ACITranAmountIntDB,0)-nvl(ACITranAmountIntCR,0) *
CASE WHEN q1.acc_gact_type IN ('M','I','L','SU') THEN 1 ELSE -1 END ACI_transactions_movement,
nvl(YTD_ACITranAmountIntDB,0)-nvl(YTD_ACITranAmountIntCR,0) *
CASE WHEN q1.acc_gact_type IN ('M','I','L','SU') THEN 1 ELSE -1 END YTDACI_transactions_movement
FROM q1, q2
WHERE q1.acc_account_no = q2.tran_account_no(+)
AND q1.acc_subacc_no = q2.tran_subacc_no(+)
AND q1.acc_soc_seqno = q2.tran_soc_seqno(+))
WHERE balance_movement <> transactions_movement or YTD_balance_movement <> YTD_transactions_movement


**************************
table are accounts is 5.5 million
transaction is 160 million and
other table have very few records
thanks in advance.

Server busy error while opening a webpage

Rahesh, August 25, 2011 - 5:51 am UTC

Hi tom,
In our application, when i click a link to open next page, its taking more time to open and returned Server is busy error. The below query is used to open that page.


SELECT DISTINCT v.ctgry_id,v.ctgry_dscrptn) AS ctgry_dscrptn
FROM view1 v
WHERE v.prt_id = 2
AND cntrct_id NOT IN
(SELECT a.cntrct_id FROM cntrct a,accnt b
WHERE a.acc_id = b.acc_id AND b.prt_id = 2
AND SYSDATE BETWEEN b.prt_eff_date AND b.prt_exp_date )


When I tested the above query in backend its retrieved the records around 400 sec's. I thought it might be a reason to show the Server busy error in front end.

Just i changed the query using NOT EXISTS like below.

SELECT DISTINCT v.ctgry_id,v.ctgry_dscrptn) AS ctgry_dscrptn
FROM view1 v
WHERE v.prt_id = 2
AND NOT EXISTS
(SELECT 'X' FROM cntrct a,accnt b
WHERE a.acc_id = b.acc_id AND b.prt_id = 2
AND a.cntrct_id = v.cntrct_id
AND SYSDATE BETWEEN b.prt_eff_date AND b.prt_exp_date )

Its retrieved the records in 26 sec's in backend production database. But in the screen(frontend) its still taking more time to display the next page and showed Server busy error.

Can you tell why this is not used in frontend?

Thanks.

Direct Path Read in AWR

Karan, September 12, 2011 - 12:12 am UTC

Dear Tom,

My database has just been migrated to Oracle 11g from Oracle 10g. During load testing, the AWR shows that 75% DB time in wait events is due to direct path read. This has come up now after migration. We have identified a table which has a select statement with 1.2 million rows and a FTS occurs on it. This table cannot have a "where clause" due to application reasons so a full table scan is imminent.

According to my AWR Advisory PGA/SGA sizing is sufficient (max_memory_target=10GB). How can i reduce time taken to execute this query.

Thanks
Tom Kyte
September 12, 2011 - 8:31 am UTC

you can test disabling the direct path read for this query to see if getting it from the cache is better for you.

http://dioncho.wordpress.com/2009/07/21/disabling-direct-path-read-for-the-serial-full-table-scan-11g/

Although - I'd be looking at why I needed to scan 1.2 million rows frequently.

Nathan Marston, September 13, 2011 - 11:03 pm UTC

Apologies for jumping into the conversation, but this sounds like a very "weird" scenario. Any bit of SQL I think of that matches the description above sounds "wrong" in some way.

Can you post a copy of the SQL, and also can you say roughly how many rows the query itself returns?

Join vs Exists

Praveen Ray, September 29, 2011 - 7:21 am UTC

Hi Tom,

I have a query like:

select distinct t1.xid from tab1 t1, tab2 t2
where t1.xid = t2.xid and t2.col in ('X1','Y1')
union
select distinct t1.xid from tab1 t1, tab2 t2
where t1.xid = t2.xid and t2.col in ('X2','Y2');

Q1. Removing the DISTINCTs
Q2. Using EXISTS for table tab2 in place of a join:

select distinct t1.xid from tab1 t1 --, tab2 t2
where exists (select 1 from tab2 t2 where t1.xid = t2.xid and t2.col in ('X1','Y1'))
union
select distinct t1.xid from tab1 t1 --, tab2 t2
where exists (select 1 from tab2 t2 where t1.xid = t2.xid and t2.col in ('X2','Y2'));


For both the above cases, I didn't see any change in overall cost. I need your comments on these two scenarios. Thanks.

Ray
Tom Kyte
September 29, 2011 - 8:00 am UTC

select distinct ...
union
select distinct ...

is redundant beyond belief :)

A union B is really distinct( A + B ), there is already a distinct there.

But that is OK because the optimizer would have removed the redundant distincts for you already.


and I fail to see what this query is anymore than


select distinct t1.xid from tab1 t1, tab2 t2
where t1.xid = t2.xid and t2.col in ('X1','Y1', 'X2', 'Y2')

or


select xid from tab1 where xid in (select xid from tab2 where col in ('x1','y1','x2','y2' );


A reader, September 29, 2011 - 5:28 pm UTC

Hello Sir,

We have perfomance issue with below query written by our senior developer

select *
from Tabl1 x Left Join Table2 y
on x.id=y.id and y.col1='ACCOUNT'
Where x.col1='ABC' and substr(y.code,18,2)='00'

both table have million of records

Can you please help with this?

Thanks


Tom Kyte
September 30, 2011 - 6:09 pm UTC

well, you don't tell me

a) what the schema looks like
b) how many records x.col1 = 'ABC' returns
c) how many records y.col1 = 'ACCOUNT' will filter down to
d) or substr() = '00' will as well
e) how big the table is (millions of records is pretty darn obscure. 1,000,000 records could be 1mb or 1tb - no clue)
f) how fast it is running
g) how fast you think it should run
h) how many records it will return
i) etc.

JOIN vs EXISTS

Praveen Ray, September 29, 2011 - 11:56 pm UTC

Sorry Tom.

Actually, there were more conditions which I had removed for clarity but that only caused obscurity. But you never fail to ignore inefficient code :)
Say, for example:

select distinct t1.xid from tab1 t1, tab2 t2 where t1.xid = t2.xid and t2.col in ('X1','Y1') and <cond1 on tab1>
union
select distinct t1.xid from tab1 t1, tab2 t2 where t1.xid = t2.xid and t2.col in ('X1','Y1') and <cond2 on tab1>;

That means the only purpose to include TAB2 is to check whether T2.COL has values ('X1','Y1'). Or even better consider the following:

select * from tab1 t1, tab2 t2 where t1.xid = t2.xid and t2.col in ('X1','Y1');
-or-
select * from tab1 t1 --, tab2 t2
-- where t1.xid = t2.xid and t2.col in ('X1','Y1');
where exists (select 1 from tab2 t2 where t1.xid = t2.xid and t2.col in ('X1','Y1'));

Here, I wanted your comment, whcih you suggest better to use (JOIN or EXISTS) as both the above queries have same cost, performance-wise. I have a habbit of using EXISTS if I have to check whether record exists in table X.

Ray
Tom Kyte
September 30, 2011 - 6:17 pm UTC

I would use IN myself, that is my usual preferred syntax. Followed by EXISTS.

I would not join, since you are thinking you have to distinct the data - the join must be to a one to many relation and you didn't want the "many"

I wrote about this not too long ago
http://www.oracle.com/technetwork/issue-archive/2006/06-may/o36asktom-099107.html

Jess, October 03, 2011 - 10:52 am UTC

Hi Tom,

I've recently inherited this query for maintenance:

select dim_calendar.day_dt order_date, dim_time.time_dt order_time, fact_transactions.quantity, 
       fact_transactions.price, dim_customers_tier1.name tier1_name, dim_customers_tier2.name tier2_name, 
       case when dim_customers_tier1.ext_id_type='R' then 'R' else dim_customers_tier1.ext_id_type end tier1_type, 
       case when dim_customers_tier2.ext_id_type='R' then 'R' else dim_customers_tier2.ext_id_type end tier2_type, 
       dim_products.secondary_name, dim_key_accts.acct_label, 
       fact_transactions.reference_no, dim_customers_tier0.name tier0_name, 
       dim_customers_tier0.ext_id, dim_attributes.exchanged, dim_attributes.purch_type, dim_products.product_name, 
       dim_payment.card_type, dim_customers_tier1.ext_id, dim_customers_tier2.ext_id, dim_location.location_name, 
       dim_products.ext_id_type, dim_products.ext_id, dim_products.product_type, dim_products.secondary_ext_id, 
       case when dim_products.ext_id_type in ('Q', 'Z') then dim_products.secondary_manuf else dim_products.manuf end manuf,                                                                   
       dim_products.validity_date, dim_products.exch_type, dim_products.category_code, 
       case when dim_products.product_order_type <> 'L' then to_number(decode(dim_products.price, 0, null, dim_products.price)) 
                                   else dim_products.price end price,         
       case when dim_products.ext_id_type = 'O' then null else dim_products.man_code end man_code, 
       dim_products.price_code, fact_transactions.tax_perc, fact_transactions.ref_no, dim_customers_type.name type_name, 
       fact_transactions.trx_date, dim_attributes.isvalid
       from (
             (
               (
                 (   
                   (   
                     (
                        (        
                           (         
                             (
                               (fact_transactions inner join dim_attributes dim_attributes on fact_transactions.attribute_key = dim_attributes.attribute_key) 
                              inner join dim_time on dim_time.skey_time = fact_transactions.time_key) 
                            inner join dim_location on dim_location.location_key = fact_transactions.location_key) 
                         inner join dim_calendar on dim_calendar.calendar_key = fact_transactions.calendar_key) 
                      inner join dim_customers dim_customers_type on dim_customers_type.customer_key = fact_transactions.customer_key_type) 
                    inner join dim_customers dim_customers_tier0 on dim_customers_tier0.customer_key = fact_transactions.customer_key_tier0) 
                  inner join dim_customers dim_customers_tier2 on dim_customers_tier2.customer_key = fact_transactions.customer_key_tier2) 
                inner join dim_customers dim_customers_tier1 on dim_customers_tier1.customer_key = fact_transactions.customer_key_tier1) 
              inner join dim_products on dim_products.product_key = fact_transactions.product_key) 
            inner join dim_payment on dim_payment.payment_key = fact_transactions.payment_key) 
          left outer join dim_key_accts  on fact_transactions.customer_key_tier0=dim_key_accts.customer_key_tier0 
              and fact_transactions.customer_key_kacct=dim_key_accts.customer_key_kacct 
  where fact_transactions.trans_date between to_date('2011-09-01 00:00:00', 'YYYY-MM-DD HH24:MI:SS') 
                                         and to_date('2011-09-01 23:59:59', 'YYYY-MM-DD HH24:MI:SS') 
    and dim_customers_tier0.customer_code in ('XUWSRYZ7643') and dim_attributes.current_state <> 'REMOVED' 
    and (dim_products.category = 'Q') 
    and dim_products.validity_date between to_date('1900-01-01', 'YYYY-MM-DD') and to_date('9999-12-31', 'YYYY-MM-DD') 
    and fact_transactions.current = 'Y' and dim_products.current = 'Y' 
    and dim_attributes.xfer = 'N'
 order by order_date asc nulls first, order_time asc nulls first;
 


It is extremely slow, and I am trying my best to tune it.
The searches are done on CUSTOMER_CODE, sometimes more than one at a time.

I've tried removing 'validity date' since it's not doing much, as well as trying to slice it apart into sub-queries in hopes of limiting the set each time.

Current indexing is this:

fact_transactions:
customer_key_tier1
time_key
trans_date, transaction_id
product_key
current
customer_key_tier2
location_key
customer_key_kacct
customer_key_type
attribute_key
customer_key_tier0
calendar_key
payment_key


dim_products:
product_order_type
product_key
category
current

dim_customers:
ext_id_type
customer_code
ext_id

Transaction table has about 20M a day (partitioned), products and customers are not partitioned and are 15M and 3M each respectively.

Is there anything you could suggest to speed it up?

The query plan at its best is
-----------------------------------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                                        | Name                           | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     | Pstart| Pstop |
-----------------------------------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                                 |                                |  7628 |    18M|       | 19757   (4)| 00:03:58 |       |       |
|   1 |  TEMP TABLE TRANSFORMATION                       |                                |       |       |       |            |          |       |       |
|   2 |   LOAD AS SELECT                                 | SYS_TEMP_0FD9D6659_F42ADB19    |       |       |       |            |          |       |       |
|   3 |    TABLE ACCESS BY INDEX ROWID                   | DIM_CUSTOMERS                  |     2 |   104 |       |     5   (0)| 00:00:01 |       |       |
|*  4 |     INDEX RANGE SCAN                             | BIN$q+1hispvI/vgRAAhKB7VsA==$0 |     2 |       |       |     3   (0)| 00:00:01 |       |       |
|   5 |   SORT ORDER BY                                  |                                |  7628 |    18M|    19M| 19752   (4)| 00:03:58 |       |       |
|*  6 |    HASH JOIN                                     |                                |  7628 |    18M|       | 19751   (4)| 00:03:58 |       |       |
|*  7 |     HASH JOIN                                    |                                |  7599 |    18M|       | 11936   (4)| 00:02:24 |       |       |
|*  8 |      TABLE ACCESS BY INDEX ROWID                 | DIM_PRODUCTS                   |     1 |   143 |       |     4   (0)| 00:00:01 |       |       |
|   9 |       NESTED LOOPS                               |                                |  7570 |    17M|       |  4121   (1)| 00:00:50 |       |       |
|  10 |        NESTED LOOPS                              |                                |  5853 |    12M|       |  1515   (1)| 00:00:19 |       |       |
|* 11 |         HASH JOIN                                |                                |  5830 |    12M|       |   216   (5)| 00:00:03 |       |       |
|  12 |          TABLE ACCESS FULL                       | DIM_TIME                       | 86400 |  1181K|       |    77   (6)| 00:00:01 |       |       |
|* 13 |          HASH JOIN                               |                                |  5830 |    12M|       |   138   (4)| 00:00:02 |       |       |
|  14 |           TABLE ACCESS FULL                      | DIM_CALENDAR                   |  7305 |    99K|       |    14   (0)| 00:00:01 |       |       |
|* 15 |           HASH JOIN                              |                                |  5830 |    12M|       |   123   (4)| 00:00:02 |       |       |
|  16 |            TABLE ACCESS FULL                     | DIM_LOCATION                   |  2223 | 33345 |       |    12   (0)| 00:00:01 |       |       |
|* 17 |            HASH JOIN                             |                                |  5830 |    12M|       |   111   (4)| 00:00:02 |       |       |
|  18 |             TABLE ACCESS FULL                    | DIM_PAYMENT                    |   197 |  1576 |       |     3   (0)| 00:00:01 |       |       |
|* 19 |             HASH JOIN                            |                                |  5830 |    12M|       |   107   (3)| 00:00:02 |       |       |
|* 20 |              TABLE ACCESS FULL                   | DIM_ATTRIBUTES                 |    64 |  3264 |       |     3   (0)| 00:00:01 |       |       |
|* 21 |              HASH JOIN RIGHT OUTER               |                                |  5830 |    12M|       |   103   (2)| 00:00:02 |       |       |
|  22 |               TABLE ACCESS FULL                  | DIM_KEY_ACCTS                  |     1 |  2028 |       |     2   (0)| 00:00:01 |       |       |
|* 23 |               HASH JOIN                          |                                |  5830 |   865K|       |   101   (2)| 00:00:02 |       |       |
|  24 |                TABLE ACCESS FULL                 | SYS_TEMP_0FD9D6659_F42ADB19    |     2 |    80 |       |     2   (0)| 00:00:01 |       |       |
|  25 |                PARTITION RANGE SINGLE            |                                |  5830 |   637K|       |    98   (2)| 00:00:02 |   794 |   794 |
|* 26 |                 TABLE ACCESS BY LOCAL INDEX ROWID| FACT_TRANSACTIONS              |  5830 |   637K|       |    98   (2)| 00:00:02 |   794 |   794 |
|  27 |                  BITMAP CONVERSION TO ROWIDS     |                                |       |       |       |            |          |       |       |
|  28 |                   BITMAP AND                     |                                |       |       |       |            |          |       |       |
|  29 |                    BITMAP MERGE                  |                                |       |       |       |            |          |       |       |
|  30 |                     BITMAP KEY ITERATION         |                                |       |       |       |            |          |       |       |
|  31 |                      TABLE ACCESS FULL           | SYS_TEMP_0FD9D6659_F42ADB19    |     1 |    13 |       |     2   (0)| 00:00:01 |       |       |
|* 32 |                      BITMAP INDEX RANGE SCAN     | FACT_TRANS_CUSTOMER_KEY_TIER0  |       |       |       |            |          |   794 |   794 |
|  33 |                    BITMAP MERGE                  |                                |       |       |       |            |          |       |       |
|  34 |                     BITMAP KEY ITERATION         |                                |       |       |       |            |          |       |       |
|* 35 |                      TABLE ACCESS FULL           | DIM_ATTRIBUTES                 |    64 |  3264 |       |     3   (0)| 00:00:01 |       |       |
|* 36 |                      BITMAP INDEX RANGE SCAN     | FACT_TRANS_ATTRIBUTE_KEY       |       |       |       |            |          |   794 |   794 |
|* 37 |                    BITMAP INDEX SINGLE VALUE     | FACT_TRANS_CURRENT             |       |       |       |            |          |   794 |   794 |
|  38 |         TABLE ACCESS BY INDEX ROWID              | DIM_CUSTOMERS                  |     1 |    30 |       |     2   (0)| 00:00:01 |       |       |
|* 39 |          INDEX UNIQUE SCAN                       | BIN$q+1hispwI/vgRAAhKB7VsA==$0 |     1 |       |       |     1   (0)| 00:00:01 |       |       |
|* 40 |        INDEX RANGE SCAN                          | DIM_PRODUCT_PRODUCT_KEY        |     2 |       |       |     2   (0)| 00:00:01 |       |       |
|  41 |      TABLE ACCESS FULL                           | DIM_CUSTOMERS                  |  1161K|    46M|       |  7811   (5)| 00:01:34 |       |       |
|  42 |     TABLE ACCESS FULL                            | DIM_CUSTOMERS                  |  1161K|    46M|       |  7811   (5)| 00:01:34 |       |       |
-----------------------------------------------------------------------------------------------------------------------------------------------------------



Is there anything you can advise that would help this go a little faster? I have read this thread as well as a few other threads and tried to change the query based on some of the tips and suggestions but haven't gotten too far...

Thank you.
Tom Kyte
October 03, 2011 - 11:26 am UTC

can you run the query with /*+ gather_plan_statistics */ and then use dbms_xplan to dump the results. Most interested in the filters (predicate section) and the A-row/E-rows columns. see
http://jonathanlewis.wordpress.com/2006/11/09/dbms_xplan-in-10g/

Please take that output and try to make it readable in a 80 character line length (chop out things like cost, time - the step, text description of the step, a-rows/e-rows are most important)

As I look at the above plan, it looks like it should be pretty darn fast, so we must be getting some estimates off.

Jess, October 04, 2011 - 3:49 pm UTC

Hi Tom,

Thank you for replying. Something is DEFINITELY off....

I have run the query with with /*+ gather_plan_statistics */ in 2 environments: our performance environment and production. Performance is almost a size of production--about a week or two less of data, so normally we expect results to be the same. (Doubly so because customer and product tables are pretty stable, and transactions are partitioned by date, so even though the table is larger in production, that particular day would be comparable).

My session is set to dump out the first 50 rows and stop.

In performance environment, I get the 50 rows in 55 seconds.
select * from table(dbms_xplan.display_cursor('zg65d8htnwv01',null,'ALLSTATS LAST')); returns the following.

--------------------------------------------------------------------------------
Id|Operation |Name |Srts|ERws|ARows|Bufrs
--------------------------------------------------------------------------------
0|SELECT STATEMENT | | 1 | | 50 |8847K
1| TEMP TABLE TRANSFORMATION | | 1 | | 50 |8847K
2| LOAD AS SELECT | | 1 | | 1 | 71
3| TABLE ACCESS BY INDEX ROWID |DIM_CUSTOMERS | 1 | 4| 64 | 67
* 4| INDEX RANGE SCAN |DCUST_CSTCODE | 1 | 4| 64 | 3
5| SORT ORDER BY | | 1 |7494| 50 |8847K
* 6| TABLE ACCESS BY INDEX ROWID |DIM_PRODUCTS | 1 | 2| 655K|8847K
7| NESTED LOOPS | | 1 |7494|4323K|5287K
* 8| HASH JOIN RIGHT OUTER | | 1 |4794| 655K|3974K
9| TABLE ACCESS FULL |DIM_KEY_ACCTS | 1 | 1| 0 | 3
*10| HASH JOIN | | 1 |4794| 655K|3974K
11| TABLE ACCESS FULL |DIM_CALENDAR | 1 |4749|4749 | 10
*12| HASH JOIN | | 1 |4794| 655K|3974K
*13| HASH JOIN | | 1 |4794| 655K|3973K
14| TABLE ACCESS FULL |DIM_LOCATION | 1 | 984| 984 | 30
*15| HASH JOIN | | 1 |4794| 655K|3973K
16| TABLE ACCESS FULL |DIM_PAYMENT | 1 | 202| 202 | 10
17| NESTED LOOPS | | 1 |4794| 655K|3973K
18| NESTED LOOPS | | 1 |4792| 655K|2662K
19| NESTED LOOPS | | 1 |4790| 655K|1350K
*20| HASH JOIN | | 1 |4788| 655K|38993
21| TABLE ACCESS FULL |SYS_TEMP_0FD9D| 1 | 4| 64 | 6
*22| HASH JOIN | | 1 |4788| 655K|38987
*23| TABLE ACCESS FULL |DIM_ATTRIBUTES| 1 | 64| 64 | 8
24| PARTITION RANGE SINGLE | | 1 |4788| 655K|38979
*25| TBLACC BYLCAL IDXROWID |F_TRANSACTIONS| 1 |4788| 655K|38979
26| BITMAP CONV'N TOROWIDS| | 1 | | 655K| 548
27| BITMAP AND | | 1 | | 14 | 548
28| BITMAP MERGE | | 1 | | 15 | 155
29| BITMAP KEY ITERAT'N| | 1 | | 43 | 155
30| TABLE ACCESS FULL |SYS_TEMP_0FD9D| 1 | 1| 64 | 3
*31| BTMAP IDX RNGESCAN|FTX_CSTKYTIER0| 64 | | 43 | 152
32| BITMAP MERGE | | 1 | | 53 | 334
33| BTMAP KEY ITERATION| | 1 | | 355 | 334
*34| TABLE ACCESS FULL |DIM_ATTRIBUTES| 1 | 64| 64 | 8
*35| BTMAP IDX RNGESCAN|FTRANS_ATR_KEY| 64 | | 355 | 326
*36| BTMAP IDX SNGL VALUE|FTRANS_ATR_CUR| 1 | | 108 | 59
37| TABLE ACCESS BY IDX ROWID |DIM_CUSTOMERS |655K| 1| 655K|1311K
*38| INDEX UNIQUE SCAN |DIM_CUST_PK |655K| 1| 655K| 655K
39| TABLE ACCESS BY INDEX ROWID|DIM_CUSTOMERS |655K| 1| 655K|1311K
*40| INDEX UNIQUE SCAN |DIM_CUST_PK |655K| 1| 655K| 655K
41| TABLE ACCESS BY INDEX ROWID |DIM_CUSTOMERS |655K| 1| 655K|1311K
*42| INDEX UNIQUE SCAN |DIM_CUST_PK |655K| 1| 655K| 655K
43| TABLE ACCESS FULL |DIM_TIME | 1 | 85K|86400| 95
*44| INDEX RANGE SCAN |DIMPRD_PRDKEY |655K| 3|3667K|1313K
--------------------------------------------------------------------------------


Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("DIM_CUSTOMERS_TIER0"."CUSTOMER_CODE"='XUWSRYZ7643')
6 - filter(("DIM_PRODUCTS"."CURRENT"='Y' AND
"DIM_PRODUCTS"."VALIDITY_DATE">=TO_DATE(' 1900-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
"DIM_PRODUCTS"."VALIDITY_DATE"<=TO_DATE(' 9999-12-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))
8 - access("FACT_TRANSACTIONS"."CUSTOMER_KEY_KACCT"="DIM_KEY_ACCTS"."CUSTOMER_KEY_KACCT" AND
"FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0"="DIM_KEY_ACCTS"."CUSTOMER_KEY_TIER0")
10 - access("DIM_CALENDAR"."CALENDAR_KEY"="FACT_TRANSACTIONS"."CALENDAR_KEY")
12 - access("DIM_TIME"."SKEY_TIME"="FACT_TRANSACTIONS"."TIME_KEY")
13 - access("DIM_LOCATION"."LOCATION_KEY"="FACT_TRANSACTIONS"."LOCATION_KEY")
15 - access("DIM_PAYMENT"."PAYMENT_KEY"="FACT_TRANSACTIONS"."PAYMENT_KEY")
20 - access("C0"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER1")
22 - access("FACT_TRANSACTIONS"."ATTRIBUTE_KEY"="DIM_ATTRIBUTES"."ATTRIBUTE_KEY")
23 - filter(("DIM_ATTRIBUTES"."XFER"='N' AND "DIM_ATTRIBUTES"."TRX_STATUS"<>'REMOVED'))
25 - filter("FACT_TRANSACTIONS"."TRX_TRADE_DATE_TIME"<=TO_DATE(' 2011-09-01 23:59:59', 'syyyy-mm-dd hh24:mi:ss'))
31 - access("FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER1"="C0")
34 - filter(("DIM_ATTRIBUTES"."XFER"='N' AND "D_ZDWH_TRX_ATTRIB"."CURRENT_STATE"<>'REMOVED'))
35 - access("FACT_TRANSACTIONS"."ATTRIBUTE_KEY"="DIM_ATTRIBUTES"."ATTRIBUTE_KEY")
36 - access("FACT_TRANSACTIONS"."CURRENT"='Y')
38 - access("DIM_CUSTOMERS_TIER1"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER1")
40 - access("DIM_CUSTOMERS_TIER2"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER2")
42 - access("DIM_CUSTOMERS_TYPE"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TYPE")
44 - access("DIM_PRODUCTS"."PRODUCT_KEY"="FACT_TRANSACTIONS"."PRODUCT_KEY")

----------

In production, I get the 50 rows in 700 seconds.
select * from table(dbms_xplan.display_cursor.. returns something quite odd:

--------------------------------------------------------------------------------
| Id|Operation |Name |ERws|OMem |1Mem
--------------------------------------------------------------------------------
| 0|SELECT STATEMENT | | | |
| 1| SORT ORDER BY | | 1|73728|73728
|* 2| HASH JOIN OUTER | | 1| 240M|8576K
|* 3| TABLE ACCESS BY INDEX ROWID |DIM_PRODUCTS | 1| |
| 4| NESTED LOOPS | | 1| |
| 5| NESTED LOOPS | | 1| |
| 6| NESTED LOOPS | | 1| |
| 7| NESTED LOOPS | | 1| |
| 8| NESTED LOOPS | | 1| |
| 9| NESTED LOOPS | | 1| |
| 10| NESTED LOOPS | | 1| |
| 11| NESTED LOOPS | | 1| |
| 12| NESTED LOOPS | | 1| |
| 13| NESTED LOOPS | | 1| |
| 14| PARTITION RANGE SINGLE | | 1| |
|*15| TABLE ACC BYLOCIDX RWID|F_TRANSACTIONS | 1| |
|*16| INDEX RANGE SCAN |FTXNS_CALKEY_TRXNID| 1| |
|*17| TABLE ACCESS BYIDX ROWID|DIM_PARTIES | 1| |
|*18| INDEX UNIQUE SCAN |DIM_PARTIES_PK | 1| |
| 19| TABLE ACCESS BY IDX ROWID|DIM_PARTIES | 1| |
|*20| INDEX UNIQUE SCAN |DIM_PARTIES_PK | 1| |
| 21| TABLE ACCESS BY IDX ROWID |DIM_PARTIES | 1| |
|*22| INDEX UNIQUE SCAN |DIM_PARTIES_PK | 1| |
| 23| TABLE ACCESS BY INDEX ROWID|DIM_PARTIES | 1| |
|*24| INDEX UNIQUE SCAN |DIM_PARTIES_PK | 1| |
|*25| TABLE ACCESS BY INDEX ROWID |DIM_ATTRIBUTES | 1| |
|*26| INDEX UNIQUE SCAN |DIM_ATTR_KEY | 1| |
| 27| TABLE ACCESS BY INDEX ROWID |DIM_PAYMENT | 1| |
|*28| INDEX UNIQUE SCAN |DIM_PMNT_KEY | 1| |
| 29| TABLE ACCESS BY INDEX ROWID |DIM_LOCATION | 1| |
|*30| INDEX UNIQUE SCAN |DIM_LOCATN_KEY | 1| |
| 31| TABLE ACCESS BY INDEX ROWID |DIM_TIME | 1| |
|*32| INDEX UNIQUE SCAN |DIM_TIME_KEY | 1| |
| 33| TABLE ACCESS BY INDEX ROWID |DIM_CALENDDAR | 1| |
|*34| INDEX UNIQUE SCAN |DIM_CAL_KEY | 1| |
|*35| INDEX RANGE SCAN |DIMPRD_PRDKEY | 2| |
| 36| TABLE ACCESS FULL |DIM_KEY_ACCTS | 1| |
--------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - access("FACT_TRANSACTIONS"."CUSTOMER_KEY_KACCT"="DIM_KEY_ACCTS"."CUSTOMER_KEY_KACCT" AND
"FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0"="DIM_KEY_ACCTS"."CUSTOMER_KEY_TIER0")
3 - filter(("DIM_PRODUCTS"."CURRENT"='Y' AND
"DIM_PRODUCTS"."VALIDITY_DATE">=TO_DATE(' 1900-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
"DIM_PRODUCTS"."VALIDITY_DATE"<=TO_DATE(' 9999-12-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))
15 - access("FACT_TRANSACTIONS"."CURRENT"='Y')
16 - access("F_ZMAD_TRANSACTIONS"."TRX_TRADE_DATE_TIME">=TO_DATE(' 2011-09-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
"F_ZMAD_TRANSACTIONS"."TRX_TRADE_DATE_TIME"<=TO_DATE(' 2011-09-01 23:59:59', 'syyyy-mm-dd hh24:mi:ss'))
17 - access("DIM_CUSTOMERS_TIER0"."CUSTOMER_CODE"='XUWSRYZ7643')
18 - access("DIM_CUSTOMERS_TIER1"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0")
20 - access("DIM_CUSTOMERS_TIER1"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER1")
22 - access("DIM_CUSTOMERS_TIER2"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER2")
24 - access("DIM_CUSTOMERS_TYPE"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TYPE")
25 - filter(("DIM_ATTRIBUTES"."XFER"='N' AND "DIM_ATTRIBUTES"."TRX_STATUS"<>'REMOVED'))
26 - access("FACT_TRANSACTIONS"."ATTRIBUTE_KEY"="DIM_ATTRIBUTES"."ATTRIBUTE_KEY")
28 - access("DIM_PAYMENT"."PAYMENT_KEY"="FACT_TRANSACTIONS"."PAYMENT_KEY")
30 - access("DIM_LOCATION"."LOCATION_KEY"="FACT_TRANSACTIONS"."LOCATION_KEY")
32 - access("DIM_TIME"."SKEY_TIME"="FACT_TRANSACTIONS"."TIME_KEY")
34 - access("DIM_CALENDAR"."CALENDAR_KEY"="FACT_TRANSACTIONS"."CALENDAR_KEY")
35 - access("DIM_PRODUCTS"."PRODUCT_KEY"="FACT_TRANSACTIONS"."PRODUCT_KEY")

I don't get actual rows, only estimated. And even so, I am failing to see why it's all 1s.

Had a look at the AWR. 5% cluster waits, 59% user i/o waits, 36% cpu. Rows is at 50, and for those buffer gets are at 48M (per execution, of which there is 1), with 968K per row. Disk reads are 77K per execution, 1.5K per row.
Elapsed time is roughly 14 secs per row, CPU time is 5 secs per row. System was as quiet as it gets when I ran the queries. Execution plan in the AWR is nothing to write home about and looks reasonable (though doesn't run that way)....

Is there anything you can spot here that just screams wrong? (Strange estimated rows included)... Will try to run it again after some maintenance completes to see if I can get actual rows from production.

Slowly starting to go mental over this. Many thanks in advance....
Tom Kyte
October 04, 2011 - 3:56 pm UTC

what is your statistics_level set to in production? It should be typical or above to get these findings. It should just be left at typical (default) unless you have a really good reason not to.

Are your statistics in production REPRESENTATIVE of the data in the database?

really need the dbms_xplan output if you want me to look further.



Your performance environment - isn't one. You don't have the same or similar data in there - the plans are way different. You are wasting time testing in that environment right now, whatever you do there won't work the same in production.

Jess, October 05, 2011 - 11:23 am UTC

Hi Tom,

Thank you again for taking the interest in this, as it's doing my head in.

STATISTICS_LEVEL is set to 'TYPICAL' indeed. As for statistics being representative of the data, I thought they were, but now not too sure.

Reran the query. Took 16 minutes to complete.

select * from table(dbms_xplan.display_cursor('hi74f7jymbb93',null,'ALLSTATS LAST'));

--------------------------------------------------------------------------------------
Id|Operation |Name |Stts|ERs|ARws|Bfrs| A-Time |Reads
--------------------------------------------------------------------------------------
0|SELECT STATEMENT | | 1 | |500 | 49M|00:15:11|77826
1| SORT ORDER BY | | 1 | 1|500 | 49M|00:15:11|77826
* 2| HASH JOIN OUTER | | 1 | 1|655K| 49M|00:15:07|77826
* 3| TABLE ACCESS BY INDEX ROWID |DIM_PRODUCTS | 1 | 1|655K| 49M|00:15:05|77826
4| NESTED LOOPS | | 1 | 1| 4M| 46M|03:05:16|77650
5| NESTED LOOPS | | 1 | 1|655K| 44M|00:13:55|76558
6| NESTED LOOPS | | 1 | 1|887K| 43M|00:11:13|76556
7| NESTED LOOPS | | 1 | 1|887K| 42M|00:11:04|76429
8| NESTED LOOPS | | 1 | 1|887K| 41M|00:10:56|76425
9| NESTED LOOPS | | 1 | 1|887K| 39M|00:10:47|76422
10| NESTED LOOPS | | 1 | 1|887K| 37M|00:10:38|76421
11| NESTED LOOPS | | 1 | 1|887K| 35M|00:10:30|76410
12| NESTED LOOPS | | 1 | 1|887K| 34M|00:10:17|76351
13| NESTED LOOPS | | 1 | 1|887K| 33M|00:10:11|76350
14| PART'N RANGE SINGL| | 1 | 1| 11M| 11M|00:09:36|76211
*15| TBLAC BYLCIDX RID|F_TRANSACTIONS | 1 | 1| 11M| 11M|00:09:36|76211
*16| INDEX RANGE SCAN|FTX_CALKEYTXNID| 1 | 1| 11M| 12K|00:02:02|12714
*17| TBL ACC BYIDX RWID|DIM_CUSTOMERS | 11M| 1|887K| 22M|00:02:00| 139
*18| INDEX UNIQUE SCAN|DIM_PARTIES_PK | 11M| 1| 11M| 11M|00:01:03| 139
19| TBL ACC BYIDX ROWID|DIM_PAYMENT |887K| 1|887K|887K|00:00:06| 1
*20| INDEX UNIQUE SCAN |DIM_PAYMENT_PK |887K| 1|887K| 2 |00:00:02| 0
21| TBL ACC BY IDX ROWID|DIM_CUSTOMRS |887K| 1|887K| 2M|00:00:12| 59
*22| INDEX UNIQUE SCAN |DIM_CUSTOMRS_PK|887K| 1|887K|887K|00:00:06| 59
23| TBL ACC BY IDX ROWID |DIM_CUSTOMRS |887K| 1|887K| 2M|00:00:09| 11
*24| INDEX UNIQUE SCAN |DIM_CUSTOMRS_PK|887K| 1|887K|887K|00:00:04| 11
25| TBL ACC BY INDEX ROWID|DIM_CUSTOMRS |887K| 1|887K| 2M|00:00:09| 1
*26| INDEX UNIQUE SCAN |DIM_CUSTOMRS_PK|887K| 1|887K|887K|00:00:05| 1
27| TBL ACC BY INDEX ROWID |DIM_CALENDAR |887K| 1|887K| 2M|00:00:08| 3
*28| INDEX UNIQUE SCAN |DIM_CALENDAR_PK|887K| 1|887K|887K|00:00:04| 2
29| TBL ACCESS BY IDX ROWID |DIM_LOCATION |887K| 1|887K|887K|00:00:07| 4
*30| INDEX UNIQUE SCAN |DIM_LOCATION_PK|887K| 1|887K| 2 |00:00:02| 1
31| TBL ACCESS BY IDX ROWID |DIM_TIME |887K| 1|887K| 2M|00:00:09| 127
*32| INDEX UNIQUE SCAN |DIM_TIME_PK |887K| 1|887K|887K|00:00:05| 62
*33| TBL ACCESS BY INDEX ROWID |DIM_ATTRIBUTES |887K| 1|655K|887K|00:00:07| 2
*34| INDEX UNIQUE SCAN |DIM_ATTRIB_PK |887K| 1|887K| 2 |00:00:02| 1
*35| INDEX RANGE SCAN |DIMPRD_PRDKEY |655K| 2| 4M| 1M|00:00:23| 1092
36| TABLE ACCESS FULL |DIM_KEY_ACCTS | 1 | 1| 0 | 3 |00:00:00| 0
--------------------------------------------------------------------------------------

2 - access("FACT_TRANSACTIONS"."CUSTOMER_KEY_KACCT"="DIM_KEY_ACCTS"."CUSTOMER_KEY_KACCT" AND
"FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0"="DIM_KEY_ACCTS"."CUSTOMER_KEY_TIER0")
3 - filter(("DIM_PRODUCTS"."CURRENT"='Y' AND
"DIM_PRODUCTS"."VALIDITY_DATE">=TO_DATE('1900-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
"DIM_PRODUCTS"."VALIDITY_DATE"<=TO_DATE('9999-12-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))
15 - access("FACT_TRANSACTIONS"."CURRENT"='Y')
16 - access("FACT_TRANSACTIONS"."TRANS_DATE">=TO_DATE(' 2011-09-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND
"FACT_TRANSACTIONS"."TRANS_DATE"<=TO_DATE(' 2011-09-01 23:59:59', 'syyyy-mm-dd hh24:mi:ss'))
17 - access("DIM_CUSTOMERS_TIER0"."CUSTOMER_CODE"='XUWSRYZ7643')
18 - access("DIM_CUSTOMERS_TIER1"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0")
20 - access("DIM_PAYMENT"."PAYMENT_KEY"="FACT_TRANSACTIONS"."PAYMENT_KEY")
22 - access("DIM_CUSTOMERS_TIER1"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER1")
24 - access("DIM_CUSTOMERS_TIER2"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER2")
26 - access("DIM_CUSTOMERS_TYPE"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TYPE")
28 - access("DIM_CALENDAR"."CALENDAR_KEY"="FACT_TRANSACTIONS"."TRANS_DATE")
30 - access("DIM_LOCATION"."LOCATION_KEY"="FACT_TRANSACTIONS"."LOCATION_KEY")
32 - access("DIM_TIME"."TIME_KEY"="FACT_TRANSACTIONS"."TIME_KEY")
33 - filter(("DIM_ATTRIBUTES"."XFER"='N' AND "DIM_ATTRIBUTES"."TRX_STATUS"<>'REMOVED'))
34 - access("FACT_TRANSACTIONS"."ATTRIBUTE_KEY"="DIM_ATTRIBUTES"."ATTRIBUTE_KEY")
35 - access("DIM_PRODUCTS"."PRODUCT_KEY"="FACT_TRANSACTIONS"."PRODUCT_KEY")


So it's doing loads more work than it thinks it will. I am right in thinking this isn't something fixable with a quick hint but something that points to a larger underlying problem?

Not really sure where to go with that. Looked at the stats on dimensions. The sample_size to num_rows ratio is 100% for dim_customers and 9% for dim_products. I don't know where this discrepancy is coming from. We are running gather_database_stats_job_proc to gather for all tables/partitions changing more than 20%. Is it likely that optimiser mistakes that sample size at its low percentage for something it expects at a higher one?

Many thanks, as always...


Tom Kyte
October 05, 2011 - 12:44 pm UTC

query starts here:

*15|               TBLAC BYLCIDX RID|F_TRANSACTIONS |  1 |  1| 11M| 11M|00:09:36|76211
*16|                INDEX RANGE SCAN|FTX_CALKEYTXNID|  1 |  1| 11M| 12K|00:02:02|12714



we guessed one row, we got 11,000,000 of them. That is a problem, a big one. Looking at 15/16 we see the following access/filters:

15 - access("FACT_TRANSACTIONS"."CURRENT"='Y') 
  16 - access("FACT_TRANSACTIONS"."TRANS_DATE">=TO_DATE(' 2011-09-01 00:00:00', 
'syyyy-mm-dd hh24:mi:ss') AND
            "FACT_TRANSACTIONS"."TRANS_DATE"<=TO_DATE(' 2011-09-01 23:59:59', 
'syyyy-mm-dd hh24:mi:ss'))



Now, those predicates are so simple - we should have gotten them dead on.

I'll suspect the table FACT_TRANSACTIONS doesn't have representative statistics, in fact, it is missing the new high value on TRANS_DATE (someone loaded a ton of data and never advanced the TRANS_DATE - we think there isn't any data for September in that table...)

Just run this query:

select count(*) from fact_transactions where "FACT_TRANSACTIONS"."TRANS_DATE">=TO_DATE(' 2011-09-01 00:00:00',
'syyyy-mm-dd hh24:mi:ss') AND
"FACT_TRANSACTIONS"."TRANS_DATE"<=TO_DATE(' 2011-09-01 23:59:59',
'syyyy-mm-dd hh24:mi:ss')

and show that to the DBA - it'll have an estimate of 1 row, it'll get 11,000,000 rows - ask them if that might be a problem.... :)



We are
running gather_database_stats_job_proc to gather for all tables/partitions
changing more than 20%.


that is too simplistic. If you have a 100,000,000 table- you'd have to add more than 20,000,000 rows to it to trigger a gather. Now, if you have columns like trans_date, sequences, etc that are always advancing - think about what happens to the stats for them?


Jess, October 05, 2011 - 11:26 am UTC

P.S: I am with you on tuning SQL in the environment where it's running poorly. However, we have pretty severe access restrictions in production, so more often than not we get asked to tune in the performance environment, which is supposed to be fit for purpose :(
Tom Kyte
October 05, 2011 - 12:45 pm UTC

your performance environment needs to have a copy of the real environment restored to it is all.

Jess, October 05, 2011 - 12:09 pm UTC

(but today's results above are from production)

Jess, October 06, 2011 - 10:27 am UTC

Hi Tom,

Thank you for the feedback.

Indeed, running select count(*) from fact_transactions for 1-Sept returned as you predicted:

--------------------------------------------------------------------------
|Id|Operation |Name |Sts|ERws|ARws| Bfrs| A-Time| Rds|
--------------------------------------------------------------------------
| 0|SELECT STATEMENT | | 1| | 1 |12714|00:00:50|6299|
| 1| SORT AGGREGATE | | 1| 1| 1 |12714|00:00:50|6299|
| 2| PART'N RANGE SNGL| | 1| 1| 11M|12714|00:00:44|6299|
|*3| INDEX RANGE SCAN|FTX_CALKEYTXNID| 1| 1| 11M|12714|00:00:44|6299|
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
16 - access("FACT_TRANSACTIONS"."TRANS_DATE">=TO_DATE(' 2011-09-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "FACT_TRANSACTIONS"."TRANS_DATE"<=TO_DATE(' 2011-09-01 23:59:59', 'syyyy-mm-dd hh24:mi:ss'))

Looked at the state of stats in tab_partitions for the 1-Sep partition:
num_rows = 7,739,791
sample_size = 5,784
last_analyzed = 02-SEP-2011

select count(*) from that partition actually returns 11,130,180.

That's a ~44% increase from num_rows in the table. I would expect the stats to be more up to date, but they clearly haven't been gathered on this partition for over a month now.

With regard to not advancing the trade_date, the table is partitioned. Other partitions for subsequent trade_dates have been analysed between now and then, some multiple times.

The way the system works, we populate a new partition every day and gather stats for it. On subsequent days, we add more rows into old partitions--usually not a lot, as some belated transactions trickle in. Sometimes, it can be lots though if we don't get all the source files on time.

Given that gather_database_stats_job_proc is meant to gather stats for 20% change, what does Oracle actually compare it to? If a table has lots of rows and gets analyzed, and then a handful of rows is added every day, will stats be gathered when cumulative change surpasses 20% compared to volume on last_analysed_date or will each day only be compared to previous day (and if the latter, where does it store that info)?

Spoke to the DBAs about it, who said it was unclear why this is happening, so not really a lot of help there. Looks like we need a different stats gathering strategy, so I will be pressing this further with them.


I picked another similarly-sized partition from transactions table that does have its stats up to date and reran the hinted query against that date. It runs in 10 minutes, pretty much the same time as the one against the stale date.

------------------------------------------------------------------------------------------------
Id|Operation |Name |Sts|ERws |ARws |Bfrs| A-Time | Rds|Wrts
------------------------------------------------------------------------------------------------
0|SELECT STATEMENT | | 1| | 500 |268K|00:04:08|143K|2653
1| TEMP TABLE TRANSFORMATION | | 1| | 500 |268K|00:04:08|143K|2653
2| LOAD AS SELECT | | 1| | 1 | 76 |00:00:00| 1 | 1
3| TABLE ACCESS BY INDEX ROWID |DIM_CUSTOMRS | 1| 1 | 69 | 72 |00:00:00| 1 | 0
* 4| INDEX RANGE SCAN |DIMCUST_CUSTCODE| 1| 1 | 69 | 3 |00:00:00| 1 | 0
5| SORT ORDER BY | | 1| 179K| 500 |268K|00:04:08|143K|2652
* 6| HASH JOIN | | 1| 179K| 766K|268K|00:06:00|143K|2652
* 7| HASH JOIN RIGHT OUTER | | 1| 150K| 766K| 88K|00:01:06| 34K|2652
8| TABLE ACCESS FULL |DIM_KEY_ACCTS | 1| 1 | 0 | 3 |00:00:00| 0 | 0
* 9| HASH JOIN | | 1| 150K| 766K| 88K|00:01:05| 34K|2652
10| TABLE ACCESS FULL |DIM_CALENDAR | 1|4749 |4749 | 10 |00:00:00| 0 | 0
*11| HASH JOIN | | 1| 150K| 766K| 88K|00:01:04| 34K|2652
12| TABLE ACCESS FULL |DIM_TIME | 1| 86K| 86K| 95 |00:00:00| 40 | 0
*13| HASH JOIN | | 1| 150K| 766K| 88K|00:01:02| 34K|2652
14| TABLE ACCESS FULL |DIM_LOCATION | 1| 974 | 989 | 34 |00:00:00| 27 | 0
*15| HASH JOIN | | 1| 150K| 766K| 88K|00:01:01| 34K|2652
16| TABLE ACCESS FULL |DIM_PAYMENT | 1| 202 | 204 | 10 |00:00:00| 0 | 0
*17| HASH JOIN | | 1| 150K| 766K| 88K|00:01:00| 34K|2652
*18| TABLE ACCESS FULL |DIM_ATTRIBUTES | 1| 64 | 64 | 8 |00:00:00| 0 | 0
*19| HASH JOIN | | 1| 150K| 766K| 88K|00:01:00| 34K|2652
*20| HASH JOIN | | 1| 150K| 766K| 72K|00:00:54| 33K|1470
*21| HASH JOIN | | 1| 150K| 766K| 55K|00:00:48| 32K| 0
*22| HASH JOIN | | 1| 150K| 766K| 38K|00:00:45| 32K| 0
23| TABLE ACCESS FULL |SYS_TEMP_0FD | 1| 1 | 69 | 6 |00:00:00| 1 | 0
24| PART'N RANGE SINGL | | 1| 150K| 766K| 38K|00:00:43| 32K| 0
*25| TBLAC BYLCIDX RID |F_TRANSACTIONS | 1| 150K| 766K| 38K|00:00:43| 32K| 0
26| BTMAP CONVN TORWIDS| | 1| | 766K|564 |00:00:00|170 | 0
27| BITMAP AND | | 1| | 16 |564 |00:00:01|170 | 0
28| BITMAP MERGE | | 1| | 16 |173 |00:00:00| 21 | 0
29| BTMAP KEY ITR'N | | 1| | 32 |173 |00:00:00| 21 | 0
30| TBL ACCESS FULL|SYS_TEMP_0FD | 1| 1 | 69 | 3 |00:00:00| 0 | 0
*31| BTMP IDXRNG SCN|FTX_CUSTKEYTIER0| 69| | 32 |170 |00:00:00| 21 | 0
32| BITMAP MERGE | | 1| | 35 |353 |00:00:01|112 | 0
33| BTMAP KEY ITER'N| | 1| | 215 |353 |00:00:00|112 | 0
*34| TBL ACCESS FULL|DIM_ATTRIBUTES | 1| 64 | 64 | 8 |00:00:00| 0 | 0
*35| BTMP IDXRNG SCN|F_TRANS_ATTR_KEY| 64| | 215 |345 |00:00:00|112 | 0
*36| BTMP IDX SNGL VAL|F_TRANS_ATTR_CUR| 1| | 70 | 38 |00:00:00| 37 | 0
37| TABLE ACCESS FULL |DIM_CUSTOMRS | 1|2105K|2142K| 17K|00:00:00| 0 | 0
38| TABLE ACCESS FULL |DIM_CUSTOMRS | 1|2105K|2142K| 17K|00:00:00| 0 | 0
39| TABLE ACCESS FULL |DIM_CUSTOMRS | 1|2105K|2142K| 17K|00:00:00| 0 | 0
*40| TABLE ACCESS FULL |DIM_PRODUCTS | 1|6606K|6574K|179K|00:02:04|109K| 0
------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

4 - access("DIM_CUSTOMERS_TIER0"."CUSTOMER_CODE"='XUWSRYZ7643')
6 - access("DIM_PRODUCTS"."PRODUCT_KEY"="FACT_TRANSACTIONS"."PRODUCT_KEY")
7 - access("FACT_TRANSACTIONS"."CUSTOMER_KEY_KACCT"="DIM_KEY_ACCTS"."CUSTOMER_KEY_KACCT" AND
"FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0"="DIM_KEY_ACCTS"."CUSTOMER_KEY_TIER0")
9 - access("DIM_CALENDAR"."CALENDAR_KEY"="FACT_TRANSACTIONS"."TRANS_DATE")
11 - access("DIM_TIME"."TIME_KEY"="FACT_TRANSACTIONS"."TIME_KEY")
13 - access("DIM_LOCATION"."LOCATION_KEY"="FACT_TRANSACTIONS"."LOCATION_KEY")
15 - access("DIM_PAYMENT"."PAYMENT_KEY"="FACT_TRANSACTIONS"."PAYMENT_KEY")
=>17 - access("FACT_TRANSACTIONS"."ATTRIBUTE_KEY"="DIM_ATTRIBUTES"."ATTRIBUTE_KEY")
=>18 - filter(("DIM_ATTRIBUTES"."XFER"='N' AND "DIM_ATTRIBUTES"."TRX_STATUS"<>'REMOVED'))
19 - access("DIM_CUSTOMERS_TYPE"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TYPE")
20 - access("DIM_CUSTOMERS_TIER2"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER2")
21 - access("DIM_CUSTOMERS_TIER1"."CUSTOMER_KEY"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER1")
22 - access("C0"="FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0")
25 - filter("FACT_TRANSACTIONS"."TRANS_DATE"<=TO_DATE(' 2011-10-05 23:59:59', 'syyyy-mm-dd hh24:mi:ss'))
31 - access("FACT_TRANSACTIONS"."CUSTOMER_KEY_TIER0"="C0")
=>34 - filter(("DIM_ATTRIBUTES"."XFER"='N' AND "DIM_ATTRIBUTES"."TRX_STATUS"<>'REMOVED'))
=>35 - access("FACT_TRANSACTIONS"."ATTRIBUTE_KEY"="DIM_ATTRIBUTES"."ATTRIBUTE_KEY")
36 - access("FACT_TRANSACTIONS"."CURRENT"='Y')
40 - filter(("DIM_PRODUCTS"."VALIDITY_DATE">=TO_DATE('1900-01-01 00:00:00', 'syyyy-mm-dd hh24:mi:ss') AND "DIM_PRODUCTS"."VALIDITY_DATE"<=TO_DATE('9999-12-31 00:00:00', 'syyyy-mm-dd hh24:mi:ss')))

The estimated is a fair match for actual now, but it still takes 10 minutes to complete, whereas the users are expecting this to return in one or two (and not unreasonably so). There also seem to be two passes (=>) against attribute dimension and DIM_CUSTOMERS is joined to 4 times as well, not adding to the overall happiness....

Is there any room for improvement here?

It's likely to take a while for DBAs to sort out the stats problem, and, unfortunately, this has landed on my plate to optimise NOW, so that the users can at least have some benefits in the mean time. I am going to try and rerun it with some cardinality hints perhaps and/or separating dim_customers into an inline view with no_merge...

If there is anything else you could recommend and/or suggest a stats strategy that would work given how we process data, that would be of massive help.

Thank you again for you help thus far.



Tom Kyte
October 06, 2011 - 12:27 pm UTC

last_analyzed = 02-SEP-2011


you don't have any stats about september.

You are asking for all data from september.

do you see the problem? We think there is no september data. You need to correct that.

You could

a) gather stats on the affected partitions
b) use dbms_stats.set_column_stats to tell us about the new high values so we understand that september exists.



You should be more aggressive with your stats management - you KNOW you need new stats and what partitions need them better than anyone (including an automatic piece of software)


It is likely that you want to copy last months stats onto THIS MONTH - when this month is first created - and then use dbms_stats to set new high/low values for some columns (you KNOW what those values for dates and sequences are likely to be) and then gather stats at the end of the month against the data and copy those to next month and keep on rolling along.

that is what we do for AWR for example.

Your DBA need to become a little more proactive and understanding of the stats gathering stuff - what options they have, how it works and so on..

Jess, October 06, 2011 - 12:56 pm UTC

Hi Tom,

Well, this particular day in September doesn't seem to have correct stats. Other days do. But all the same, you're right--things won't work properly until stats gathering is corrected.

Heard back from the DBAs by the way. They say partition histograms are not being collected properly, which is making the plans turn sour. They're working to resolve that.

Copying of the stats a month forward sounds like pretty nifty idea that we'll definitely need to look forward to. I'm still planning on trying to tune the query itself to do something about attributes and customers dimensions.

Thanks again, this has been unbelievably helpful.

tools of our trade

Zvi, October 07, 2011 - 6:30 pm UTC

Hi Tom,

Could you please describe the tools you currently use for tuning, testing, benchmarking, development/debugging ?

Many Thanks.

Zvi
Tom Kyte
October 08, 2011 - 6:50 am UTC

I personally do not write a ton of software these days - most of my time is filled with writing, performing seminars, working on specific customer issues, answering questions and keeping up with how things work.

So, I might not be the best for this. Also - there is the fact that I sort of specialize in SQL and PL/SQL only.

I pretty much use sqldeveloper, sqlplus, ASH, AWR and the other database tools (tkprof, real application testing, etc).

Alter view improves performance?

ranjith, October 08, 2011 - 12:57 am UTC

Hi Tom,

I have a query that selects from a view. It took 39 minutes to run.

When I issue "alter view view_name compile;" and run the same query, it takes only 31 seconds. (if I re-submit the same without alter view, it takes around 39 minutes again). Its consistently simulatable, whenever I alter view and run the query it runs fast

Do you understand whats the magic here?

My oracle version is (11.2.0.2.0)

This is the plan/statistics without alter view:


[/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>set autotrace traceonly line 9999 time on timing on
15:38:32 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>
15:38:32 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>SELECT *
15:38:32   2    FROM (SELECT sumalias.*, rownum Rno
15:38:32   3            FROM (SELECT *
15:38:32   4                    FROM (SELECT AUTH_STATUS     AS AUTHSTAT,
15:38:32   5                                 CONTRACT_STATUS AS CONSTAT,
15:38:32   6                                 CONTREFNO       AS CONREFNO,
15:38:32   7                                 PRODUCT_CODE    AS PRDCD,
15:38:32   8                                 CONTRACT_CCY    AS CONTCCY,
15:38:32   9                                 CONTRACT_AMT    AS CONTAMT,
15:38:32  10                                 USER_REF_NO     AS USEREFNO,
15:38:32  11                                 EXTERNAL_REF_NO AS EXTREFNO,
15:38:32  12                                 CUST_REF_NO     AS CUSTREFNO,
15:38:32  13                                   CUST_REF_DATE   AS CUSTREFDT,
15:38:32  14                                 CUST_TYPE       AS CUSTTYP,
15:38:32  15                                 ISSUE_DATE      AS ISSDT,
15:38:32  16                                 EXPIRY_DATE     AS EXPDT,
15:38:32  17                                 BRANCH          AS BRANCH
15:38:32  18                            FROM LCVW_FCJ_CONTRACT_SUMMARY
15:38:32  19                           WHERE MODULE_CODE = 'LC')
15:38:32  20                   WHERE UPPER(BRANCH) LIKE UPPER('ACU')) sumalias)
15:38:32  21   WHERE Rno > 0
15:38:32  22     AND Rno <= 15
15:38:32  23  /

15 rows selected.

Elapsed: 00:39:40.68

Execution Plan
----------------------------------------------------------

------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name                      | Rows  | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |                           |     1 |   130 |     7   (0)|
|*  1 |  VIEW                               |                           |     1 |   130 |     7   (0)|
|   2 |   COUNT                             |                           |       |       |            |
|   3 |    NESTED LOOPS OUTER               |                           |     1 |   179 |     5   (0)|
|   4 |     NESTED LOOPS                    |                           |     1 |   158 |     5   (0)|
|   5 |      NESTED LOOPS                   |                           |     1 |   138 |     4   (0)|
|   6 |       TABLE ACCESS BY INDEX ROWID   | CSTB_CONTRACT             |     1 |    64 |     2   (0)|
|*  7 |        INDEX RANGE SCAN             | IX04_CSTB_CONTRACT        |     1 |       |     1   (0)|
|   8 |       TABLE ACCESS BY INDEX ROWID   | LCTB_CONTRACT_MASTER      |     1 |    74 |     2   (0)|
|*  9 |        INDEX RANGE SCAN             | PK01_LCTB_CONTRACT_MASTER |     1 |       |     1   (0)|
|  10 |         SORT AGGREGATE              |                           |     1 |    20 |            |
|  11 |          FIRST ROW                  |                           |     1 |    20 |     1   (0)|
|* 12 |           INDEX RANGE SCAN (MIN/MAX)| PK01_LCTB_CONTRACT_MASTER |     1 |    20 |     1   (0)|
|* 13 |      INDEX RANGE SCAN               | PK01_LCTB_AVAILMENTS      |     1 |    20 |     1   (0)|
|  14 |       SORT AGGREGATE                |                           |     1 |    20 |            |
|  15 |        FIRST ROW                    |                           |     1 |    20 |     1   (0)|
|* 16 |         INDEX RANGE SCAN (MIN/MAX)  | PK01_LCTB_AVAILMENTS      |     1 |    20 |     1   (0)|
|* 17 |     INDEX UNIQUE SCAN               | PK01_LCTB_SHIPMENT        |     1 |    21 |     0   (0)|
------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("RNO">0 AND "RNO"<=15)
   7 - access("D"."MODULE_CODE"='LC')
       filter(UPPER("D"."BRANCH")='ACU')
   9 - access("A"."CONTRACT_REF_NO"="D"."CONTRACT_REF_NO")
       filter("A"."EVENT_SEQ_NO"= (SELECT MAX("EVENT_SEQ_NO") FROM
              FLXOSYD."LCTB_CONTRACT_MASTER" "LCTB_CONTRACT_MASTER" WHERE "EVENT_SEQ_NO"<=:B1 AND
              "CONTRACT_REF_NO"=:B2))
  12 - access("CONTRACT_REF_NO"=:B1 AND "EVENT_SEQ_NO"<=:B2)
  13 - access("B"."CONTRACT_REF_NO"="D"."CONTRACT_REF_NO")
       filter("B"."EVENT_SEQ_NO"= (SELECT MAX("EVENT_SEQ_NO") FROM FLXOSYD."LCTB_AVAILMENTS"
              "LCTB_AVAILMENTS" WHERE "EVENT_SEQ_NO"<=:B1 AND "CONTRACT_REF_NO"=:B2))
  16 - access("CONTRACT_REF_NO"=:B1 AND "EVENT_SEQ_NO"<=:B2)
  17 - access("C"."CONTRACT_REF_NO"(+)="A"."CONTRACT_REF_NO" AND
              "C"."EVENT_SEQ_NO"(+)="A"."EVENT_SEQ_NO")

Note
-----
   - 'PLAN_TABLE' is old version


Statistics
----------------------------------------------------------
       6543  recursive calls
          0  db block gets
     160442  consistent gets
     804768  physical reads
          0  redo size
       2515  bytes sent via SQL*Net to client
        524  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
         15  rows processed

16:18:13 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>


And below is with Alter view;

[/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>set autotrace traceonly line 9999 time on timing on
15:37:20 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>
15:37:20 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>alter view LCVW_FCJ_CONTRACT_SUMMARY compile;

View altered.

Elapsed: 00:00:00.05
15:37:20 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>
15:37:20 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>
15:37:20 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>SELECT *
15:37:20   2    FROM (SELECT sumalias.*, rownum Rno
15:37:20   3            FROM (SELECT *
15:37:20   4                    FROM (SELECT AUTH_STATUS     AS AUTHSTAT,
15:37:20   5                                 CONTRACT_STATUS AS CONSTAT,
15:37:20   6                                 CONTREFNO       AS CONREFNO,
15:37:20   7                                 PRODUCT_CODE    AS PRDCD,
15:37:20   8                                 CONTRACT_CCY    AS CONTCCY,
15:37:20   9                                 CONTRACT_AMT    AS CONTAMT,
15:37:20  10                                 USER_REF_NO     AS USEREFNO,
15:37:20  11                                 EXTERNAL_REF_NO AS EXTREFNO,
15:37:20  12                                 CUST_REF_NO     AS CUSTREFNO,
15:37:20  13                                   CUST_REF_DATE   AS CUSTREFDT,
15:37:20  14                                 CUST_TYPE       AS CUSTTYP,
15:37:20  15                                 ISSUE_DATE      AS ISSDT,
15:37:20  16                                 EXPIRY_DATE     AS EXPDT,
15:37:20  17                                 BRANCH          AS BRANCH
15:37:20  18                            FROM LCVW_FCJ_CONTRACT_SUMMARY
15:37:20  19                           WHERE MODULE_CODE = 'LC')
15:37:20  20                   WHERE UPPER(BRANCH) LIKE UPPER('ACU')) sumalias)
15:37:20  21   WHERE Rno > 0
15:37:20  22     AND Rno <= 15
15:37:20  23  /

15 rows selected.

Elapsed: 00:00:00.31

Execution Plan
----------------------------------------------------------

------------------------------------------------------------------------------------------------------
| Id  | Operation                           | Name                      | Rows  | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                    |                           |     1 |   130 |     7   (0)|
|*  1 |  VIEW                               |                           |     1 |   130 |     7   (0)|
|   2 |   COUNT                             |                           |       |       |            |
|   3 |    NESTED LOOPS OUTER               |                           |     1 |   179 |     5   (0)|
|   4 |     NESTED LOOPS                    |                           |     1 |   158 |     5   (0)|
|   5 |      NESTED LOOPS                   |                           |     1 |   138 |     4   (0)|
|   6 |       TABLE ACCESS BY INDEX ROWID   | CSTB_CONTRACT             |     1 |    64 |     2   (0)|
|*  7 |        INDEX RANGE SCAN             | IX04_CSTB_CONTRACT        |     1 |       |     1   (0)|
|   8 |       TABLE ACCESS BY INDEX ROWID   | LCTB_CONTRACT_MASTER      |     1 |    74 |     2   (0)|
|*  9 |        INDEX RANGE SCAN             | PK01_LCTB_CONTRACT_MASTER |     1 |       |     1   (0)|
|  10 |         SORT AGGREGATE              |                           |     1 |    20 |            |
|  11 |          FIRST ROW                  |                           |     1 |    20 |     1   (0)|
|* 12 |           INDEX RANGE SCAN (MIN/MAX)| PK01_LCTB_CONTRACT_MASTER |     1 |    20 |     1   (0)|
|* 13 |      INDEX RANGE SCAN               | PK01_LCTB_AVAILMENTS      |     1 |    20 |     1   (0)|
|  14 |       SORT AGGREGATE                |                           |     1 |    20 |            |
|  15 |        FIRST ROW                    |                           |     1 |    20 |     1   (0)|
|* 16 |         INDEX RANGE SCAN (MIN/MAX)  | PK01_LCTB_AVAILMENTS      |     1 |    20 |     1   (0)|
|* 17 |     INDEX UNIQUE SCAN               | PK01_LCTB_SHIPMENT        |     1 |    21 |     0   (0)|
------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("RNO">0 AND "RNO"<=15)
   7 - access("D"."MODULE_CODE"='LC')
       filter(UPPER("D"."BRANCH")='ACU')
   9 - access("A"."CONTRACT_REF_NO"="D"."CONTRACT_REF_NO")
       filter("A"."EVENT_SEQ_NO"= (SELECT MAX("EVENT_SEQ_NO") FROM
              FLXOSYD."LCTB_CONTRACT_MASTER" "LCTB_CONTRACT_MASTER" WHERE "EVENT_SEQ_NO"<=:B1 AND
              "CONTRACT_REF_NO"=:B2))
  12 - access("CONTRACT_REF_NO"=:B1 AND "EVENT_SEQ_NO"<=:B2)
  13 - access("B"."CONTRACT_REF_NO"="D"."CONTRACT_REF_NO")
       filter("B"."EVENT_SEQ_NO"= (SELECT MAX("EVENT_SEQ_NO") FROM FLXOSYD."LCTB_AVAILMENTS"
              "LCTB_AVAILMENTS" WHERE "EVENT_SEQ_NO"<=:B1 AND "CONTRACT_REF_NO"=:B2))
  16 - access("CONTRACT_REF_NO"=:B1 AND "EVENT_SEQ_NO"<=:B2)
  17 - access("C"."CONTRACT_REF_NO"(+)="A"."CONTRACT_REF_NO" AND
              "C"."EVENT_SEQ_NO"(+)="A"."EVENT_SEQ_NO")

Note
-----
   - 'PLAN_TABLE' is old version


Statistics
----------------------------------------------------------
          8  recursive calls
          0  db block gets
      23651  consistent gets
          0  physical reads
          0  redo size
       2629  bytes sent via SQL*Net to client
        524  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         15  rows processed

15:37:21 [/] mshkdflxsdb01vm : FLXOSYD @ OD_SD_FX>


Tom Kyte
October 08, 2011 - 6:56 am UTC

I'm pretty sure it would have gone faster all by itself.

See the drop in recursive calls - the first execution was doing a lot of something - that the second execution benefited from.

Trace it - see what the recursive calls where in the first case versus the second.

RE: Alter view improves performance?

ranjith, October 08, 2011 - 9:11 am UTC

Hi Tom,

Actually it does not tune by itself. I have tested several number of times, and it gives the same slow performance when I am running without "alter view". The moment I alter view, it runs faster for the immediate next execution. But then again it would go slow (with the recursive call route) if I type forward slash and enter.


How can alter view drop the recursive calls?

Tom Kyte
October 09, 2011 - 11:08 am UTC

if you look at the recursive sql, we might be able to figure it out. To just guess is not useful, to have some *facts* to look at would be.

so, again

Trace it - see what the recursive calls where in the first case versus the second.



Database error on a link

Galen Boyer, October 17, 2011 - 9:16 am UTC

Hi Tom,

I'm not sure if you want people to let you know, but I clicked another link, " http://asktom.oracle.com/pls/apex/f?p=100:11:0::::P11_QUESTION_ID:6904032233295" and got

Error Error during rendering of region "Reviews".
ORA-06502: PL/SQL: numeric or value error: character string buffer too small

You probably have an email write now from this link and are fixing it, but I thought you might want to know.

I hope randomly choosing a posting to tell you this is okay? You can delete postings correct? Please delete this one. It is the only way I knew to get in touch with you, and I love your site, so being in a "QA" mode for this site is something I feel like is my responsibility.
Tom Kyte
October 17, 2011 - 10:33 pm UTC

Thanks - we've put in a temporary workaround and will fix the "real" problem soon (minor code rewrite, it is affected by a change from a single byte to a multibyte character set)

re-cusrive calls.

A reader, December 09, 2011 - 6:39 am UTC

Hi Tom.



we have SQL similar to....


SELECT col1, col2, f(col3) from t where col4 =?


function f is similar to :

CREATE OR REPLACE FUNCTION f(p_col3 IN NUMBER)
...
BEGIN
select x into RET_VAL from t1 where col2 in ( select ..);
RETURN(RET_VAL);
END f;


we have taken the tkprof of main SQL.


SELECT col1, col2, f(col3) from t where col4 =?
****
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 28 61.92 74.19 78155 13280928 31 400
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 30 61.92 74.20 78155 13280928 31 400


Statistics
----------------------------------------------------------
1407 recursive calls
31 db block gets
13168677 consistent gets
81595 physical reads
224 redo size
56243 bytes sent via SQL*Net to client
942 bytes received via SQL*Net from client
28 SQL*Net roundtrips to/from client
945 sorts (memory)
3 sorts (disk)
400 rows processed






and the re-cursive call has the following tkprof




select x from t1 where col2 in ( select ..);
******
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 470 0.06 0.06 0 0 0 0
Fetch 470 53.57 59.84 0 13095488 0 409
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 941 53.63 59.90 0 13095488 0 409


So most of the time ( 85%) spent is calling the function in SELECT part ..

What would be other way of doing to minise the re-cusrive calls?
regards
Tom Kyte
December 11, 2011 - 2:43 pm UTC

I would recommend strongly using NO PLSQL here first and foremost. Just


select co1, col2, (select x from t1 where col2 in (select ....) )
from t;


that will benefit from scalar subquery caching

http://www.oracle.com/technetwork/issue-archive/2011/11-sep/o51asktom-453438.html


at the very least:

select col1, col2, (select f(col2) from dual) from t;


that would be better than what you have no, but the right answer is to remove the plsql altogehter.

re-cusrive calls. ...

A reader, December 12, 2011 - 2:04 am UTC

Thanks Tom.
we did the same and it reduced the recusrive calls and so the query run time.

further, just thinking why the SCALAR SUBQUERY were named so?

I am trying to correlate the same... with the definition of the SCALAR( no direction.. only mass)

regards
Tom Kyte
December 12, 2011 - 6:08 am UTC

a scalar subquery is called that because it returns

1 row
1 column


it is in fact a "scalar value". Just like 'KING' is a scalar value in a query

select 'KING' from dual;

scalar coming from the computer science, programming use of the word

direct path read temp

Rajeshwaran, Jeyabal, December 18, 2011 - 3:45 am UTC

Tom:

Can you help me to resolve this direct path read temp wait event?

Is that 5G of Tempspace is not enough to sort this 103MB of partitioned Index segment?

rajesh@ORA11GR2> select event,p1text,p1,
  2  p2text,p2,
  3  p3text,p3
  4  from v$session
  5  where username ='RAJESH'
  6  /

EVENT                          P1TEXT                        P1 P2TEXT                        P2 P3TEXT                        P3
------------------------------ -------------------- ----------- -------------------- ----------- -------------------- -----------
SQL*Net message from client    driver id             1111838976 #bytes                         1                        0
SQL*Net message from client    driver id             1111838976 #bytes                         1                        0
direct path read temp          file number                  201 first dba                  16421 block cnt                      1

Elapsed: 00:00:00.01
rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> SELECT A.tablespace_name tablespace, D.mb_total,
  2  SUM (A.used_blocks * D.block_size) / 1024 / 1024 mb_used,
  3  D.mb_total - SUM (A.used_blocks * D.block_size) / 1024 / 1024 mb_free
  4  FROM v$sort_segment A,
  5  (
  6  SELECT B.name, C.block_size, SUM (C.bytes) / 1024 / 1024 mb_total
  7  FROM v$tablespace B, v$tempfile C
  8  WHERE B.ts#= C.ts#
  9  GROUP BY B.name, C.block_size
 10  ) D
 11  WHERE A.tablespace_name = D.name
 12  GROUP by A.tablespace_name, D.mb_total;

TABLESPACE                        MB_TOTAL    MB_USED    MB_FREE
------------------------------- ---------- ---------- ----------
TEMP                                  5303        120       5183

Elapsed: 00:00:00.15
rajesh@ORA11GR2>
rajesh@ORA11GR2> show parameter pga;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target                 big integer 1500M
rajesh@ORA11GR2> show parameter sga;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
lock_sga                             boolean     FALSE
pre_page_sga                         boolean     FALSE
sga_max_size                         big integer 1600M
sga_target                           big integer 1552M
rajesh@ORA11GR2> show parameter memory;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
hi_shared_memory_address             integer     0
memory_max_target                    big integer 3G
memory_target                        big integer 3G
shared_memory_address                integer     0
rajesh@ORA11GR2>
rajesh@ORA11GR2> set autotrace traceonly explain;
rajesh@ORA11GR2>
rajesh@ORA11GR2> select isa_id,
  2         iea_id,
  3         gs_id,
  4         ge_id,
  5         st_grp as group_id,
  6         se_id,
  7         st_start_id,
  8         first_value(bill_prov_start_id ignore nulls) over(partition by st_grp order by record_id) - 1 as st_end_id,
  9         bill_prov_start_id,
 10         first_value(bill_subs_start_id ignore nulls) over(partition by bill_prov_grp order by record_id)-1 as bill_prov_end_id,
 11         bill_subs_start_id,
 12         first_value(claim_start_id ignore nulls) over(partition by bill_subs_grp order by record_id) - 1 as bill_subs_end_id,
 13         claim_start_id,
 14         claim_end_id,
 15         case when lag(bill_subs_start_id) over(order by record_id) is null or
 16                  lag(bill_subs_start_id) over(order by record_id) <> bill_subs_start_id
 17              then 1 end as provider_rnk
 18  from (
 19     select
 20       last_value(case when seg_identifier like 'ISA%' then record_id end ignore nulls) over(order by record_id) as isa_id,
 21       last_value(case when seg_identifier like 'IEA%' then record_id end ignore nulls) over(order by record_id rows between current row and unbounded following) as iea_id
 22       last_value(case when seg_identifier like 'GS%' then record_id end ignore nulls) over(order by record_id) as gs_id,
 23       lead(case when seg_identifier like 'GE%' then record_id end ignore nulls ) over(order by record_id) as ge_id,
 24       count(case when seg_identifier like 'ST%' then record_id end ) over(order by record_id) as st_grp,
 25       count(case when seg_identifier like 'HL*%**20*%' then record_id end ) over(order by record_id) as bill_prov_grp,
 26       count(case when seg_identifier like 'HL*%*%*22*%' then record_id end ) over(order by record_id) as bill_subs_grp,
 27       count(case when seg_identifier like 'CLM%' then record_id end ) over(order by record_id) as claim_grp,
 28       last_value(case when seg_identifier like 'ST%' then record_id end ignore nulls) over(order by record_id) as st_start_id,
 29       last_value(case when seg_identifier like 'HL*%**20*%' then record_id end ignore nulls) over(order by record_id) as bill_prov_start_id,
 30       last_value(case when seg_identifier like 'HL*%*%*22*%' then record_id end ignore nulls) over(order by record_id) as bill_subs_start_id,
 31       last_value(case when seg_identifier like 'CLM%' then record_id end ignore nulls) over(order by record_id) as claim_start_id,
 32       record_id,seg_identifier,
 33       lead(coalesce(case when seg_identifier like 'CLM%' then record_id end,
 34       case when seg_identifier like 'HL*%*%*22*%' then record_id end,
 35       case when seg_identifier like 'HL*%**20*%' then record_id end,
 36       case when seg_identifier like 'SE%' then record_id end) ignore nulls) over(order by record_id) - 1 as claim_end_id,
 37       case when seg_identifier like 'CLM%' then
 38             row_number() over(order by record_id) end as clm_rnk,
 39       lead(case when seg_identifier like 'SE%' then record_id end ignore nulls) over(order by record_id) as se_id
 40     from stg_inbound_837
 41     where file_key = 5
 42  ) where clm_rnk is not null
 43  order by record_id;
Elapsed: 00:00:00.23

Execution Plan
----------------------------------------------------------
Plan hash value: 665217875

------------------------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name       | Rows  | Bytes |TempSpc| Cost (%CPU)| Time     | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |            |  2699K|   502M|       |   367K  (1)| 01:13:33 |    |  |
|   1 |  WINDOW SORT                |            |  2699K|   502M|   602M|   367K  (1)| 01:13:33 |    |  |
|   2 |   WINDOW SORT               |            |  2699K|   502M|   602M|   367K  (1)| 01:13:33 |    |  |
|   3 |    WINDOW SORT              |            |  2699K|   502M|   602M|   367K  (1)| 01:13:33 |    |  |
|   4 |     WINDOW SORT             |            |  2699K|   502M|   602M|   367K  (1)| 01:13:33 |    |  |
|*  5 |      VIEW                   |            |  2699K|   502M|       | 23057   (1)| 00:04:37 |    |  |
|   6 |       WINDOW SORT           |            |  2699K|    64M|    93M| 23057   (1)| 00:04:37 |    |  |
|   7 |        PARTITION LIST SINGLE|            |  2699K|    64M|       |  3545   (1)| 00:00:43 |   KEY |   KEY |
|   8 |         INDEX FAST FULL SCAN| IDX_STG_01 |  2699K|    64M|       |  3545   (1)| 00:00:43 |     1 |     1 |
------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   5 - filter("CLM_RNK" IS NOT NULL)

rajesh@ORA11GR2>
rajesh@ORA11GR2> exec show_space(user,'IDX_STG_01','INDEX PARTITION','P_5');
l_total_blocks****************  13312
l_total_bytes*****************  109051904
l_unused_blocks***************  124
l_unused_bytes****************  1015808
l_last_used_extent_file_id****  7
l_last_used_extent_block_id***  154496
l_last_used_block*************  900
l_unformatted_blocks**********  0
l_unformatted_bytes***********  0
l_fs1_blocks******************  0
l_fs1_bytes*******************  0
l_fs2_blocks******************  1
l_fs2_bytes*******************  8192
l_fs3_blocks******************  0
l_fs3_bytes*******************  0
l_fs4_blocks******************  0
l_fs4_bytes*******************  0
l_full_blocks*****************  13032
l_full_bytes******************  106758144

PL/SQL procedure successfully completed.

rajesh@ORA11GR2>
rajesh@ORA11GR2>
rajesh@ORA11GR2> select index_name, column_name
  2  from user_ind_columns
  3  where index_name = 'IDX_STG_01'
  4  /

INDEX_NAME                COLUMN_NAME
------------------------- -------------------------
IDX_STG_01                FILE_KEY
IDX_STG_01                SEG_IDENTIFIER
IDX_STG_01                RECORD_ID

rajesh@ORA11GR2>
rajesh@ORA11GR2>

AWR Shows me this

                                                                   Snap Id      Snap Time      Sessions Curs/Sess
            --------- ------------------- -------- ---------
Begin Snap:      3305 18-Dec-11 03:05:00        24       1.5
  End Snap:      3306 18-Dec-11 03:28:27        25       1.8
   Elapsed:               23.45 (mins)
   DB Time:               23.04 (mins)

Cache Sizes                       Begin        End
~~~~~~~~~~~                  ---------- ----------
               Buffer Cache:     1,320M     1,320M  Std Block Size:         8K
           Shared Pool Size:       200M       200M      Log Buffer:    11,368K

Load Profile              Per Second    Per Transaction   Per Exec   Per Call
~~~~~~~~~~~~         ---------------    --------------- ---------- ----------
      DB Time(s):                1.0               76.8       0.51       3.84
       DB CPU(s):                0.2               13.0       0.09       0.65
       Redo size:            1,194.9           93,414.9
   Logical reads:               29.7            2,321.2
   Block changes:                4.7              368.4
  Physical reads:              901.5           70,475.4
 Physical writes:               22.0            1,719.2
      User calls:                0.3               20.0
          Parses:                1.3              101.4
     Hard parses:                0.1                8.1
W/A MB processed:                0.0                2.2
          Logons:                0.0                0.7
        Executes:                1.9              151.3
       Rollbacks:                0.0                0.1
    Transactions:                0.0

Instance Efficiency Percentages (Target 100%)
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
            Buffer Nowait %:  100.00       Redo NoWait %:  100.00
            Buffer  Hit   %:   99.34    In-memory Sort %:   99.90
            Library Hit   %:   94.73        Soft Parse %:   92.00
         Execute to Parse %:   32.94         Latch Hit %:   99.99
Parse CPU to Parse Elapsd %:   85.00     % Non-Parse CPU:   99.85

 Shared Pool Statistics        Begin    End
                              ------  ------
             Memory Usage %:   74.05   76.57
    % SQL with executions>1:   76.78   80.91
  % Memory for SQL w/exec>1:   58.80   77.37

Top 5 Timed Foreground Events
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
                                                           Avg
                                                          wait   % DB
Event                                 Waits     Time(s)   (ms)   time Wait Class
------------------------------ ------------ ----------- ------ ------ ----------
direct path read temp             1,253,924       1,124      1   81.3 User I/O
DB CPU                                              234          16.9
db file sequential read                 134           2     14     .1 User I/O
control file sequential read            601           1      2     .1 System I/O
db file scattered read                   38           0     13     .0 User I/O

Foreground Wait Events           DB/Inst: ORA11GR2/ora11gr2  Snaps: 3305-3306
-> s  - second, ms - millisecond -    1000th of a second
-> Only events with Total Wait Time (s) >= .001 are shown
-> ordered by wait time desc, waits desc (idle events last)
-> %Timeouts: value of 0 indicates value was < .5%.  Value of null is truly 0

                                                             Avg
                                        %Time Total Wait    wait    Waits   % DB
Event                             Waits -outs   Time (s)    (ms)     /txn   time
-------------------------- ------------ ----- ---------- ------- -------- ------
direct path read temp         1,253,924     0      1,124       1 6.97E+04   81.3
db file sequential read             134     0          2      14      7.4     .1
control file sequential re          601     0          1       2     33.4     .1
db file scattered read               38     0          0      13      2.1     .0
Disk file operations I/O             16     0          0      27      0.9     .0
log file sync                         3     0          0      73      0.2     .0
asynch descriptor resize            101   100          0       0      5.6     .0
direct path write temp                2     0          0       1      0.1     .0
direct path write                     3     0          0       0      0.2     .0
SQL*Net message from clien          218     0      1,772    8127     12.1
jobq slave wait                     240   100        120     500     13.3
          -------------------------------------------------------------

Tom Kyte
December 18, 2011 - 5:35 am UTC

Is that 5G of Tempspace is not enough to sort this 103MB of partitioned Index segment?


do you get an error? If not, it is enough.


Your wait times for reads from temp are awesomely good - average wait time of 1ms! Given the average IO response times are usually in the 5ms range - that is pretty good.

Your issue is you do that 1 million times - that is 1,000 seconds of wait.


You are not just sorting this data, you are really sorting this data, over and over

367K  (1)| 01:13:33 |    |  |
|   1 |  WINDOW SORT                |            |  2699K|   502M|   602M|   
367K  (1)| 01:13:33 |    |  |
|   2 |   WINDOW SORT               |            |  2699K|   502M|   602M|   
367K  (1)| 01:13:33 |    |  |
|   3 |    WINDOW SORT              |            |  2699K|   502M|   602M|   
367K  (1)| 01:13:33 |    |  |
|   4 |     WINDOW SORT             |            |  2699K|   502M|   602M|   
367K  (1)| 01:13:33 |    |  |
|*  5 |      VIEW                   |            |  2699K|   502M|       | 
23057   (1)| 00:04:37 |    |  |
|   6 |       WINDOW SORT           |            |  2699K|    64M|    93M| 
23057   (1)| 00:04:37 |    |  |
|   7 |        PARTITION LIST SINGLE|            |  2699K|    64M|       |  


see all of the window sort steps?

direct path read temp

Rajeshwaran, Jeyabal, December 18, 2011 - 12:07 pm UTC

Tom:

1) Given the average IO response times are usually in the 5ms range - that is pretty good - Which portion from AWR report tells you this? Can you please highlight on this?

2) You are not just sorting this data, you are really sorting this data, over and over

Given this requirement. How can this be achievedwithout sorting this data, over and over

a) isa_id - when  seg_identifier like 'ISA%'
b) iea_id - When  seg_identifier like 'IEA%'
c) gs_id - When  seg_identifier like 'GS%'
e) ge_id - When  seg_identifier like 'GE%'
f) st_start_id - When seg_identifier like 'ST%' 
g) st_end_id - firt Occurance - 1 of seg_identifier like 'HL*%**20*%' with in ST ( seg_identifier ='ST') and SE ( seg_identifier ='SE') boundry
h) bill_prov_start_id - When seg_identifier like 'HL*%**20*%' 
i) bill_prov_end_id - firt Occurance - 1 of seg_identifier like 'HL*%*%*22*%'  immediately after the bill_prov_start_id
j) bill_subs_start_id -  When seg_identifier like 'HL*%*%*22*%' 
k) bill_subs_end_id - firt Occurance - 1 of seg_identifier like 'CLM%' immediately after the bill_subs_start_id
l) claim_start_id - When seg_identifier like 'CLM%' 
m) claim_end_id - When seg_identifier like 'CLM%' or seg_identifier like 'HL*%*%*22*%' or
  seg_identifier like 'HL*%**20*%' or  seg_identifier like 'SE%'  immediately after the claim_start_id
n)  se_id -  When seg_identifier like 'SE%'


Structure of the data will be like this
1)ISA
2) GS
3)  ST
4)   A
5)   B
6)   C
7)    HL*%**20*%
8)    1
9)    2
10)    3
11)    HL*%*%*22*%
12)    5
13)    6
14)    7
15)    CLM1
16)    D11
17)    D2
18)    CLM2
19)    N1
20)    N2
21)  SE
22)  ST
23)   V
24)   B
25)   HL*%**20*%
26)   4
27)   HL*%*%*22*%
28)   5
29)   CLM1
30)   D1
31)   CLM2
32)   D2
33)   HL*%*%*22*%
34)   6
35)   7
36)   CLM
37)   D5
38)  SE
39) GE
40)IEA 


I need the output at CLM level ( when y='CLM%') breakup. In the above data i have 5 'CLM%'. so i need 5 rows in the output like this.


ISA_id  IEA_ID GS_ID GE_ID st_start_id st_end_id billprovstart billprovend billsubsstart billsubsend claimstart claimends se_id
1  38  2   37 3   6   7    10   11     14  15   17     21 
1  38  2   37 3   6   7    10   11     14  18   20     21 
1  38  2   37 22   24   25    26   27        28  29   30     38 
1  38  2   37 22   24   25    26   27        28  31   32     38 
1  38  2   37 22   24   25    26   33        35  36   37     38 
create table t (x number, seg_identifier varchar2(15));
insert into t values(1,'ISA');
insert into t values(2,'GS');
insert into t values(3,'ST');
insert into t values(4,'A');
insert into t values(5,'B');
insert into t values(6,'C');
insert into t values(7,'HL*%**20*%');
insert into t values(8,'1');
insert into t values(9,'2');
insert into t values(10,'3');
insert into t values(11,'HL*%*%*22*%');
insert into t values(12,'5');
insert into t values(13,'6');
insert into t values(14,'7');
insert into t values(15,'CLM1');
insert into t values(16,'D11');
insert into t values(17,'D2');
insert into t values(18,'CLM2');
insert into t values(19,'N1');
insert into t values(20,'N2');
insert into t values(21,'SE');
insert into t values(22,'ST');
insert into t values(23,'V');
insert into t values(24,'B');
insert into t values(25,'HL*%**20*%');
insert into t values(26,'4');
insert into t values(27,'HL*%*%*22*%');
insert into t values(28,'5');
insert into t values(29,'CLM1');
insert into t values(30,'D1');
insert into t values(31,'CLM2');
insert into t values(32,'D2');
insert into t values(33,'HL*%*%*22*%');
insert into t values(34,'6');
insert into t values(35,'7');
insert into t values(36,'CLM');
insert into t values(37,'D5');
insert into t values(38,'SE');
insert into t values(39,'GE');
insert into t values(40,'IEA');
commit; 


Tom Kyte
December 18, 2011 - 2:43 pm UTC

1)

                                                           Avg
                                                          wait   % DB
Event                                 Waits     Time(s)   (ms)   time Wait Class
------------------------------ ------------ ----------- ------ ------ ----------
direct path read temp             1,253,924       1,124      1   81.3 User I/O


see the column - avg wait (ms) - it says "1"

divide waits into time, you get the average... In real life, an average of 5ms would be considered "normal and expected", you are doing 1ms - you are reading pretty much at light speed (must be a cache going on there somewhere, I doubt it is coming from a real disk)


2) Given this requirement. How can this be achievedwithout sorting this data, over and over


sometimes you gotta do what you gotta do - some queries do not run too slow, they are running as fast as the hardware you give them can - they just take that long. Some long running queries are in fact "tuned" - it is sometimes our expectations that need to be tuned.


You might study your data and use your knowledge of it to come up with a better design - one that can be queried in a realistic amount of time (where you define realistic)

remember: we insert data once, we query it over and over - it is many times (many times) perfectly ok to penalize the insertion of data in order to optimize the retrieval.


that said, your list above is not sufficient for me to suggest anything - it really doesn't tell me what you are looking for (and no, I'm not going to reverse engineer a 43 line query to figure it out :) )


direct path read temp

Rajeshwaran, Jeyabal, December 18, 2011 - 4:21 pm UTC

Tom:
I'm not going to reverse engineer a 43 line query to figure it out :)

I dont want you to do this and that's why i gave the entire requirement for this query above.

Can you provide me some direction of how this requirement can be done efficient, Our estimates are that this query should be completed in 20sec given this 103 MB Index segment.

it is many times (many times) perfectly ok to penalize the insertion of data in order to optimize the retrieval

Can you give me some guidelines on how this can be handled for this requirement?
Tom Kyte
December 19, 2011 - 7:25 am UTC

I dont want you to do this and that's why i gave the entire requirement for this query above.


and where pray tell was that? Please don't tell me it was this list of personal notes for you to remind you of what you needed to do (don't tell us this is a "specification", it just isn't)


a) isa_id - when seg_identifier like 'ISA%'
b) iea_id - When seg_identifier like 'IEA%'
...
l) claim_start_id - When seg_identifier like 'CLM%'
m) claim_end_id - When seg_identifier like 'CLM%' or seg_identifier like 'HL*%*%*22*%' or
seg_identifier like 'HL*%**20*%' or seg_identifier like 'SE%' immediately after the
claim_start_id
n) se_id - When seg_identifier like 'SE%'


that list is not meaningful to anyone short of you.


Can you provide me some direction of how this requirement can be done efficient, Our estimates are that this query should be completed in 20sec given this 103 MB Index segment.

care to share that math?

you basically have to sort the entire result by record_id to get the first/last records for various conditions. You have to join up each record with a complex next record (not just the next record - but the next record that matches a complex series of LIKE clauses). This is one window sort

then you have to take the output of that and find the lag by record id, this is another window sort

Then you have to break the data up by st_grp and within st_grp sort by record_id again to find a first value, skipping over nulls. 3rd window sort

Then you have to break the data up by bill_prov_grp - sorting by record id again to find a first value - skipping over nulls once again. 4th window sort

Then you have to break the data up by bill_subs_grp, sorting by record id, to find a first value after skipping nulls. 6th window sort.


do you have a reasonable sized PGA?

Can you give me some guidelines on how this can be handled for this requirement?


like I said before - if I knew the question being asked as well as you, if I understood the data required as well as you - I could help.

SQL Tuning

A reader, December 18, 2011 - 8:39 pm UTC


what to do with megaqueries?

Michael, January 19, 2012 - 3:53 am UTC

hi tom,

a third party application is sending very large queries with up to 1500 lines in size when pretty formatted (due to massive literal inlists).

due to - sometimes only a few - inlist changes the execution plan (350 - 600 lines in size) and execution times sometimes differs massively (from 20 minutes to 5 hours).

i'm asked for the reason as well as for a solution in that case by business peoples as "you are the dba". i'm not in the position to resolve such megaquery troubles. what would you tell them?

cheers,
michael

Tom Kyte
January 19, 2012 - 5:32 am UTC

that the developers of this 3rd party application have subjected us to a

o performance issue
o scalability issue
o SQL INJECTION SECURITY ISSUES <<<=== bad, very very bad


Tell them that the DBA is not a magician, more like a car mechanic and applications are cars. Give them a go cart and it'll go as fast as a go cart, no faster. Give them a forumla one race car and it'll go faster.

You'll never make a hacked together go cart resemble a formula one race car.

garbage in, garbage out.

what to do with megaqueries?

Michael, January 19, 2012 - 8:08 am UTC

tom,

besides of the literal inlists and its security pitfalls, do you think such megaqueries resulting in several hundred lines of execution plan are reasonable and particularly feasible?

cheers,
michael
Tom Kyte
January 19, 2012 - 12:33 pm UTC

sure, you gotta do what you gotta do. 'mega-queries' are more appealing then someone breaking it up into 50 tiny queries. I'd rather have one big query that does all of the work.

Now, on the other hand, if the mega query is pulling stuff that is not necessary, if the mega query could be replace by a more concise to the point query that gets just what is required - that would be a different story, but we cannot assume that here.

Number of executions can be parallelized?

Sikki, February 14, 2012 - 2:03 pm UTC

Hi Tom,

I have SQL statement which runs about 1 hour with the number of executions 3470566. I queried from v$sql. The total batch process runs for 10 hours in an average which includes this as well, other part have tuned and now it came close to 6 hours. Now this query takes significant amount of time and looking to reduce the time.

Do you have any better idea to reduce the time of this particular query?

SELECT DISTINCT FLIGHTSEQNO, FLIGHTDATE, TRIPLEGNO FROM STG_ROSTER_ACTUAL A WHERE TRIPLEGNO = (SELECT MIN(TRIPLEGNO) FROM STG_ROSTER_ACTUAL WHERE STAFFNO = :B3 AND DATEOFDUTY = TRUNC(:B2 ) AND TRIPSEQNO = :B4 ) AND STAFFNO = :B3 AND DATEOFDUTY = TRUNC(:B2 ) AND A.ACTTYPE = :B1

Below is the plan of this query.

old 1: select id,OPERATION,OPTIONS,OBJECT_NAME,OPTIMIZER,COST,BYTES,CPU_COST,IO_COST,TIME,to_char(TIMESTAMP,'dd-mm-yyyy:hh24:mi:ss'),plan_hash_value from v$sql_plan where sql_id='&sqlid'
new 1: select id,OPERATION,OPTIONS,OBJECT_NAME,OPTIMIZER,COST,BYTES,CPU_COST,IO_COST,TIME,to_char(TIMESTAMP,'dd-mm-yyyy:hh24:mi:ss'),plan_hash_value from v$sql_plan where sql_id='7n8v36mrmcazu'

ID OPERATION OPTIONS OBJECT_NAME OPTIMIZER COST BYTES CPU_COST IO_COST TIME TO_CHAR(TIMESTAMP,' PLAN_HASH_VALUE
---------- -------------------- ---------- -------------------- ---------- ---------- ---------- ---------- ---------- ---------- ------------------- ---------------
0 SELECT STATEMENT ALL_ROWS 8 14-02-2012:21:53:53 2449550040
1 HASH UNIQUE 8 29 46177258 7 1 14-02-2012:21:53:53 2449550040
2 TABLE ACCESS BY INDEX R STG_ROSTER_ACTUAL 4 29 60497 4 1 14-02-2012:21:53:53 2449550040
OWID

3 INDEX RANGE SCAN INDX_TRIPSEQNO_12115 3 45157 3 1 14-02-2012:21:53:53 2449550040
4 SORT AGGREGATE 20 14-02-2012:21:53:53 2449550040
5 TABLE ACCESS BY INDEX R STG_ROSTER_ACTUAL 3 20 46277 3 1 14-02-2012:21:53:53 2449550040
OWID

6 INDEX RANGE SCAN INDX_TRIPSEQNO_12116 2 31022 2 1 14-02-2012:21:53:53 2449550040


Tom Kyte
February 14, 2012 - 2:12 pm UTC

... Do you have any better idea to reduce the time of this particular query?
...

absolutely.
definitely.

go back to the application running this statement and figure out why the heck it is running such a query 3,470,566 times.

Make it run a "bigger" query ONCE.

You are lucky it only takes an hour. Think about it - you have a query that is run 3.5 million *times*. that means that query runs in about 1ms (1/1000th of a second)



ops$tkyte%ORA11GR2> select 3470566 * 1 / 1000 / 60 / 60 from dual;

3470566*1/1000/60/60
--------------------
          .964046111



that query is already running at light speed .

It is a mathematical fact that if you take a huge number and multiply it by a small number you end up with..... a huge number.

If you do something really really fast - millions of times - it takes HOURS


The only way to make this thing (this batch) go "faster" will be to go back to the batch program and make it SET BASED - instead of slow by slow (row by row).


You would have to run your batch in many processes (many copies of your batch program at the same time) in order to get any parallelism.


But - if you make it set based - you can probably make this go 100-1000 times faster (or more, I would not be surprised to get more than 1000x faster). You'll never do that by just running multiple copies of your batch process.

And besides, to run multiple copies of your batch - you'll have to recode anyway - so you might as well do it right and make it set based!

Number of executions can be parallelized?

sikki, February 14, 2012 - 6:46 pm UTC

Tom,

Thanks for your input, the process cannot go in multiple copies as one session is dependent on other, this includes drop & recreate of indexes with parallel option (Informatica needs the table without index for any bulk load).

As this is apart, i am not sure about set based. do you want us rewrite the query with more where condition to reduce the time? can you shed some light on this?
Tom Kyte
February 15, 2012 - 8:05 am UTC

not the query - but the PROCESS itself.

Its fundamental approach is wrong. It is doing something like:

for x in (get something)
   for y in (get something else based on x)
      for z in (get something else based on y and x)
         for ..... for for for
                 execute something  millions of times here



it is taking a procedural, slow by slow approach as evidenced by a teeny tiny little query that does hardly any work being executed 3.5 MILLION times.


You need to look at the fundamental algorithm, refactor it to be set based instead of slow by slow - but only if you want this to go measurably faster. If you are happy with the current performance, leave it be. But if you want this to go X times faster - you'll be looking at re-working the underlying logic.


So, I'm not talking about tuning a query.

I'm talking about tuning a process, an algorithm, an approach.

Questions on execution plan and predicate information

A reader, February 22, 2012 - 4:43 pm UTC

In the execution plan and predicate information shown below,

* What exactly do "COUNT STOPKEY" (id=1) and "SORT ORDER BY STOPKEY" (id=3) do?
* What are the SYS_NC0000x$ objects in id=6 and id=8?
* id=7, why is LNNVL function applied to the filter?


CREATE TABLE x AS
SELECT rownum id, name1, name2, object_type, created
FROM (
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
   UNION  ALL
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
   UNION  ALL
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
   UNION  ALL
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
   UNION  ALL
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
   UNION  ALL
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
   UNION  ALL
   SELECT object_name name1, object_name name2, object_type, created
   FROM   all_objects
);

INSERT INTO x
SELECT id + 100000, name1, name2, object_type, created
FROM   x;

SELECT COUNT(*) FROM x;

  COUNT(*)
----------
    103796

ALTER TABLE x ADD CONSTRAINT x_pk PRIMARY KEY (id);

CREATE INDEX x_idx1 ON x(LOWER(name1));
CREATE INDEX x_idx2 ON x(LOWER(name2));

set linesize 300
set serveroutput off

SELECT *
FROM (
   SELECT /*+ gather_plan_statistics */ *
   FROM   x
   WHERE  LOWER(Name1) LIKE 'v$dlm%' OR
          LOWER(Name2) LIKE 'v$dlm%'
   ORDER  BY LOWER(Name1), id
)
WHERE  rownum <= 10;

SELECT * FROM TABLE(dbms_xplan.display_cursor(NULL, NULL, 'allstats last'));

-------------------------------------------------------------------------------------------------------------------------------
| Id  | Operation                       | Name   | Starts | E-Rows | A-Rows |   A-Time   | Buffers |  OMem |  1Mem | Used-Mem |
-------------------------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                |        |      1 |        |     10 |00:00:00.01 |     232 |    |          |          |
|*  1 |  COUNT STOPKEY                  |        |      1 |        |     10 |00:00:00.01 |     232 |    |          |          |
|   2 |   VIEW                          |        |      1 |     16 |     10 |00:00:00.01 |     232 |    |          |          |
|*  3 |    SORT ORDER BY STOPKEY        |        |      1 |     16 |     10 |00:00:00.01 |     232 |  2048 |  2048 | 2048  (0)|
|   4 |     CONCATENATION               |        |      1 |        |    112 |00:00:00.01 |     232 |    |          |          |
|   5 |      TABLE ACCESS BY INDEX ROWID| X      |      1 |      8 |    112 |00:00:00.01 |     116 |    |          |          |
|*  6 |       INDEX RANGE SCAN          | X_IDX2 |      1 |      8 |    112 |00:00:00.01 |       4 |    |          |          |
|*  7 |      TABLE ACCESS BY INDEX ROWID| X      |      1 |      8 |      0 |00:00:00.01 |     116 |    |          |          |
|*  8 |       INDEX RANGE SCAN          | X_IDX1 |      1 |      8 |    112 |00:00:00.01 |       4 |    |          |          |
-------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(ROWNUM<=10)
   3 - filter(ROWNUM<=10)
   6 - access("X"."SYS_NC00007$" LIKE 'v$dlm%')
       filter("X"."SYS_NC00007$" LIKE 'v$dlm%')
   7 - filter(LNNVL(LOWER("NAME2") LIKE 'v$dlm%'))
   8 - access("X"."SYS_NC00006$" LIKE 'v$dlm%')
       filter("X"."SYS_NC00006$" LIKE 'v$dlm%')


Tom Kyte
February 23, 2012 - 7:42 pm UTC

1) that is top-n query optimization taking place.

2) that is the virtual column that we generate under the covers for function based indexes. We have a virtual column that takes no storage in your table that represents "lower(column)"

3) lnnvl treats NULL evaluations differently. If you would have an OR condition that was: where NULL or TRUE, that would evaluate to "unknown", the LNNVL is being used to make the "NULL" issues go away for the proper evaluation of the where clause.

Tuning Distributed SQL

Alec, March 01, 2012 - 12:22 am UTC

Hi Tom,

We have a 24/7 webapp that performs this query in DB1 which has db link to DB2, at around 700 times per hour.

DB1:

SELECT W.EID, E.EID, E.STATUS, L.COLOR, C.OPMODE
FROM WORKSPACE W, EQUN B, EQPS E, CUROPS@DB2 C, LEGEND L
WHERE E.SERIALNO = 0
AND E.RECTYPE = 'C'
AND E.EID = B.EID
AND W.EID = C.EID (+)
AND (B.EID LIKE W.EID || '%')
AND (E.STATUS = L.COLORITEM)
ORDER BY EID;


DB2:

This SQL is distributed to DB2 as:

SELECT "EID","OPMODE" FROM "CUROPS" "C" WHERE :1="EID"

And is executed at least 2 million times per hour. It is consistently the top SQL in DB2 and is consuming significant CPU% (at around 10%).

Elapsed CPU Elap per % Total
Time (s) Time (s) Executions Exec (s) DB Time SQL Id
---------- ---------- ------------ ---------- ------- -------------
398 389 2,130,069 0.0 5.9 6vznxjxq8jskq

SELECT "EID","OPMODE" FROM "CUROPS" "C" WHERE :1="EID"


CUROPS has an index on column EID.

When I check the explain plan manually I get this:
------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 14 | 1 (0)|
| 1 | TABLE ACCESS BY INDEX ROWID| CUROPS | 1 | 14 | 1 (0)|
|* 2 | INDEX RANGE SCAN | IDX_CUROPS | 1 | | 1 (0)|
------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("EID"=:1)

I had to change :1 to :B1 because sqlplus does not like "variable 1 varchar2". Please correct me if I am not correct.


We create a new index for columns EID and OPMODE, the explain plan will look like this:
--------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
--------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 14 | 1 (0)|
|* 1 | INDEX RANGE SCAN| IDX_CUROPS_NEW | 1 | 14 | 1 (0)|
--------------------------------------------------------------------------------

It no longer does the TABLE ACCESS BY INDEX ROWID. Will this "skip" be significant given that the distributed query is executed millions of times? Any other thing that we can improve?

BTW, CUROPS is a small dynamic table with 586 rows. EID is unique while OPMODE has 2 values, "AUTO", or "MANUAL".

Thanks in advance for sharing your awesomeness. :)
Tom Kyte
March 01, 2012 - 7:49 am UTC

there is simply no way I'd have a distributed query be part of an application that is client facing.

In the background - sure, database links are great. In the foreground - while an end user is waiting - not a chance.

There are uptime issues (I have to have two databases up in order for my application to be up)

There are performance issues (distributed queries are not in the category of "super fast")


It no longer does the TABLE ACCESS BY INDEX ROWID. Will this "skip" be
significant given that the distributed query is executed millions of times? Any
other thing that we can improve?


it could be very large in significance, yes. It might cut out somewhere between 33% to 50% of the logical IO performed - assuming the index is only 1 or 2 levels (1 to 2 IO's against the index, 1 against the table)



My main suggestion would be:

do not query this table remotely, use a materialized view to have it be physically present on your site.

A reader, March 01, 2012 - 9:38 am UTC


SELECT W.EID, E.EID, E.STATUS, L.COLOR, C.OPMODE
 FROM WORKSPACE W, EQUN B, EQPS E, CUROPS@DB2 C, LEGEND L
WHERE E.SERIALNO = 0
  AND E.RECTYPE = 'C'
  AND E.EID = B.EID
  AND W.EID = C.EID (+)
  AND (B.EID LIKE W.EID || '%')
  AND (E.STATUS = L.COLORITEM)
ORDER BY EID;



in above query consider set X=(B join E join L) and set Y(W join C) the join is missing between set A and B which result into cross join

Thanks


Full scan for query using connect by

Lal Cyril, March 02, 2012 - 8:15 am UTC

Tom,

I have a table called SERIALISED_RECORDS which has PART_ID and NHA_PARTID columns having parent child relation
PARTID is a unique column.
Indexes exists for both columns

A full table occurs for the following query

SELECT SR.PART_ID,   SR.AIRCRAFT_PARTNO,   SR.AIRCRAFT_SERIALNO 
  FROM SERIALISED_RECORDS SR
 WHERE SR.PART_ID                = 100000000016966   
 START WITH SR.PART_ID         = 100000000016966   
 CONNECT BY (SR.NHA_PART_ID    = PRIOR SR.PART_ID)  

 

PART_ID         AIRCRAFT_PARTNO                               AIRCRAFT_SERIALNO 
--------------- --------------------------------------------- ----------------- 
100000000016966 EMBRAER 190                                   19000012          

1 rows selected


The execution plan is shown below.

Why is it going for a full scan. Is it because of the connect by clause.
Any way to avoid full scan for this query. If i remove the connect by clause the full scan does not happens


PLAN_TABLE_OUTPUT

SQL_ID  7z3xvt5vd7k50, child number 0
-------------------------------------
SELECT SR.PART_ID,   SR.AIRCRAFT_PARTNO,   SR.AIRCRAFT_SERIALNO FROM SERIALISED_RECORDS SR WHERE
SR.PART_ID                = 100000000016966   START WITH SR.PART_ID         = 100000000016966   CONNECT
BY (SR.NHA_PART_ID    = PRIOR SR.PART_ID)

Plan hash value: 2156164189

----------------------------------------------------------------------------------------------------------------
| Id  | Operation                      | Name                          | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT               |                               |       |       |    53 (100)|          |
|*  1 |  FILTER                        |                               |       |       |            |          |
|*  2 |   CONNECT BY WITH FILTERING    |                               |       |       |            |          |
|   3 |    TABLE ACCESS BY INDEX ROWID | SERIALISED_RECORDS            |       |       |            |          |
|*  4 |     INDEX FAST FULL SCAN       | SERIALISED_RECS_PART_ID       |     1 |    16 |    79   (2)| 00:00:01 |
|   5 |    NESTED LOOPS                |                               |       |       |            |          |
|   6 |     BUFFER SORT                |                               |       |       |            |          |
|   7 |      CONNECT BY PUMP           |                               |       |       |            |          |
|   8 |     TABLE ACCESS BY INDEX ROWID| SERIALISED_RECORDS            |   150 |  7950 |    53   (0)| 00:00:01 |
|*  9 |      INDEX RANGE SCAN          | SERIALISED_RECORDS_NHA_PARTID |   150 |       |     3   (0)| 00:00:01 |
|  10 |    TABLE ACCESS FULL           | SERIALISED_RECORDS            |   150 |  7950 |    53   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(TO_NUMBER("SR"."PART_ID")=100000000016966)
   2 - filter(TO_NUMBER("SR"."PART_ID")=100000000016966)
   4 - filter(TO_NUMBER("SR"."PART_ID")=100000000016966)
   9 - access("SR"."NHA_PART_ID"=NULL)


32 rows selected

Tom Kyte
March 02, 2012 - 10:32 am UTC

do you have a tkprof for this. I want to see the row source execution bit from that report.

EXEC in 10046 trace file,

A reader, March 03, 2012 - 5:42 pm UTC

Hello,

I have extracted a portion of my 10046 trace file that tells about an INSERT of one record into a table. The elapsed time in EXEC is around 90ms and CPU is 20ms. I am hoping the other 70ms would be around WAIT events, but there are hardly any wait events that sum up to 70ms. How can I get details on what went through in the actual EXEC?

I know there may be some unknown time waiting for CPU, but in my case, on a 8CPU box, I have only one job running so I am assuming that shouldn't be a case.

Here is the extract of trace file:


PARSE #11529215046053684000:c=0,e=23,p=0,cr=0,cu=0,mis=0,r=0,dep=0,og=1,plh=974762403,tim=2073631673855
BINDS #11529215046053684000:
Bind#0
oacdty=02 mxl=22(22) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000000 frm=01 csi=873 siz=2408 off=0
kxsbbbfp=9fffffffff1f1910 bln=22 avl=05 flg=05
value=13049811
Bind#1
oacdty=01 mxl=2000(36) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=24
kxsbbbfp=9fffffffff1f1928 bln=2000 avl=09 flg=01
value="SOTEC S A"
Bind#2
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2024
kxsbbbfp=9fffffffff1f20f8 bln=32 avl=00 flg=01
Bind#3
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2056
kxsbbbfp=9fffffffff1f2118 bln=32 avl=01 flg=01
value="Y"
Bind#4
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2088
kxsbbbfp=9fffffffff1f2138 bln=32 avl=01 flg=01
value="Y"
Bind#5
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2120
kxsbbbfp=9fffffffff1f2158 bln=32 avl=01 flg=01
value="N"
Bind#6
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2152
kxsbbbfp=9fffffffff1f2178 bln=32 avl=00 flg=01
Bind#7
oacdty=01 mxl=32(08) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2184
kxsbbbfp=9fffffffff1f2198 bln=32 avl=02 flg=01
value="MU"
Bind#8
oacdty=02 mxl=22(22) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000000 frm=01 csi=873 siz=0 off=2216
kxsbbbfp=9fffffffff1f21b8 bln=22 avl=00 flg=01
Bind#9
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2240
kxsbbbfp=9fffffffff1f21d0 bln=32 avl=00 flg=01
Bind#10
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2272
kxsbbbfp=9fffffffff1f21f0 bln=32 avl=00 flg=01
Bind#11
oacdty=180 mxl=11(11) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000000 frm=01 csi=873 siz=0 off=2304
kxsbbbfp=9fffffffff1f2210 bln=11 avl=11 flg=01
value=
Bind#12
oacdty=180 mxl=11(11) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000000 frm=01 csi=873 siz=0 off=2320
kxsbbbfp=9fffffffff1f2220 bln=11 avl=11 flg=01
value=
Bind#13
oacdty=02 mxl=22(22) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000000 frm=01 csi=873 siz=0 off=2336
kxsbbbfp=9fffffffff1f2230 bln=22 avl=02 flg=01
value=2
Bind#14
oacdty=01 mxl=32(04) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000010 frm=01 csi=873 siz=0 off=2360
kxsbbbfp=9fffffffff1f2248 bln=32 avl=01 flg=01
value="N"
Bind#15
oacdty=180 mxl=11(11) mxlc=00 mal=00 scl=00 pre=00
oacflg=03 fl2=1000000 frm=01 csi=873 siz=0 off=2392
kxsbbbfp=9fffffffff1f2268 bln=11 avl=11 flg=01
value=
EXEC #11529215046053684000:c=20000,e=90647,p=0,cr=1,cu=21,mis=0,r=1,dep=0,og=1,plh=974762403,tim=2073633509491
WAIT #11529215046053684000: nam='SQL*Net message to client' ela= 8 driver id=675562835 #bytes=1 p3=0 obj#=-1 tim=2073633510120
WAIT #11529215046053684000: nam='SQL*Net message from client' ela= 2289 driver id=675562835 #bytes=1 p3=0 obj#=-1 tim=2073633515597
CLOSE #11529215046053684000:c=0,e=8,dep=0,type=3,tim=2073633516582

Tom Kyte
March 04, 2012 - 9:14 am UTC

just show the tkprof report next time, reading a raw trace file can be a pain in the butt.

you have to remember that things are timed at different granularities (milliseconds, centiseconds) and for different durations.

For exmaple

elapsed timer1 := get time right now
...
cputimer := get cpu time right now
do some of your your insert
cputot := cputot + (get cpu time right now-cputimer)
...
cputimer := get cpu time right now
do a bit more of your insert
cputot := cputot + (get cpu time right now-cputimer)
............
elapsed timer2 := get time right now
...

the elapsed times are in 1/1000000ths of a second, the cpu time is in 1/1000th of a second

They are measured using different clocks - at different points in time. There could be spins for latches happening and other tiny bits of code in there that are not measured.

sql tuning - unnecessary function call in sql

A reader, April 06, 2012 - 1:24 am UTC

Hi Tom,

Sorry i can not find a thread more related to my question than this one, so post it here.

I happened to noticed one shocking-smart part of ORACLE which i do not know yet - seems ORACLE try to eliminate unnecessary function calls in SQL.

I do not know the formal terminology of this, bear me:)

For example:
create or replace function f1 return number
as
begin
dbms_output.put_line('a');
return 1;
end;
select id from (select rownum id, f1 id1 from dual connect by level<=10);
-- here function f1 was not called even once, because it will not be used in the select list, right?
select id+id1 from (select rownum id, f1 id1 from dual connect by level<=10);
-- here got called 10 times

I did further more testing with below and proved myself more.
create table test1(id int primary key, name char(1000));
insert into test1 select rownum,'a'||rownum from dual connect by level<=10000;
select id from test1;
select id from (select id,name from test1);
-- both above 2 are infex fast full scan
select id||name from (select id,name from test1);
-- here got table full scan

Then i tried below testing, but not what i am expecting, could you please help?
create table t1(id int, name varchar2(10));
create table t2(id int, age number);
create table t3(id int, address varchar2(10));
select id from (select a.id, a.name, b.age, c.address from t1 a, t2 b, t3 c where a.id = b.id and b.id = c.id);
-- i can understand this plain
------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 39 | 7 (15)| 00:00:01 |
|* 1 | HASH JOIN | | 1 | 39 | 7 (15)| 00:00:01 |
| 2 | MERGE JOIN CARTESIAN| | 1 | 26 | 4 (0)| 00:00:01 |
| 3 | TABLE ACCESS FULL | T1 | 1 | 13 | 2 (0)| 00:00:01 |
| 4 | BUFFER SORT | | 1 | 13 | 2 (0)| 00:00:01 |
| 5 | TABLE ACCESS FULL | T3 | 1 | 13 | 2 (0)| 00:00:01 |
| 6 | TABLE ACCESS FULL | T2 | 1 | 13 | 2 (0)| 00:00:01 |
------------------------------------------------------------------------------

select id from (select a.id, a.name, b.age, c.address from t1 a, t2 b, t3 c where a.id = b.id(+) and b.id = c.id(+));
-- why not oracle just access table t1 is ok, because the result is just all the ids from t1, nothing else?
----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 195 | 10 (10)| 00:00:01 |
|* 1 | HASH JOIN OUTER | | 5 | 195 | 10 (10)| 00:00:01 |
|* 2 | HASH JOIN OUTER | | 5 | 130 | 7 (15)| 00:00:01 |
| 3 | TABLE ACCESS FULL| T1 | 5 | 65 | 3 (0)| 00:00:01 |
| 4 | TABLE ACCESS FULL| T2 | 4 | 52 | 3 (0)| 00:00:01 |
| 5 | TABLE ACCESS FULL | T3 | 3 | 39 | 3 (0)| 00:00:01 |
----------------------------------------------------------------------------
Tom Kyte
April 06, 2012 - 2:04 pm UTC

here function f1 was not called even once, because it will not be used in
the select list, right?


it might be, it might not be, it doesn't have to be, it doesn't have to NOT be. It likely would be very version dependent as well.


here got called 10 times

and it might some day be called once, and it could have been called 20 times. You cannot rely on the number of times, the order of calls - nothing like that. SQL is not a procedural language like that.

I did further more testing with below and proved myself more.


you have empirically observed a behavior in a specific release, yes.




.. why not oracle just access table t1 is ok, because the result is just
all the ids from t1, nothing else? ...


no, that is wrong.






ops$tkyte%ORA11GR2> insert into t1 values ( 1, 'x' );

1 row created.

ops$tkyte%ORA11GR2> insert into t2 values ( 1, 1 );

1 row created.

ops$tkyte%ORA11GR2> insert into t2 values ( 1, 1 );

1 row created.

ops$tkyte%ORA11GR2> insert into t2 values ( 1, 1 );

1 row created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> select id from (select a.id, a.name, b.age, c.address from t1 a, t2 b, t3 c where a.id = b.id(+) and b.id = c.id(+));

   ID
-----
    1
    1
    1

ops$tkyte%ORA11GR2> select id from t1;

   ID
-----
    1



see, the tables have to be joined in this case. However, if you give the optimizer sufficient data about the relations of the table - so that the above query is in fact equivalent to select * from t1 - current releases will be glad to make that optimization:



ops$tkyte%ORA11GR2> create table t1(id int primary key, name varchar2(10));

Table created.

ops$tkyte%ORA11GR2> create table t2(id int primary key, age number);

Table created.

ops$tkyte%ORA11GR2> create table t3(id int primary key, address varchar2(10));

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select id from (select a.id, a.name, b.age, c.address from t1 a, t2 b, t3 c where a.id = b.id(+) and b.id = c.id(+));

Execution Plan
----------------------------------------------------------
Plan hash value: 3617692013

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |    13 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS FULL| T1   |     1 |    13 |     2   (0)| 00:00:01 |
--------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement (level=2)


give us primary keys so we know that if you join T1 to T2 - every row in T1 will appear AT MOST ONCE (and due to the outer join AT LEAST ONCE) and same for T2 to T3 - we can remove the tables which are now unnecessary.

In your original example, they MUST be accessed.

sql tuning

rizwan, April 27, 2012 - 5:43 am UTC

We are executing one query through oracle forms from two different servers .. On old server its taking around 22 seconds and on new server its taking 35-50 seconds .. By tracing the user session we were able to 
figure out the query .. Then we ran the query on the database server .. Below is our analysis 

New server :- 

Checking v$session_wait for the sid running  the query on the new server we get 

SQL> /

       SID       SEQ# EVENT                                                            P1TEXT                                                                   P1 P1RAW
---------- ---------- ---------------------------------------------------------------- ---------------------------------------------------------------- ---------- ----------------
P2TEXT                                                                   P2 P2RAW            P3TEXT                                                                   P3 P3RAW    WAIT_CLASS_ID
---------------------------------------------------------------- ---------- ---------------- ---------------------------------------------------------------- ---------- ---------------- -------------
WAIT_CLASS# WAIT_CLASS                                                        WAIT_TIME SECONDS_IN_WAIT STATE               WAIT_TIME_MICRO TIME_REMAINING_MICRO TIME_SINCE_LAST_WAIT_MICRO
----------- ---------------------------------------------------------------- ---------- --------------- ------------------- --------------- -------------------- --------------------------
      1740        207 SQL*Net message to client                                        driver id                                                        1650815232 0000000062657100
#bytes                                                                    1 0000000000000001                                                                           0 00          2000153315
          7 Network                                                                  -1              30 WAITED SHORT TIME                 1                                        30386736


SQL>
SQL>
SQL> /

       SID       SEQ# EVENT                                                            P1TEXT                                                                   P1 P1RAW
---------- ---------- ---------------------------------------------------------------- ---------------------------------------------------------------- ---------- ----------------
P2TEXT                                                                   P2 P2RAW            P3TEXT                                                                   P3 P3RAW    WAIT_CLASS_ID
---------------------------------------------------------------- ---------- ---------------- ---------------------------------------------------------------- ---------- ---------------- -------------
WAIT_CLASS# WAIT_CLASS                                                        WAIT_TIME SECONDS_IN_WAIT STATE               WAIT_TIME_MICRO TIME_REMAINING_MICRO TIME_SINCE_LAST_WAIT_MICRO
----------- ---------------------------------------------------------------- ---------- --------------- ------------------- --------------- -------------------- --------------------------
      1740        210 SQL*Net message from client                                      driver id                                                        1650815232 0000000062657100
#bytes                                                                    1 0000000000000001                                                                           0 00          2723168908
          6 Idle                                                                      0               0 WAITING                      103435                   -1                  0

                                                                 0               0 WAITING                      176733                   -1                  0




And setting autotrace on while the query is running we are getting below statistics 


395 rows selected.

Elapsed: 00:00:35.42

Execution Plan
----------------------------------------------------------
Plan hash value: 1184574360

----------------------------------------------------------------------------------------------
| Id  | Operation                     | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |              |   127 | 23876 |  6652   (2)| 00:01:20 |
|*  1 |  HASH JOIN RIGHT SEMI         |              |   127 | 23876 |  6652   (2)| 00:01:20 |
|   2 |   VIEW                        | VW_SQ_1      |  5877 | 35262 |   925  (10)| 00:00:12 |
|*  3 |    HASH JOIN                  |              |  5877 |   160K|   925  (10)| 00:00:12 |
|*  4 |     INDEX FAST FULL SCAN      | OSI_SINH01_1 |  5877 | 82278 |   720  (13)| 00:00:09 |
|   5 |     INDEX FAST FULL SCAN      | OSCP_SOPL01  |   223K|  3057K|   203   (1)| 00:00:03 |
|   6 |   NESTED LOOPS                |              |       |       |            |          |
|   7 |    NESTED LOOPS               |              |  2509 |   445K|  5727   (1)| 00:01:09 |
|   8 |     SORT UNIQUE               |              |  2509 | 55198 |  4470   (1)| 00:00:54 |
|*  9 |      INDEX FAST FULL SCAN     | OSCP_SCUR01  |  2509 | 55198 |  4470   (1)| 00:00:54 |
|* 10 |     INDEX UNIQUE SCAN         | OSCP_STUD01  |     1 |       |     0   (0)| 00:00:01 |
|* 11 |    TABLE ACCESS BY INDEX ROWID| OST_STUDENT  |     1 |   160 |     1   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("ITEM_1"="OST_STUDENT"."STUDENTNUMMER")
   3 - access("OST_STUDENT_INSCHRIJFHIST"."STUDENTNUMMER"="OST_STUDENT_OPLEIDING"."STU
              DENTNUMMER" AND "OST_STUDENT_INSCHRIJFHIST"."OPLEIDING"="OST_STUDENT_OPLEIDING"."OPLEI
              DING")
   4 - filter("OSP_HERIN_AANWEZIG"("OST_STUDENT_INSCHRIJFHIST"."STUDENTNUMMER",'2011')
              ='N')
   9 - filter("OST_STUDENT_CURSUS"."COLLEGEJAAR"=2011)
  10 - access("OST_STUDENT_CURSUS"."STUDENTNUMMER"="OST_STUDENT"."STUDENTNUMMER")
       filter("OST_STUDENT"."STUDENTNUMMER" NOT LIKE 'F%')
  11 - filter("OST_STUDENT"."OVERLIJDENSDATUM" IS NULL)


Statistics
----------------------------------------------------------
     559972  recursive calls
          0  db block gets
    1717082  consistent gets
          0  physical reads
          0  redo size
      66109  bytes sent via SQL*Net to client
        810  bytes received via SQL*Net from client
         28  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
        395  rows processed



And the same analysis done on the old server which is fast :- 



11:20:56 SQL> /

       SID       SEQ# EVENT                                                            P1TEXT                                                                   P1 P1RAW
---------- ---------- ---------------------------------------------------------------- ---------------------------------------------------------------- ---------- ----------------
P2TEXT                                                                   P2 P2RAW            P3TEXT                                                                   P3 P3RAW    WAIT_CLASS_ID
---------------------------------------------------------------- ---------- ---------------- ---------------------------------------------------------------- ---------- ---------------- -------------
WAIT_CLASS# WAIT_CLASS                                                        WAIT_TIME SECONDS_IN_WAIT STATE               WAIT_TIME_MICRO TIME_REMAINING_MICRO TIME_SINCE_LAST_WAIT_MICRO
----------- ---------------------------------------------------------------- ---------- --------------- ------------------- --------------- -------------------- --------------------------
      1756        465 SQL*Net message to client                                        driver id                                                        1650815232 0000000062657100
#bytes                                                                    1 0000000000000001                                                                           0 00          2000153315
          7 Network                                                                  -1              14 WAITED SHORT TIME                 1                                        14341314


Elapsed: 00:00:00.00
11:20:57 SQL> /

       SID       SEQ# EVENT                                                            P1TEXT                                                                   P1 P1RAW
---------- ---------- ---------------------------------------------------------------- ---------------------------------------------------------------- ---------- ----------------
P2TEXT                                                                   P2 P2RAW            P3TEXT                                                                   P3 P3RAW    WAIT_CLASS_ID
---------------------------------------------------------------- ---------- ---------------- ---------------------------------------------------------------- ---------- ---------------- -------------
WAIT_CLASS# WAIT_CLASS                                                        WAIT_TIME SECONDS_IN_WAIT STATE               WAIT_TIME_MICRO TIME_REMAINING_MICRO TIME_SINCE_LAST_WAIT_MICRO
----------- ---------------------------------------------------------------- ---------- --------------- ------------------- --------------- -------------------- --------------------------
      1756        594 SQL*Net message from client                                      driver id                                                        1650815232 0000000062657100
#bytes                                                                    1 0000000000000001                                                                           0 00          2723168908
          6 Idle                                                                      0               0 WAITING                        7041                   -1                  0




395 rows selected.

Elapsed: 00:00:15.38

Execution Plan
----------------------------------------------------------
Plan hash value: 1184574360

----------------------------------------------------------------------------------------------
| Id  | Operation                     | Name         | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |              |   127 | 23876 |  6652   (2)| 00:01:20 |
|*  1 |  HASH JOIN RIGHT SEMI         |              |   127 | 23876 |  6652   (2)| 00:01:20 |
|   2 |   VIEW                        | VW_SQ_1      |  5877 | 35262 |   925  (10)| 00:00:12 |
|*  3 |    HASH JOIN                  |              |  5877 |   160K|   925  (10)| 00:00:12 |
|*  4 |     INDEX FAST FULL SCAN      | OSI_SINH01_1 |  5877 | 82278 |   720  (13)| 00:00:09 |
|   5 |     INDEX FAST FULL SCAN      | OSCP_SOPL01  |   223K|  3057K|   203   (1)| 00:00:03 |
|   6 |   NESTED LOOPS                |              |       |       |            |          |
|   7 |    NESTED LOOPS               |              |  2509 |   445K|  5727   (1)| 00:01:09 |
|   8 |     SORT UNIQUE               |              |  2509 | 55198 |  4470   (1)| 00:00:54 |
|*  9 |      INDEX FAST FULL SCAN     | OSCP_SCUR01  |  2509 | 55198 |  4470   (1)| 00:00:54 |
|* 10 |     INDEX UNIQUE SCAN         | OSCP_STUD01  |     1 |       |     0   (0)| 00:00:01 |
|* 11 |    TABLE ACCESS BY INDEX ROWID| OST_STUDENT  |     1 |   160 |     1   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("ITEM_1"="OST_STUDENT"."STUDENTNUMMER")
   3 - access("OST_STUDENT_INSCHRIJFHIST"."STUDENTNUMMER"="OST_STUDENT_OPLEIDING"."STU
              DENTNUMMER" AND "OST_STUDENT_INSCHRIJFHIST"."OPLEIDING"="OST_STUDENT_OPLEIDING"."OPLEI
              DING")
   4 - filter("OSP_HERIN_AANWEZIG"("OST_STUDENT_INSCHRIJFHIST"."STUDENTNUMMER",'2011')
              ='N')
   9 - filter("OST_STUDENT_CURSUS"."COLLEGEJAAR"=2011)
  10 - access("OST_STUDENT_CURSUS"."STUDENTNUMMER"="OST_STUDENT"."STUDENTNUMMER")
       filter("OST_STUDENT"."STUDENTNUMMER" NOT LIKE 'F%')
  11 - filter("OST_STUDENT"."OVERLIJDENSDATUM" IS NULL)


Statistics
----------------------------------------------------------
     559972  recursive calls
          0  db block gets
    1717248  consistent gets
          0  physical reads
          0  redo size
      97355  bytes sent via SQL*Net to client
       2691  bytes received via SQL*Net from client
        199  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
        395  rows processed





Explain plan is exactly the same in both the queries .. recursive calls , db block gets , consistent gets , physical reads, redo size are all same .. 
bytes sent via SQL*Net to client , bytes received via SQL*Net from client , SQL*Net roundtrips to/from client are more in the old server (which is running fast ) .. 
Can that be the reason for old server running fast and new one running slow .. Can we set some parameters for that ? 

Some more information:- 

Old is Physical Server and New is 

Database size is exactly the same in the both the servers :- 45 GB 

Memory on OLD server is 8 GB and new server is 16 GB .. 

Os on OLD server is :0 

SUSE Linux Enterprise Server 10 (x86_64)
VERSION = 10
PATCHLEVEL = 2


And on New server is :- 

Oracle Linux Server release 5.7 


Please provide your thought on this .. Is there any other thing we can check .. If the database is exact copy (manual offline backup) but performs differently on different servers
can i say that the problem is in the Server not in the database or can there be any setting which needs to be changed on the database ..  

Tom Kyte
April 27, 2012 - 8:24 am UTC

how about you get a tkprof from both.

and please realize that your select output above from the V$ tables is useless. a) it is not readable at all. b) it provides nothing of interest - it shows a point in time wait - not the waits experienced by each query in its entirety.



forgetting the OS's for a second here - what are the machine configurations.

SQL Query

A reader, May 01, 2012 - 3:59 am UTC

Hi Tom,

I have a table which has around million of rows. The basic thing I want to achieve here is:

CREATE TABLE DEMO(Quote_ID VARCHAR2(10), id varchar2(10), latestversion varchar2(10));

insert into demo values(NULL,'Q-1','Q-1-4');
insert into demo values('Q-1','Q-1-1',NULL);
insert into demo values('Q-1','Q-1-2',NULL);
insert into demo values('Q-1','Q-1-3',NULL);
insert into demo values('Q-1','Q-1-4',NULL);
insert into demo values('Q-1','Q-1-5',NULL);

insert into demo values(NULL,'Q-2','Q-2');

My expected result is:

<u>
Quote_ID  id     latestversion    FLAG
</u>
NULL      Q-1     Q-1-4           FALSE
Q-1       Q-1-1   NULL            FALSE
Q-1       Q-1-2   NULL            FALSE
Q-1       Q-1-3   NULL            FALSE
Q-1       Q-1-4   NULL            TRUE
Q-1       Q-1-5   NULL            FALSE
NULL      Q-2     Q-2             TRUE



Logic: There is LATESTVERSION value where QuoteID is blank for a given quote id. One quote ID can have multiple child ID like Q-1, Q-1-1 and so on..

Now I have to mark a flag where the value in LATESTVERSION = ID column as TRUE rest must be marked as BLANK.

I did try with self join to achieve this but since the table is having many rows so I am not sure about the best method.

Could you please help.
Tom Kyte
May 01, 2012 - 3:41 pm UTC

can a child have a child or does the hierarchy only go one level deep?

Followup

A reader, May 01, 2012 - 4:41 pm UTC

It can go only one level deep.

One parent Q-1
Multiple children: Q-1-1, Q-1-2

select a.quote_id, a.id, a.latestversion,
case when (select count(*) from demo b where a.id=b.latestversion) > 0 then 'TRUE' ELSE 'FALSE' END FLAG
from demo a;

I did something like that.
Tom Kyte
May 02, 2012 - 12:36 pm UTC

ops$tkyte%ORA11GR2> select quote_id, id, latestversion,
  2         case when max(latestversion) over (partition by nvl(quote_id,id)) = id
  3              then 'TRUE'
  4              else 'FALSE'
  5          end flag
  6    from t
  7   order by nvl(quote_id,id), id;

QUOTE_ID   ID         LATESTVERS FLAG
---------- ---------- ---------- -----
           Q-1        Q-1-4      FALSE
Q-1        Q-1-1                 FALSE
Q-1        Q-1-2                 FALSE
Q-1        Q-1-3                 FALSE
Q-1        Q-1-4                 TRUE
Q-1        Q-1-5                 FALSE
           Q-2        Q-2        TRUE

7 rows selected.


Creating foreign keys in Oracle 11g

A reader, May 01, 2012 - 8:48 pm UTC

Hi Tom,

I'm using Oracle 11g, a latest version for windows 7.

I have a parent table named Course(CourseNo, Quarter, Daytime), and all columns are primary keys. And, a child table named Student(CourseNo, Quarter, name), and CourseNo and Quarter are primary keys in Student table. They are also foreign keys of the Course table.

I couldn't create these foreign keys by using "Database Control - Orcl" of Oracle 11 g. I got the error which is "no matching primary keys" even though i defined the same type and same size for CourseNo and Quarter columns. The number of foreign keys here is the same the number of primary keys which are referenced to.

I could create foreign keys successfully if the foreign keys are not primary keys in child table.

Please help me with this problem. Thanks so much!
Tom Kyte
May 02, 2012 - 1:19 pm UTC

huh?

I could create foreign keys successfully if the foreign keys are not primary
keys in child table.


I don't know what you mean there?


but basically - if courseno, quarter are a foreign key in student, then there must exist a table whose primary key is courseno,quarter to point to!


Your data model is very very wacky. I believe it to be entirely wrong actually.


Seems like COURSE would be a table with a primary key of COURSENO

And there would be a table COURSE_BY_QUARTER whose key would be courseno and quarter, with courseno as a foreign key to course

and a table COURSE_SCHEDULES whose key would be courseno, quarter and daytime, with courseno, quarter being a foreign key to course_by_quarter.


then there would be a table STUDENT whose key would be student_no

and a table STUDENT_COURSES whose key would be student_no, courseno, quarter, daytime. And this table would have a foreign key student_no pointing to student and courseno, quarter, daytime pointing to course_schedules

Thanks Tom for the reply

A reader, May 02, 2012 - 1:26 pm UTC


Creating foreign keys in Oracle 11g

A reader, May 03, 2012 - 3:38 am UTC

Thanks for your reply.

I know it could be a bad database design, but
It's just an example to study about queries and create foreign keys. I've just started to learn about Oracle. Please let me explain my point again.

* Course Table:
Course(CourseNo, Quarter, Daytime, RoomNumber) and
(CourseNo, Quarter, Daytime, RoomNumber) are primary keys.

* Student Table :
Student(student_name, CourseNo, Quarter)
and (student_name, CourseNo, Quarter) are primary keys,
assumes that (CourseNo, Quarter) in Student table are foreign keys of Course table.

I used "Database Control - Orcl" or GUI of Oracle 11 g to create foreign key constraint. I just click on columns in tables to choose what columns (foreign keys) point to what columns (primary keys). Because i use Oracle GUI, so i don't need to write DDL for this constraint, but click to choose attributes/columns. Basically, general sql should be like this:

Alter table Student Add Foreign key (CourseNo) References Course (CourseNo)

Alter table Student Add Foreign key (Quarter) References Course (Quarter)

But, Oracle 11g GUI did not create those foreign keys successfully.


** But creating foreign keys by using Oracle 11g GUI was successful with the following table:

* Table_1(col_1, col_2, col_3), and col_1 is a primary key.

* Table_2(col_1, col_22, column_33, col_44)
and (col_1, col_22, column_33) are primary keys in Table_2

col_1 in Table_2 points to col_1 in Table_1.
Oracle GUI could create a foreign key for this case successfully. Is it because Table_1 in this case has only one primary key? It doesn't make sense.

For the error in the first case, i got "no matching unique or primary key". Please help me understand why i got this error or couldn't create foreign keys even though i defined same data size and type for columns which are considered primary keys and foreign keys.


Thanks so much for your reply.









Tom Kyte
May 03, 2012 - 8:59 am UTC

GUI or not - a foreign key needs a matching (same number of columns) primary or unique key to point to. All databases would.


you need a primary key that matches your foreign key in NUMBER of columns as well as TYPEs

You don't have that.

SQL Tuning

Lal, May 16, 2012 - 1:21 am UTC

Tom,

I have the following query which involves eight outer joins

<code>SELECT TIRACT.TYP,
  ACT.ACTNUM,
  ACT.ACTDES,
  ACT.ACTDAT,
  ACT.CANFLG,
  OTHLNG.MUTLIGDES,
  OTHLNG.LNGCOD,
  ACT.ACTTYP,
  (SELECT ONE.FLDDES
  FROM COMONETIM ONE
  WHERE ONE.FLDCOD = 'activityType'
  AND ACT.ACTTYP   = ONE.FLDVAL
  AND ACT.CMPCOD   = ONE.CMPCOD
  ) ACTTYPDESC,
  (SELECT ONE.FLDDES
  FROM COMONETIM ONE
  WHERE ONE.FLDCOD = 'activityStatus'
  AND ACT.ACTSTA   = ONE.FLDVAL
  AND ACT.CMPCOD   = ONE.CMPCOD
  ) ACTSTA,
  ACT.CANACTNUM,
  ACT.USRCOD,
  PNT.DISNAM,
  PNT.PNTTYP,
  TXN.TXNTYP,
  TXN.TXNACTTYP,
  TXN.PNT,
  TXN.TXNNUM,
  TXN.PAYTXNFLG,
  TXN.BNSCOD,
  B.BNSNAM ,
  TIRACT.RMK TCRMK,
  CHGPNTACT.RMK MURMK,
  ACT.ACTTYP,
  (SELECT ONE.FLDDES
  FROM COMONETIM ONE
  WHERE ONE.FLDCOD     = 'manualChangeReason'
  AND CHGPNTACT.RSNCOD = ONE.FLDVAL
  AND CHGPNTACT.CMPCOD = ONE.CMPCOD
  )MURSN,
  CHGPNTACT.RSNCOD MURSNCOD,
  (SELECT ONE.FLDDES
  FROM COMONETIM ONE
  WHERE ONE.FLDCOD  = 'tierChangeReason'
  AND TIRACT.RSNCOD = ONE.FLDVAL
  AND TIRACT.CMPCOD = ONE.CMPCOD
  ) TCRSN,
  TIRACT.RSNCOD TCRSNCOD,
  (SELECT ACT1.ACTTYP
  FROM ACT ACT1
  WHERE ACT1.CMPCOD = ACT.CMPCOD
  AND ACT1.PRGCOD   = ACT1.PRGCOD
  AND ACT.MEMSHPNUM = ACT1.MEMSHPNUM
  AND ACT1.ACTNUM   = ACT.DPNACTNUM
  ) PRTACTTYP,
  ACRACT.ACTREFNUM,
  (SELECT ONE.FLDDES
  FROM COMONETIM ONE
  WHERE ONE.FLDCOD  = 'actionReasons'
  AND ACTPRG.RSNCOD = ONE.FLDVAL
  AND ACTPRG.CMPCOD = ONE.CMPCOD
  ) ACRRSN,
  ACTPRG.RSNCOD ,
  (SELECT MAX(STMMST.STMGENDAT)
  FROM STMMST STMMST
  WHERE STMMST.CMPCOD  = ACT.CMPCOD
  AND STMMST.PRGCOD    = ACT.PRGCOD
  AND STMMST.MEMSHPNUM = ACT.MEMSHPNUM
  AND STMMST.STMIDR   IN
    (SELECT STMIDR
    FROM STMACTDTL STMDTL
    WHERE STMDTL.CMPCOD  = ACT.CMPCOD
    AND STMDTL.PRGCOD    = ACT.PRGCOD
    AND STMDTL.MEMSHPNUM = ACT.MEMSHPNUM
    AND STMDTL.ACTNUM    = ACT.ACTNUM
    )
  AND STMMST.STMTYP = 'O'
  ) STMDAT
FROM ACT ACT
LEFT OUTER JOIN PNTTXN TXN
ON ACT.CMPCOD  = TXN.CMPCOD
AND ACT.PRGCOD = TXN.PRGCOD
AND ACT.ACTNUM = TXN.ACTNUM
LEFT OUTER JOIN PNTTYPMST PNT
ON TXN.CMPCOD  = PNT.CMPCOD
AND TXN.PRGCOD = PNT.PRGCOD
AND PNT.PNTTYP = TXN.PNTTYP
LEFT OUTER JOIN COMBNSMST B
ON TXN.BNSCOD =B.BNSCOD
AND TXN.CMPCOD=B.CMPCOD
LEFT OUTER JOIN PRGTIRCHGACT TIRACT
ON ACT.CMPCOD  = TIRACT.CMPCOD
AND ACT.ACTNUM =TIRACT.ACTNUM
AND ACT.PRGCOD =TIRACT.PRGCOD
LEFT OUTER JOIN PRGMANACCUPDACT CHGPNTACT
ON ACT.CMPCOD  = CHGPNTACT.CMPCOD
AND ACT.ACTNUM =CHGPNTACT.ACTNUM
AND ACT.PRGCOD = CHGPNTACT.PRGCOD
LEFT OUTER JOIN ACTOTHLNGDES OTHLNG
ON ACT.CMPCOD  = OTHLNG.CMPCOD
AND ACT.PRGCOD = OTHLNG.PRGCOD
AND ACT.ACTNUM = OTHLNG.ACTNUM
LEFT OUTER JOIN ACRACT ACRACT
ON ACT.CMPCOD  = ACRACT.CMPCOD
AND ACT.PRGCOD =ACRACT.PRGCOD
AND ACT.ACTNUM =ACRACT.ACTNUM
LEFT OUTER JOIN ACRACTPRG ACTPRG
ON ACRACT.CMPCOD          =ACTPRG.CMPCOD
AND ACRACT.PRGCOD         = ACTPRG.PRGCOD
AND ACRACT.ACTREFNUM      = ACTPRG.ACTREFNUM
WHERE ACT.CMPCOD          = 'XX'
AND (ACT.HIDACT           = '0'
OR ACT.HIDACT            IS NULL)
AND ACT.PRGCOD            = 'XXX'
AND ACT.MEMSHPNUM         = '999999'
AND ACT.ACTDAT           >= to_date('01-Jan-2011 00:00:00','dd-MON-yyyy hh24:mi:ss')
AND ACT.ACTDAT           <= to_date('20-Jan-2012 12:23:00','dd-MON-yyyy hh24:mi:ss')
AND NOT ((ACT.ACTTYP      = 'CA'
AND ACT.USRCOD            = 'SYSTEM')
OR ((ACT.ACTTYP           = 'TC'
AND ACT.ACTSTA            = 'C')
AND ACT.USRCOD            = 'SYSTEM'))
AND NOT (ACT.ACTTYP       = 'CA'
OR ACT.ACTSTA             = 'C')
AND PNT.INTFLG            = '0'
AND PNT.DPNFLG            = '0'
AND NVL(TIRACT.TYP, 'M') IN ('M','C')
ORDER BY ACT.ACTDAT DESC, ACT.ACTNUM

The query uses a good plan (based on my understanding)
This takes on an average 3 - 5 secs if the data is not available in cache, which would mostly be the scenario for this query.

Following section shows the trace details

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.66       0.97         50       1104          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        1      0.34       5.28        700       1630          0          50
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3      1.00       6.25        750       2734          0          50

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 132  (ILOYESUAT)

Rows     Row Source Operation
-------  ---------------------------------------------------
      2  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=6 pr=1 pw=0 time=0 us cost=2 size=59 card=1)
      2   INDEX UNIQUE SCAN COMONETIM_PK (cr=4 pr=1 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      1  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=3 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      1   INDEX UNIQUE SCAN COMONETIM_PK (cr=2 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      0  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=0 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      0   INDEX UNIQUE SCAN COMONETIM_PK (cr=0 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      0  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=0 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      0   INDEX UNIQUE SCAN COMONETIM_PK (cr=0 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      0  TABLE ACCESS BY INDEX ROWID ACT (cr=0 pr=0 pw=0 time=0 us cost=58 size=38 card=1)
      0   INDEX SKIP SCAN ACT_PK (cr=0 pr=0 pw=0 time=0 us cost=57 size=0 card=1)(object id 221722)
      0  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=0 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      0   INDEX UNIQUE SCAN COMONETIM_PK (cr=0 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
     96  SORT AGGREGATE (cr=3 pr=1 pw=0 time=0 us)
      0   NESTED LOOPS  (cr=3 pr=1 pw=0 time=0 us cost=2 size=75 card=1)
      0    TABLE ACCESS BY INDEX ROWID STMMST (cr=3 pr=1 pw=0 time=0 us cost=2 size=38 card=1)
      0     INDEX RANGE SCAN STMMST_PK (cr=3 pr=1 pw=0 time=0 us cost=1 size=0 card=1)(object id 214289)
      0    INDEX UNIQUE SCAN STMACTDTL_PK (cr=0 pr=0 pw=0 time=0 us cost=0 size=37 card=1)(object id 214285)
     50  SORT ORDER BY (cr=1630 pr=700 pw=0 time=46 us cost=50 size=1008 card=2)
    525   NESTED LOOPS OUTER (cr=1618 pr=698 pw=0 time=822453 us cost=49 size=1008 card=2)
    175    HASH JOIN  (cr=1039 pr=548 pw=0 time=355 us cost=45 size=387 card=1)
    175     NESTED LOOPS OUTER (cr=1037 pr=548 pw=0 time=4022783 us cost=42 size=1745 card=5)
    175      NESTED LOOPS  (cr=1037 pr=548 pw=0 time=4022225 us cost=42 size=1530 card=5)
     92       NESTED LOOPS OUTER (cr=676 pr=300 pw=0 time=1948538 us cost=30 size=780 card=3)
     92        NESTED LOOPS OUTER (cr=428 pr=201 pw=0 time=1383897 us cost=24 size=723 card=3)
     92         FILTER  (cr=160 pr=101 pw=0 time=604753 us)
     93          NESTED LOOPS OUTER (cr=160 pr=101 pw=0 time=604567 us cost=19 size=642 card=3)
     93           NESTED LOOPS OUTER (cr=131 pr=95 pw=0 time=585340 us cost=11 size=1330 card=7)
     93            TABLE ACCESS BY INDEX ROWID ACT (cr=114 pr=92 pw=0 time=574645 us cost=10 size=1057 card=7)
    203             INDEX RANGE SCAN ACT_MEMACTDAT_IDX (cr=5 pr=5 pw=0 time=3376 us cost=4 size=0 card=8)(object id 221989)
      0            TABLE ACCESS BY INDEX ROWID PRGMANACCUPDACT (cr=17 pr=3 pw=0 time=0 us cost=1 size=39 card=1)
      0             INDEX UNIQUE SCAN PRGMANACCUPDACT_PK (cr=17 pr=3 pw=0 time=0 us cost=0 size=0 card=1)(object id 221697)
      1           TABLE ACCESS BY INDEX ROWID PRGTIRCHGACT (cr=29 pr=6 pw=0 time=0 us cost=2 size=24 card=1)
      1            INDEX UNIQUE SCAN PRGTIRCHGACT_PK (cr=28 pr=5 pw=0 time=0 us cost=1 size=0 card=1)(object id 221716)
     82         TABLE ACCESS BY INDEX ROWID ACRACT (cr=268 pr=100 pw=0 time=0 us cost=2 size=27 card=1)
     82          INDEX UNIQUE SCAN ACRACT_PK (cr=186 pr=58 pw=0 time=0 us cost=1 size=0 card=1)(object id 221700)
     82        TABLE ACCESS BY INDEX ROWID ACRACTPRG (cr=248 pr=99 pw=0 time=0 us cost=2 size=19 card=1)
     82         INDEX UNIQUE SCAN ACRACTPGM_PK (cr=166 pr=57 pw=0 time=0 us cost=1 size=0 card=1)(object id 221990)
    175       TABLE ACCESS BY INDEX ROWID PNTTXN (cr=361 pr=248 pw=0 time=718934 us cost=4 size=92 card=2)
    175        INDEX RANGE SCAN PNTTXN_PK (cr=186 pr=79 pw=0 time=122 us cost=2 size=0 card=2)(object id 221717)
      0      TABLE ACCESS BY INDEX ROWID COMBNSMST (cr=0 pr=0 pw=0 time=0 us cost=0 size=43 card=1)
      0       INDEX UNIQUE SCAN COMBNSMST_PK (cr=0 pr=0 pw=0 time=0 us cost=0 size=0 card=1)(object id 221719)
      4     TABLE ACCESS BY INDEX ROWID PNTTYPMST (cr=2 pr=0 pw=0 time=8 us cost=2 size=76 card=2)
      4      INDEX RANGE SCAN PNTTYPMST_PK (cr=1 pr=0 pw=0 time=2 us cost=1 size=0 card=4)(object id 221720)
    525    TABLE ACCESS BY INDEX ROWID ACTOTHLNGDES (cr=579 pr=150 pw=0 time=64633 us cost=4 size=351 card=3)
    525     INDEX RANGE SCAN ACTOTHLNGDES_PK (cr=356 pr=84 pw=0 time=809 us cost=2 size=0 card=3)(object id 221721)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  latch: shared pool                              1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  Disk file operations I/O                        2        0.00          0.00
  db file sequential read                       700        0.16          5.20
  SQL*Net message from client                     1        7.02          7.02
********************************************************************************

Is it possible to optimise this to below 1 sec.
Should i try some hints in this case or create an MV with all the eight tables?

Do you find any issue with the plan?

ACT table stores the activity data(262912 blocks and 8741426 rows).
PNTTXN stores the transactions for each activity (409600 blocks and 23844734 rows)
ACTOTHLNGDES stores the activity description in different languages. (3 records for each activity) (124928 blocks and 15062133 rows).
Rest of the tables fecth one row per activity.

One of issue we noticed was since ACTOTHLNGDES has three rows for each activity and if one activity has 5 transactions 15 rows will be generated, the duplication can be avoided by applying listagg function on ACTOTHLNGDES such that the descriptions in different languages are made to one rows. This was done using a with clause and then the result was joined to the transaction and other tables. This also took the same time.

The trace details using listagg and with clause

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.66       0.97         50       1104          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        1      0.34       5.28        700       1630          0          50
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        3      1.00       6.25        750       2734          0          50

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 132  (ILOYESUAT)

Rows     Row Source Operation
-------  ---------------------------------------------------
      2  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=6 pr=1 pw=0 time=0 us cost=2 size=59 card=1)
      2   INDEX UNIQUE SCAN COMONETIM_PK (cr=4 pr=1 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      1  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=3 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      1   INDEX UNIQUE SCAN COMONETIM_PK (cr=2 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      0  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=0 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      0   INDEX UNIQUE SCAN COMONETIM_PK (cr=0 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      0  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=0 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      0   INDEX UNIQUE SCAN COMONETIM_PK (cr=0 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
      0  TABLE ACCESS BY INDEX ROWID ACT (cr=0 pr=0 pw=0 time=0 us cost=58 size=38 card=1)
      0   INDEX SKIP SCAN ACT_PK (cr=0 pr=0 pw=0 time=0 us cost=57 size=0 card=1)(object id 221722)
      0  TABLE ACCESS BY INDEX ROWID COMONETIM (cr=0 pr=0 pw=0 time=0 us cost=2 size=59 card=1)
      0   INDEX UNIQUE SCAN COMONETIM_PK (cr=0 pr=0 pw=0 time=0 us cost=1 size=0 card=1)(object id 214632)
     96  SORT AGGREGATE (cr=3 pr=1 pw=0 time=0 us)
      0   NESTED LOOPS  (cr=3 pr=1 pw=0 time=0 us cost=2 size=75 card=1)
      0    TABLE ACCESS BY INDEX ROWID STMMST (cr=3 pr=1 pw=0 time=0 us cost=2 size=38 card=1)
      0     INDEX RANGE SCAN STMMST_PK (cr=3 pr=1 pw=0 time=0 us cost=1 size=0 card=1)(object id 214289)
      0    INDEX UNIQUE SCAN STMACTDTL_PK (cr=0 pr=0 pw=0 time=0 us cost=0 size=37 card=1)(object id 214285)
     50  SORT ORDER BY (cr=1630 pr=700 pw=0 time=46 us cost=50 size=1008 card=2)
    525   NESTED LOOPS OUTER (cr=1618 pr=698 pw=0 time=822453 us cost=49 size=1008 card=2)
    175    HASH JOIN  (cr=1039 pr=548 pw=0 time=355 us cost=45 size=387 card=1)
    175     NESTED LOOPS OUTER (cr=1037 pr=548 pw=0 time=4022783 us cost=42 size=1745 card=5)
    175      NESTED LOOPS  (cr=1037 pr=548 pw=0 time=4022225 us cost=42 size=1530 card=5)
     92       NESTED LOOPS OUTER (cr=676 pr=300 pw=0 time=1948538 us cost=30 size=780 card=3)
     92        NESTED LOOPS OUTER (cr=428 pr=201 pw=0 time=1383897 us cost=24 size=723 card=3)
     92         FILTER  (cr=160 pr=101 pw=0 time=604753 us)
     93          NESTED LOOPS OUTER (cr=160 pr=101 pw=0 time=604567 us cost=19 size=642 card=3)
     93           NESTED LOOPS OUTER (cr=131 pr=95 pw=0 time=585340 us cost=11 size=1330 card=7)
     93            TABLE ACCESS BY INDEX ROWID ACT (cr=114 pr=92 pw=0 time=574645 us cost=10 size=1057 card=7)
    203             INDEX RANGE SCAN ACT_MEMACTDAT_IDX (cr=5 pr=5 pw=0 time=3376 us cost=4 size=0 card=8)(object id 221989)
      0            TABLE ACCESS BY INDEX ROWID PRGMANACCUPDACT (cr=17 pr=3 pw=0 time=0 us cost=1 size=39 card=1)
      0             INDEX UNIQUE SCAN PRGMANACCUPDACT_PK (cr=17 pr=3 pw=0 time=0 us cost=0 size=0 card=1)(object id 221697)
      1           TABLE ACCESS BY INDEX ROWID PRGTIRCHGACT (cr=29 pr=6 pw=0 time=0 us cost=2 size=24 card=1)
      1            INDEX UNIQUE SCAN PRGTIRCHGACT_PK (cr=28 pr=5 pw=0 time=0 us cost=1 size=0 card=1)(object id 221716)
     82         TABLE ACCESS BY INDEX ROWID ACRACT (cr=268 pr=100 pw=0 time=0 us cost=2 size=27 card=1)
     82          INDEX UNIQUE SCAN ACRACT_PK (cr=186 pr=58 pw=0 time=0 us cost=1 size=0 card=1)(object id 221700)
     82        TABLE ACCESS BY INDEX ROWID ACRACTPRG (cr=248 pr=99 pw=0 time=0 us cost=2 size=19 card=1)
     82         INDEX UNIQUE SCAN ACRACTPGM_PK (cr=166 pr=57 pw=0 time=0 us cost=1 size=0 card=1)(object id 221990)
    175       TABLE ACCESS BY INDEX ROWID PNTTXN (cr=361 pr=248 pw=0 time=718934 us cost=4 size=92 card=2)
    175        INDEX RANGE SCAN PNTTXN_PK (cr=186 pr=79 pw=0 time=122 us cost=2 size=0 card=2)(object id 221717)
      0      TABLE ACCESS BY INDEX ROWID COMBNSMST (cr=0 pr=0 pw=0 time=0 us cost=0 size=43 card=1)
      0       INDEX UNIQUE SCAN COMBNSMST_PK (cr=0 pr=0 pw=0 time=0 us cost=0 size=0 card=1)(object id 221719)
      4     TABLE ACCESS BY INDEX ROWID PNTTYPMST (cr=2 pr=0 pw=0 time=8 us cost=2 size=76 card=2)
      4      INDEX RANGE SCAN PNTTYPMST_PK (cr=1 pr=0 pw=0 time=2 us cost=1 size=0 card=4)(object id 221720)
    525    TABLE ACCESS BY INDEX ROWID ACTOTHLNGDES (cr=579 pr=150 pw=0 time=64633 us cost=4 size=351 card=3)
    525     INDEX RANGE SCAN ACTOTHLNGDES_PK (cr=356 pr=84 pw=0 time=809 us cost=2 size=0 card=3)(object id 221721)

Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  latch: shared pool                              1        0.00          0.00
  SQL*Net message to client                       1        0.00          0.00
  Disk file operations I/O                        2        0.00          0.00
  db file sequential read                       700        0.16          5.20
  SQL*Net message from client                     1        7.02          7.02
********************************************************************************


With listagg and with clause the physical reads was nearly double but the elapsed was slightly less.

Any suggestions to improve the performance of the query?</code>

SQL Tuning

Lal, May 22, 2012 - 10:49 pm UTC

Tom,
Can you please help me to optimise the above query. One thing i noticed was high clustering factor values for indexes on some of the tables. I corrected that by rebuilding the table and got some improvements. Is that approach recommended. That would mean i would need to rebuild the tables periodically to correct the clustering factor.
Any other ways to improve the performance of the above query?.

Tom Kyte
May 23, 2012 - 8:13 am UTC

not really.

i don't know your schema
i don't know how your objects relate
i don't know your data patterns
i don't know the question you are trying to answer with that query

and - I don't really want to here - this is for reviews/followup - not multi-page queries asking to be "tuned"

it doesn't do that much IO, but the fact that 50% of the IO's where physical IO's is what killed you.


I don't think you should go down the path of "clustering factor". Tell me this - was there a significant difference in either of the PLAN or the PERFORMANCE before and after these rebuilds?

SQL Tuning

Lal, May 23, 2012 - 11:43 pm UTC

Tom,

Thanks very much for your time.

The query tries to retrieve the transactions conducted by a customer (public user accessing through web) with associated details such as descriptions in multiple languages for a period - say 6 months to 1 year.
Since the no of customers is high and for each customer the data comes to around 2000 records for 6 months to one year, chances that the data will be in buffer cache will be less and physical io will be required.
The transaction data will be scattered in different blocks, since the inserts happened over a period of one year and hence more blocks needs to be read. By rebuilding the table the data is sorted and only less blocks needs to be read and hence io is reduced.

I created a copy of three tables using create table as and the order by clause to correct the clustering factor and then took SQLT report for query with normal tables and rebuilt tables.
There is no plan change for both cases (In SQLT comparison report only the rebuilt object names are different in the plan).

This is the SQLT comparison figures in one of our internal environments for the same member and with normal tables(s28752_tcc11g_n3170)
and three big tables rebuilt(s28755_tcc11g_n3170) to correct the clustering factor.

Plan Summary
Name       s28752_tcc11g_n3170 s28755_tcc11g_n3170
Plan Hash Value     3673327035    2637567905
SQLT PHV       952     49382
SQLT PHV2       73534     21964
Avg Elapsed Time in secs   7.004     2.551
Avg CPU Time in secs    0.884     0.846
Avg User I/O Wait Time in secs  6.114     1.603
Avg Buffer Gets     7277     2828
Avg Disk Reads      862     591
Avg Direct Writes     0      0
Avg Rows Processed     1362     1362
Total Executions     1      1
Total Fetches      92      92
Total Version Count    1      1
Total Loads      1      1
Total Invalidations    0      0
Is Bind Sensitive     N      N
Min Optimizer Env     1006079955    1006079955
Max Optimizer Env     1006079955    1006079955
Optimizer Cost      50      46
Estimated Cardinality    1      1
Estimated Time in secs    0.600     0.552


We rebuilt the table in production and the performance improved from 30 secs to 5 secs (some cases 10 secs).

This is the first time i am coming across such a scenario, in which the plan seems to be good, but performance got improved after rebuilding the table.
I know that this is a temporary fix. This could be either a table design issue or query issue?

Or the expectation of 1 sec response time for such query is high?

Will partitioning? clustering? iot? help.
If yes which option will be better. (These are all transactional tables with lot of inserts and updates).

I have learned a lot from this site and got my issues resolved.
Expecting a solution for this problem as well. :-)

Tom Kyte
May 24, 2012 - 8:45 am UTC

This is the first time i am coming across such a scenario, in which the plan seems to be good, but performance got improved after rebuilding the table.

you did more than rebuild the table, you physically colocated related rows together - you clustered information together that is queried together. We do that with b*tree clusters, hash clusters, partitioning, IOT's and the like.


Or the expectation of 1 sec response time for such query is high?


if the data were in the buffer cache 100%, no, but give that it takes 1 cpu second just to process the data - if you have to do any IO - you are adding at least 0.005 seconds (for each IO)

You can look for things like this in your row source operations:

     93            TABLE ACCESS BY INDEX ROWID ACT (cr=114 pr=92 pw=0 tim
    203             INDEX RANGE SCAN ACT_MEMACTDAT_IDX (cr=5 pr=5 pw=0 time=3


you see how you found 203 rows in the index, but only 93 of those rows were actually useful.

that means we used the index to do part of the "where" - and had to go to the table to find the rest. Adding another column (or two) to your index ACT_MEMACTDAT_IDX to make it so we just find 93 rows in the index will cut down the amount of work we do on that particular part of the plan would be useful. for example:

create table t
as
select *
  from all_objects
 order by dbms_random.random
/

exec dbms_stats.gather_table_stats( user, 'T' );
create index t_idx on t(owner);

set termout off
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';
set termout on
alter system flush buffer_cache;
set autotrace traceonly statistics
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';
set autotrace off
set termout off
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';
set termout on
select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

drop index t_idx;
create index t_idx on t(owner,object_type);

set termout off
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';
set termout on
alter system flush buffer_cache;
set autotrace traceonly statistics
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';
set autotrace off
set termout off
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';
set termout on
select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));



when I run that, I observe:

ops$tkyte%ORA11GR2> alter system flush buffer_cache;

System altered.

<b>Note: I only did this to MAXIMIZE physical IO's to show the MAX different that could result</b>


ops$tkyte%ORA11GR2> set autotrace traceonly statistics
ops$tkyte%ORA11GR2> select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';

129 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        220  consistent gets
        209  physical reads
          0  redo size
       9651  bytes sent via SQL*Net to client
        508  bytes received via SQL*Net from client
         10  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
        129  rows processed

<b>209 physical reads...</b>

ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> set termout off
ops$tkyte%ORA11GR2> select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  5yzf5rb19d2j3, child number 0
-------------------------------------
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA'
and object_type = 'INDEX'

Plan hash value: 470836197

-----------------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
-----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |      1 |        |    129 |00:00:00.01 |     220 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| T     |      1 |     19 |    129 |00:00:00.01 |     220 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |      1 |    335 |    239 |00:00:00.01 |      11 |
-----------------------------------------------------------------------------------------------

<b>we found 239 rows in the index and had to read 239 rows out of the table - in order to find just 129. Given the data was scattered all over the place, we probably did at least 200 IO's against the table - of which only 129 were relevant (at best)</b>

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("OBJECT_TYPE"='INDEX')
   2 - access("OWNER"='ORDDATA')


21 rows selected.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> drop index t_idx;

Index dropped.

ops$tkyte%ORA11GR2> create index t_idx on t(owner,object_type);

Index created.

<b>build a better index and ...</b>

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set termout off
ops$tkyte%ORA11GR2> alter system flush buffer_cache;

System altered.

ops$tkyte%ORA11GR2> set autotrace traceonly statistics
ops$tkyte%ORA11GR2> select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA' and object_type = 'INDEX';

129 rows selected.


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
        132  consistent gets
        123  physical reads
          0  redo size
       9651  bytes sent via SQL*Net to client
        508  bytes received via SQL*Net from client
         10  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
        129  rows processed

<b>IO's dropped way down - because:</b>

ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> set termout off
ops$tkyte%ORA11GR2> select * from table(dbms_xplan.display_cursor(null,null,'ALLSTATS LAST'));

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
SQL_ID  5yzf5rb19d2j3, child number 0
-------------------------------------
select /*+ gather_plan_statistics */ * from t where owner = 'ORDDATA'
and object_type = 'INDEX'

Plan hash value: 470836197

-----------------------------------------------------------------------------------------------
| Id  | Operation                   | Name  | Starts | E-Rows | A-Rows |   A-Time   | Buffers |
-----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |       |      1 |        |    129 |00:00:00.01 |     132 |
|   1 |  TABLE ACCESS BY INDEX ROWID| T     |      1 |     19 |    129 |00:00:00.01 |     132 |
|*  2 |   INDEX RANGE SCAN          | T_IDX |      1 |     19 |    129 |00:00:00.01 |      12 |
-----------------------------------------------------------------------------------------------

<b>we only went to the table when we HAD to go to the table.,...</b>


Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("OWNER"='ORDDATA' AND "OBJECT_TYPE"='INDEX')


20 rows selected.




SQL Tuning

Lal, May 25, 2012 - 7:16 am UTC

Tom,

Thanks very much for the quick response.

I checked the option for adding more columns to the index ACT_MEMACTDAT_IDX.

But the problem is the additional condition is a not condition having an OR clause.
SELECT ACT.ACTNUM,
  ACT.ACTDES,
  ACT.ACTDAT,
  ACT.CANFLG,
  ACT.ACTTYP
FROM ACT
WHERE ACT.CMPCOD          = 'XX'
AND ACT.PRGCOD            = 'XX'
AND ACT.MEMSHPNUM         = '999999'
AND ACT.ACTDAT           >= TO_TIMESTAMP('01-Jan-2011 00:00:00','dd-MON-yyyy hh24:mi:ss.FF')
AND ACT.ACTDAT           <= TO_TIMESTAMP('20-Jan-2012 12:23:00','dd-MON-yyyy hh24:mi:ss.FF')
AND (ACT.HIDACT           = '0'
OR ACT.HIDACT            IS NULL)
AND NOT ((ACT.ACTTYP      = 'CA'
AND ACT.USRCOD            = 'SYSTEM')
OR ((ACT.ACTTYP           = 'TC'
AND ACT.ACTSTA            = 'C')
AND ACT.USRCOD            = 'SYSTEM'))
AND NOT (ACT.ACTTYP       = 'CA'
OR ACT.ACTSTA             = 'C')

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.03         12         14          0          93
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.00       0.03         12         14          0          93

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 100  
Number of plan statistics captured: 1

Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
        93         93         93  TABLE ACCESS BY INDEX ROWID ACT (cr=14 pr=12 pw=0 time=32538 us cost=5 size=1029 card=7)
       203        203        203   INDEX RANGE SCAN ACT_MEMACTDAT_IDX (cr=6 pr=5 pw=0 time=31989 us cost=4 size=0 card=8)(object id 102539)


Elapsed times include waiting on following events:
  Event waited on                             Times   Max. Wait  Total Waited
  ----------------------------------------   Waited  ----------  ------------
  SQL*Net message to client                       2        0.00          0.00
  Disk file operations I/O                        1        0.00          0.00
  db file sequential read                        12        0.01          0.03
  SQL*Net message from client                     2        9.06         11.40
********************************************************************************


Currently ACT_MEMACTDAT_IDX index has the following columns CMPCOD,PRGCOD,MEMSHPNUM,ACTDAT

The following condition filters data from 203 to 93 rows.
AND NOT (ACT.ACTTYP = 'CA'
OR ACT.ACTSTA = 'C')


I tried creating the following indexes

CREATE INDEX TCC_IDX1 ON ACT (CMPCOD, PRGCOD, MEMSHPNUM, ACTDAT,ACTTYP);
CREATE INDEX TCC_IDX2 ON ACT (CMPCOD, PRGCOD, MEMSHPNUM, ACTDAT,ACTSTA);
CREATE INDEX TCC_IDX3 ON ACT (ACTTYP);
CREATE INDEX TCC_IDX4 ON ACT (ACTSTA);


but none of the new indexes were taken by the optimiser.
Is it due to the NOT and OR conditions?

For this specific table only 12 blocks are accessed, the rest of the joins might be the problematic ones for the main query.

So i think the best way is to use the options you mentioned like partitioning, clustering, iot etc.

Which approach is better for my case?
Partitioning i prefer as the last option due to the extra cost.

Which approach to choose from clustering and IOT?
Also will creating a materialised view help?
Tom Kyte
May 25, 2012 - 9:24 am UTC

give us the autotrace traceonly explain - it'll show the processing of the predicate step by step - that is much easier to read...

SQL Tuning

Lal, June 01, 2012 - 1:46 am UTC

Tom,
Very sorry for the late reply. This is the result of autotrace traceonly explain for the query.

SQL> set autotrace traceonly explain;
SQL> SELECT ACT.ACTNUM,
  2    ACT.ACTDES,
  3    ACT.ACTDAT,
  4    ACT.CANFLG,
  5    ACT.ACTTYP
  6  FROM ACT
  7  WHERE ACT.CMPCOD     = 'XX'
  8  AND ACT.PRGCOD       = 'XX'
  9  AND ACT.MEMSHPNUM    = '999999'
 10  AND ACT.ACTDAT      >= TO_TIMESTAMP('01-Jan-2011 00:00:00','dd-MON-yyyy hh24:mi:ss.FF')
 11  AND ACT.ACTDAT      <= TO_TIMESTAMP('20-Jan-2012 12:23:00','dd-MON-yyyy hh24:mi:ss.FF')
 12  AND (ACT.HIDACT      = '0'
 13  OR ACT.HIDACT       IS NULL)
 14  AND NOT ((ACT.ACTTYP = 'CA'
 15  AND ACT.USRCOD       = 'SYSTEM')
 16  OR ((ACT.ACTTYP      = 'TC'
 17  AND ACT.ACTSTA       = 'C')
 18  AND ACT.USRCOD       = 'SYSTEM'))
 19  AND NOT (ACT.ACTTYP  = 'CA'
 20  OR ACT.ACTSTA        = 'C') ;

Execution Plan
----------------------------------------------------------
Plan hash value: 1789970264

-------------------------------------------------------------------------------------------------
| Id  | Operation                   | Name              | Rows  | Bytes | Cost (%CPU)| Time     |
-------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT            |                   |     7 |  1029 |     5  (0)| 00:00:01 |
|*  1 |  TABLE ACCESS BY INDEX ROWID| ACT               |     7 |  1029 |     5  (0)| 00:00:01 |
|*  2 |   INDEX RANGE SCAN          | ACT_MEMACTDAT_IDX |     8 |       |     4  (0)| 00:00:01 |
-------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - filter("ACT"."ACTSTA"<>'C' AND "ACT"."ACTTYP"<>'CA' AND ("ACT"."HIDACT"='0' OR
              "ACT"."HIDACT" IS NULL))
   2 - access("ACT"."CMPCOD"='XX' AND "ACT"."PRGCOD"='XX' AND
              "ACT"."MEMSHPNUM"='999999' AND "ACT"."ACTDAT">=TIMESTAMP' 2011-01-01
              00:00:00.000000000' AND "ACT"."ACTDAT"<=TIMESTAMP' 2012-01-20 12:23:00.000000000')

Tom Kyte
June 01, 2012 - 6:55 am UTC

from the tkprof we can see we found 203 rows in the index:


Rows (1st) Rows (avg) Rows (max)  Row Source Operation
---------- ---------- ----------  ---------------------------------------------------
        93         93         93  TABLE ACCESS BY INDEX ROWID ACT
       203        203        203   INDEX RANGE SCAN ACT_MEMACTDAT_IDX 


of which only 93 matched the predicate altogether. The only improvement would be to move the filter operation below from step 1 into step 2:

Predicate Information (identified by operation id):
---------------------------------------------------
   1 - filter("ACT"."ACTSTA"<>'C' AND "ACT"."ACTTYP"<>'CA' AND ("ACT"."HIDACT"='0' OR
              "ACT"."HIDACT" IS NULL))
   2 - access("ACT"."CMPCOD"='XX' AND "ACT"."PRGCOD"='XX' AND
              "ACT"."MEMSHPNUM"='999999' AND "ACT"."ACTDAT">=TIMESTAMP' 2011-01-01
              00:00:00.000000000' AND "ACT"."ACTDAT"<=TIMESTAMP' 2012-01-20 12:23:00.000000000')


you would achieve that by having an index on

cmpcod,prgcod,memshpnum,actdat PLUS actsta,acttyp,hidact



in that way, the entire where clause can be processed in the index, the index would only find 93 entries and we'd access the table 93 times instead of 203.

but frankly, your current query looks "pretty good" as it is - are you experiencing some issue?

SQL Tuning

Lal, June 04, 2012 - 2:27 am UTC

Tom,

This query is a subset of the big query with about eight joins which i posted on "May 16, 2012 - 1am Central time zone" in the same page. On reviewing the trace for the full query you mentioned to look into this case where 203 rows are scanned to get the 93 rows.

As i informed, for the original query i got some improvement (30 secs to about 5 to 10 secs) by reducing the clustering factor of some indexes.

From what i understood, the options i have to reduce io is to use partitioning, iot or table clustering.

My doubt is which option is most applicable for my case?


Tom Kyte
June 04, 2012 - 9:11 am UTC

I don't know, I know nothing about your data, I only know about partitioning, cluster, IOT's and the like.



I don't know how your data arrives
I don't know the expected data patterns
I don't know how it is used in real life



However, you do know about partitioning, IOT's, clustering and the like. AND you know the above data information too. Your goal - to get data that is queried together stored together. So, given you know your data - what sort of structure might be able to help you accomplish that??



And did you benchmark what I suggested which could cut 50% of the IO's you are doing at that step by simply changing an index definition?

nvl rewrite

Joe, June 12, 2012 - 11:28 am UTC

Hi Tom,

Can you please let me know how to rewrite the below query?

select col1,col2,col3 from tab1 where col1>=nvl(:x,col1) and col2<=nvl(:y,col2);

Whenever null values are passed to the bind variables above query does a full table scan. tab1 has around 30M records.

Thank you
Tom Kyte
June 12, 2012 - 11:38 am UTC

are x and y either

a) both null
b) both not null

or do you have four cases to deal with

and what language are you programming in

nvl rewrite

Joe, June 12, 2012 - 11:47 am UTC

Hi Tom,

Sorry for missing those details.

It is a cursor in plsql procedure.

For this procedure it's either both null or both not null.

Thank you

Tom Kyte
June 13, 2012 - 1:05 am UTC

use a ref cursor


if ( p_x is null and p_y is null )
then
   open l_cursor 
    for 
 select col1, col2, col3 
   from tab1 
  where col1 is not null 
    and col2 is not null;
else
   open l_cursor
     for 
  select col1, col2, col3
    from tab1
   where col1 >= p_x
     and col2 <= p_y;
end if;

loop
    fetch l_cursor BULK COLLECT into c1_array, c2_array, c3_array LIMIT N;
    for i in 1 .. c1_array.count
    loop
       ...
    end loop;
    exit when l_cursor%notfound;
end loop;

close l_cursor;


RE: nvl rewrite

Parthiban Nagarajan, June 12, 2012 - 1:47 pm UTC

Hi Joe

It seems you need four different cursors.

if :x is null and :y is null then
open rc for
select col1,col2,col3 from tab1;
elsif :x is not null and :y is not null then
open rc for
select col1,col2,col3 from tab1 where col1 >= :x and col2 <= :y;
elsif :x is null and :y is not null then
open rc for
select col1,col2,col3 from tab1 where col2 <= :y;
elsif :x is not null and :y is null then
open rc for
select col1,col2,col3 from tab1 where col1 >= :x;
end if;

To my knowledge, I would approach like this.
You might get better ideas.

Thanks

RE: nvl rewrite

Parthiban Nagarajan, June 13, 2012 - 12:20 am UTC

select col1,col2,col3
  from tab1
 where col1 >= nvl(:x, col1)
   and col2 <= nvl(:y, col2);

Whenever null values are passed to the bind variables above query does a full table scan.

But that is what you are asking for ...
if :x IS NULL and :y IS NULL then
the query would become
select col1,col2,col3
  from tab1
 where col1 >= col1
   and col2 <= col2;

which is nothing but
select col1,col2,col3
  from tab1

Thanks
Tom Kyte
June 13, 2012 - 1:28 am UTC

actually, it is

where col1 is not null and col2 is not null

ops$tkyte%ORA11GR2> create table t ( col1 int, col2 int, col3 int ) ;

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> insert into t values ( 1, 2,  10 );

1 row created.

ops$tkyte%ORA11GR2> insert into t values ( 1, null, 20 );

1 row created.

ops$tkyte%ORA11GR2> insert into t values ( null, 2, 30 );

1 row created.

ops$tkyte%ORA11GR2> insert into t values ( null, null, 40 );

1 row created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> select * from t where col1 >= col1 and col2 <= col2;

      COL1       COL2       COL3
---------- ---------- ----------
         1          2         10

ops$tkyte%ORA11GR2> select * from t;

      COL1       COL2       COL3
---------- ---------- ----------
         1          2         10
         1                    20
                    2         30
                              40

ops$tkyte%ORA11GR2> 



and what they wanted was:

a) an index to be used if :x/:y was not null
b) full scan otherwise


so - in general, two queries, but the could do it in a single query:

ops$tkyte%ORA11GR2> create index t_idx on t(col1);

Index created.

ops$tkyte%ORA11GR2> variable x number
ops$tkyte%ORA11GR2> variable y number
ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select *
  2    from t
  3   where (:x is null AND :y is null)
  4     and (col1 >= col1 and col2 <= col2 )
  5   UNION ALL
  6  select *
  7    from t
  8   where (:x is not null and :y is not null)
  9     and (col1 >= :x and col2 <= :y );

Execution Plan
----------------------------------------------------------
Plan hash value: 2250719457

---------------------------------------------------------------------------------------
| Id  | Operation                     | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |       |     5 |   195 |     5  (40)| 00:00:01 |
|   1 |  UNION-ALL                    |       |       |       |            |          |
|*  2 |   FILTER                      |       |       |       |            |          |
|*  3 |    TABLE ACCESS FULL          | T     |     1 |    39 |     3   (0)| 00:00:01 |
|*  4 |   FILTER                      |       |       |       |            |          |
|*  5 |    TABLE ACCESS BY INDEX ROWID| T     |     4 |   156 |     2   (0)| 00:00:01 |
|*  6 |     INDEX RANGE SCAN          | T_IDX |     4 |       |     1   (0)| 00:00:01 |
---------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - filter(:Y IS NULL AND :X IS NULL)
   3 - filter("COL1">="COL1" AND "COL2"<="COL2")
   4 - filter(:Y IS NOT NULL AND :X IS NOT NULL)
   5 - filter("COL2"<=TO_NUMBER(:Y))
   6 - access("COL1">=TO_NUMBER(:X))

Note
-----
   - dynamic sampling used for this statement (level=2)

ops$tkyte%ORA11GR2> set autotrace off


the filters on #2 and #4 would preclude us from executing one or the other of subtrees at runtime.

RE: nvl rewrite

Parthiban Nagarajan, June 13, 2012 - 2:13 am UTC

Hi Tom

As usual, EXCELLENT ...
Thanks for your time ...

Thanks and regards

nvl rewrite

Joe, June 13, 2012 - 10:38 am UTC

Thank you very much Tom/Parthibhan. Appreciate your help

sql tuning statements

misiek, June 28, 2012 - 8:52 am UTC

Hi Tom!

Can you recommend a very good book about tuning sql in database,improve performance ?

Thank You for Your help

Sql takes time for few records

Sikki, July 23, 2012 - 6:04 am UTC

Hi Tom,

I have simple Sql query which runs Good for some value and takes much time when querying some other value, below is the time difference.

14:56:26 SQL> SELECT MAX(BATCHNO)
FROM PRDS_AMM_CREW_PERCENTILE
WHERE STAFFNO = 222331;
14:56:49   2  14:56:49   3
MAX(BATCHNO)
------------
        3410

Elapsed: 00:00:00.01
14:56:49 SQL> SELECT MAX(BATCHNO)
FROM PRDS_AMM_CREW_PERCENTILE
WHERE STAFFNO = 172012;
14:56:56   2  14:56:56   3

MAX(BATCHNO)
------------
         772

Elapsed: 00:00:16.20

Tkprof reveals the below:
With problematic value,

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2     19.64      24.39     117842     348338          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4     19.65      24.39     117842     348338          0           1


Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 48  (PRDS_OWNR)

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=348338 pr=117842 pw=0 time=24394430 us)
      1   FIRST ROW  (cr=348338 pr=117842 pw=0 time=24394410 us)
      1    INDEX FULL SCAN (MIN/MAX) PK_AMM_CREW_PERCENTILE (cr=348338 pr=117842 pw=0 time=24394409 us)(object id 32369)


Rows     Execution Plan
-------  ---------------------------------------------------
      0  SELECT STATEMENT   MODE: ALL_ROWS
      1   SORT (AGGREGATE)
      1    FIRST ROW
      1     INDEX   MODE: ANALYZED (FULL SCAN (MIN/MAX)) OF
                'PK_AMM_CREW_PERCENTILE' (INDEX (UNIQUE))

****************************************************

With good value,

SELECT MAX(BATCHNO)
FROM PRDS_AMM_CREW_PERCENTILE
WHERE STAFFNO = 222331

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        2      0.00       0.00          0         65          0           1
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        4      0.00       0.00          0         65          0           1

Misses in library cache during parse: 0
Optimizer mode: ALL_ROWS
Parsing user id: 48  (PRDS_OWNR)

Rows     Row Source Operation
-------  ---------------------------------------------------
      1  SORT AGGREGATE (cr=65 pr=0 pw=0 time=4338 us)
      1   FIRST ROW  (cr=65 pr=0 pw=0 time=4291 us)
      1    INDEX FULL SCAN (MIN/MAX) PK_AMM_CREW_PERCENTILE (cr=65 pr=0 pw=0 time=4290 us)(object id 32369)


The execution plan remains same. One thing I noticed is for some prolematic variable the distinct BATCHNO has only one value whereas the good run variable has multiple BATCHNO. 

SELECT count(distinct BATCHNO) FROM PRDS_AMM_CREW_PERCENTILE
WHERE STAFFNO = 172012;

COUNT(DISTINCTBATCHNO)
----------------------
                     1

SELECT count(distinct BATCHNO) FROM PRDS_AMM_CREW_PERCENTILE
WHERE STAFFNO = 222331;

COUNT(DISTINCTBATCHNO)
----------------------
                   397

can you please advise what could be the reason. The oracle version is 10205 with PSU4.

Tom Kyte
July 30, 2012 - 8:54 am UTC

no creates
no look

I don't know what your table looks like or what this index is all about.

Amit Rai, January 21, 2013 - 2:37 am UTC

What would be the best way to write the sql to get the result --

sample data:

USERS TABLE --

user_id email gender age name
1 a@a.com <mailto:a@a.com> m 30 rob
2 a@a.com <mailto:a@a.com> m 31 robert
3 b@b.com <mailto:b@b.com> f 18 lucie
4 b@b.com <mailto:b@b.com> f 22 lulu
5 c@c.com <mailto:c@c.com> m 10 kim
6 c@c.com <mailto:c@c.com> f 18 kim
7 c@c.com <mailto:c@c.com> f 08 kim
8 d@d.com <mailto:d@d.com> f 18 JJ
9 d@d.com <mailto:d@d.com> m 22 Jay
10 e@e.com <mailto:e@e.com> f 88 Bill
11 e@e.com <mailto:e@e.com> f 88 Will
12 e@e.com <mailto:e@e.com> f 60 Will
13 f@f.com <mailto:f@f.com> m 70 George

subscriptions TABLE --

subscription_id user_id subsciption_type active_indicator
1 2 Magazine Yes
2 3 Music CD No
3 3 Magazine Yes
4 3 Video Yes
5 8 Magazine Yes
6 9 Video Yes
7 10 Magazine No
8 13 Magazine yes

transactions TABLE --

subscription_id action timestamp
1 Renewal 2002-sep-10
2 Renewal 2002-Jan-01
2 Cancellation 2002-Feb-01
3 Renewal 2002-Aug-20
4 Renewal 2002-Aug-01
4 Renewal 2002-Sep-01
5 Renewal 2002-Aug-01
6 Renewal 2001-Sep-01
7 Renewal 2002-Sep-01
7 Cancellation 2002-Sep-10


Type of business:

We are a subscription company where people signup to received products
like CDs, books, magazines, etc. We always try to market new
subscriptions to our existing client base, but having millions of
customers of which many use the same email address we like to send are
promotional email's once.

QUERY:

Some assumptions will need to be made. Please list any such assumptions.

Generate a list of unique email addresses with the latest name, gender
and age for a user with that email

The selection criteria limit the list to users which never subscribed to
anything; or;
users with inactive subscriptions; or;
users with active subscriptions that renewed between Sep 1st and sep
30th of any year


answer should be:

a@a.com <mailto:a@a.com> m 31 robert
b@b.com <mailto:b@b.com> f 22 lulu
c@c.com <mailto:c@c.com> f 08 kim
d@d.com <mailto:d@d.com> m 22 Jay
e@e.com <mailto:e@e.com> f 60 Will

Anand, January 21, 2013 - 4:05 am UTC

Hi Tom,

In our application i have found some performance issue.So i was trying to check whether the cardinality is okay or not.But found that it was way off.
So i have created a similar test case to check but still same even if i use dynamic sampling hint.
I havent analyze the table (as per production scenario)

drop table test
/
create table test(brn number ,dat_post date ,dat_value date )
/
insert into test values(706,'01-APR-11','31-MAR-11');
insert into test values(706,'01-APR-11','31-MAR-11');
insert into test values(706,'01-APR-11','31-MAR-11');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');

executed below query :

select /*+ DYNAMIC_SAMPLING(C 3) */
*
from test
where dat_post <= to_date('15-apr-2012', 'DD-MM-YYYY')
and dat_value < = to_date('15-apr-2012', 'DD-MM-YYYY')

expected rows : 358

Execution Plan
----------------------------------------------------------
Plan hash value: 217508114

--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 715 | 22165 | 15 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| TEST | 715 | 22165 | 15 (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("DAT_POST"<=TO_DATE('15-apr-2012','DD-MM-YYYY') AND
"DAT_VALUE"<=TO_DATE('15-apr-2012','DD-MM-YYYY'))

Note
-----
- dynamic sampling used for this statement

Tom Kyte
January 22, 2013 - 1:38 am UTC

... I havent analyze the table (as per production scenario)
...

well, there is problem number 1 right there.


your estimated cardinality is within an order of magnitude - you should be happy with a cardinality estimate of about 36 to about 3600. 715 is great. estimates are estimates, they should be close - within an order of magnitude. this looks perfectly OK to me.

with real statistics you might get even better cardinality estimates


dynamic sampling is not to be used IN PLACE of real statistics, it supplements them.

Anand, January 24, 2013 - 9:33 pm UTC

Hi Tom,

Let me modfiy my question.
In our application i have found some performance issue.So i was trying to check whether the
cardinality is okay or not.But found that it was way off.The reason seems like date in the query.

Please see below 2 query and its plan :

I havent analyze the table (as per production scenario)

drop table test
/
create table test(brn number ,dat_post date ,dat_value date )
/
insert into test values(706,'01-APR-11','31-MAR-11');
insert into test values(706,'01-APR-11','31-MAR-11');
insert into test values(706,'01-APR-11','31-MAR-11');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'07-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'08-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'09-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'10-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'11-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'12-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'13-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'14-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');
insert into test values(706,'15-APR-12','15-APR-12');

executed below query :

select /*+ DYNAMIC_SAMPLING(C 3) */
*
from test C
where dat_post <= to_date('15-apr-2012', 'DD-MM-YYYY')
and dat_value < = to_date('15-apr-2012', 'DD-MM-YYYY')

Execution Plan
----------------------------------------------------------
Plan hash value: 217508114

--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 358 | 11098 | 15 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| TEST | 358 | 11098 | 15 (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("DAT_POST"<=TO_DATE('15-apr-2012','DD-MM-YYYY') AND
"DAT_VALUE"<=TO_DATE('15-apr-2012','DD-MM-YYYY'))

Note
-----
- dynamic sampling used for this statement

select /*+ DYNAMIC_SAMPLING(C 3) */
*
from test C
where dat_post <= ln_global.dat_process
and dat_value < = ln_global.dat_process --- (ln_global is package here which is selecting date from a table)

Execution Plan
----------------------------------------------------------
Plan hash value: 217508114

--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 31 | 15 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| TEST | 1 | 31 | 15 (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

1 - filter("DAT_POST"<="LN_GLOBAL"."DAT_PROCESS"() AND
"DAT_VALUE"<="LN_GLOBAL"."DAT_PROCESS"())

Note
-----
- dynamic sampling used for this statement


Why for the second query cardinality is way off.But for the first query is okay.
Tom Kyte
January 30, 2013 - 1:34 pm UTC

Let me ask you this.

I want you to tell me how many records I'll receive for this where clause:


select * from test where dat_post <= to_date('15-apr-2012', 'DD-MM-YYYY')
and dat_value < = to_date('15-apr-2012', 'DD-MM-YYYY')

Now, you can run the query, you can have any statistics you want, you can use all information, you can read your post above - you can inspect the data - whatever you want.


Ok, now I want you to tell me how many records I'll receive for this query:

select * from test where dat_post <= ???
and dat_value < = ???


what did you guess for the 2nd one? I know you got the first one dead on (you better have! I let you even run the query if you wanted)


On the second one - no matter *what* number you come up with - I'll say "you are wrong".


ln_global.dat_process() is a function - it is a function which cannot be "peeked" at during optimization.


consider using a bind variable here. At least then the optimizer would be able to peek at the bind the first time...


ops$tkyte%ORA11GR2> create or replace function foo return date
  2  as
  3  begin
  4          return sysdate;
  5  end;
  6  /

Function created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> declare
  2          l_date_bind date := foo();
  3  begin
  4          for x in (select /*+ DYNAMIC_SAMPLING(C 3) */ *
  5                      from test C
  6                     where dat_post <= foo()
  7                           and dat_value < = foo() )
  8          loop
  9                  null;
 10          end loop;
 11  
 12          for x in (select * from table(dbms_xplan.display_cursor()))
 13          loop
 14                  dbms_output.put_line( x.plan_table_output );
 15          end loop;
 16  
 17          for x in (select /*+ DYNAMIC_SAMPLING(C 3) */ *
 18                      from test C
 19                     where dat_post <= l_date_bind
 20                           and dat_value < = l_date_bind )
 21          loop
 22                  null;
 23          end loop;
 24  
 25          for x in (select * from table(dbms_xplan.display_cursor()))
 26          loop
 27                  dbms_output.put_line( x.plan_table_output );
 28          end loop;
 29  end;
 30  /
SQL_ID  73npqxsdgrvpy, child number 0
-------------------------------------
SELECT /*+ DYNAMIC_SAMPLING(C 3) */ * FROM TEST C WHERE DAT_POST <=
FOO() AND DAT_VALUE < = FOO()

Plan hash value: 1357081020

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |       |       |     3 (100)|          |
|*  1 |  TABLE ACCESS FULL| TEST |     1 |    31 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(("DAT_POST"<="FOO"() AND "DAT_VALUE"<="FOO"()))

Note
-----
   - dynamic sampling used for this statement (level=2)

SQL_ID  b267kk2agaydy, child number 0
-------------------------------------
SELECT /*+ DYNAMIC_SAMPLING(C 3) */ * FROM TEST C WHERE DAT_POST <= :B1
AND DAT_VALUE < = :B1

Plan hash value: 1357081020

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |       |       |     3 (100)|          |
|*  1 |  TABLE ACCESS FULL| TEST |   358 | 11098 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(("DAT_POST"<=:B1 AND "DAT_VALUE"<=:B1))

Note
-----
   - dynamic sampling used for this statement (level=2)


PL/SQL procedure successfully completed.

Like performance improvement

A reader, January 29, 2013 - 4:43 pm UTC

Hello Tom,
We are running oracle 11g. I have a requirement to tune an existing query that does a like %text% on a field. Since there
is a wildcard or both ends normal indexes wont be picked up.
Is there any way I can tune this? Maybe use a hash value or something? please help!

thanks a lot in advance

Anand, January 31, 2013 - 12:38 am UTC

Hi Tom,

Thanks a lot for response.


..select over DB link

A Reader, January 31, 2013 - 11:10 am UTC

Tom
Just curious to know ...

How remote tables are accessed in a remote call from a sources.

say - we have db1 database 1
db2 database 2

say :
t1 table exists in database 1
t2 table exists in database 2
database link from db1 to db2 is dblink

let us say

t1 has 1000 rows size 500MB
t2 has 10000 rows size 1GB

there is a need to join the table as

select a.* from t1 a, t2@dblink b
where a.id = b.id;


now question
a) would it be more efficent if Optimizer choses HASH join instead of Nested Loop join?
because for every row fetch would happen via db link....so wait event SQl*Net waits
b) what if Oracle chosen Nested Loop.?
c) Whether Oracle calculates the cost of data fetch over the network ? while preparing the execution plan.


regards
Tom Kyte
January 31, 2013 - 2:44 pm UTC

a) almost certainly, that would be true in a single database too.

b) you would probably have been using first rows optimization. If you did that, it should use nested loops. that said - it would work. that answers the "what if"

c) we calculate costs based on CPU and IO costs - not necessarily the cost of a network directly - but via cpu costs.

no nl with first_rows-hint can be observed over DB link

Sokrates, January 31, 2013 - 3:26 pm UTC

sokrates@11.2 > create table t as select level l from dual connect by level <= 1e5;

Table created.

sokrates@11.2 > exec dbms_stats.gather_table_stats(null, 'T')

PL/SQL procedure successfully completed.

sokrates@11.2 > set lines 300 pages 5000 autotr traceonly explain arraysize 5000
sokrates@11.2 > select /*+first_rows */ * from t l, t@loopback r where l.l=r.l;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601052139

-------------------------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     | Inst   |IN-OUT|
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |   100K|   976K|    21  (15)| 00:00:01 |        |      |
|*  1 |  HASH JOIN         |      |   100K|   976K|    21  (15)| 00:00:01 |        |      |
|   2 |   TABLE ACCESS FULL| T    |   100K|   488K|    10  (10)| 00:00:01 |        |      |
|   3 |   REMOTE           | T    |   100K|   488K|    10  (10)| 00:00:01 | LOOPB~ | R->S |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - access("L"."L"="R"."L")

Remote SQL Information (identified by operation id):
----------------------------------------------------

   3 - SELECT /*+ FIRST_ROWS */ "L" FROM "T" "R" (accessing 'LOOPBACK' )


the first_rows - hint seems to be "pushed to remote" ( see Remote SQL Information ) where it effected nothing (?)
Tom Kyte
February 01, 2013 - 8:12 am UTC

any plan can be observed - but in this case, with no indexes - the fastest way to the first row would be the plan generated above.

if you have a schema where nested loops would make sense, it will use it.


ops$tkyte%ORA11GR2> create table t
  2  as
  3  select level l from dual connect by level <= 1e5;

Table created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> create index t_idx on t(l);

Index created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> exec dbms_stats.gather_table_stats(user,'T');

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select /*+ first_rows */ * from t t1, t@ora11gr2@loopback t2
  2  where t1.l = t2.l;

Execution Plan
----------------------------------------------------------
Plan hash value: 1754839799

-------------------------------------------------------------------------------------------
| Id  | Operation         | Name  | Rows  | Bytes | Cost (%CPU)| Time     | Inst   |IN-OUT|
-------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |       |   100K|   976K|   100K  (1)| 00:20:04 |        |      |
|   1 |  NESTED LOOPS     |       |   100K|   976K|   100K  (1)| 00:20:04 |        |      |
|   2 |   REMOTE          | T     |   100K|   488K|   223   (0)| 00:00:03 | ORA11~ | R->S |
|*  3 |   INDEX RANGE SCAN| T_IDX |     1 |     5 |     1   (0)| 00:00:01 |        |      |
-------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("T1"."L"="T2"."L")

Remote SQL Information (identified by operation id):
----------------------------------------------------

   2 - SELECT /*+ FIRST_ROWS */ "L" FROM "T" "T2" (accessing
       'ORA11GR2.LOCALDOMAIN@LOOPBACK' )


ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> 

..no nl with first_rows-hint can be observed over DB link

A Reader, January 31, 2013 - 9:34 pm UTC

....3 | REMOTE | T | 100K| 488K| 10 (10)| 00:00:01 | LOOPB~ | R->S |

a)
Since join chosen is HASH so no effect of FIRST_ROWS hint?


b)
What does REMOTE OPERTAION signifies...? is it a FULL table scan?

Tom Kyte
February 01, 2013 - 8:21 am UTC

a) the first_rows hint was obeyed - think about it.

what would be the fastest way to get the first few rows from this table?

option 1:
   for x in (select * from t)
   loop
        for y in (select * from t@remote where t.l = X.L /* full scan! */ )
        loop
             output x||y;
        end loop;
   end loop;

option 2:

   full scan t and hash into memory
   for x in (select * from t@remote)
   loop
          output hash_lookup(x) || x;
   end loop;




b) yes. it is running a query on remote to get the rows from T@remote

NL instead of hash join after upgrade to 11.2

A reader, February 01, 2013 - 3:13 am UTC

Hi Tom ,

We have upgraded the database from 11.1.0.7 to 11.2.0.2.
We have a insert query which inserts in to a remote table using db link.

The execution plan before upgrade is

| 4 | NESTED LOOPS | | | | | | | |
| 5 | NESTED LOOPS | | 1 | 317 | 162 (1)| 00:00:03 | | |
| 6 | NESTED LOOPS | | 1 | 294 | 161 (1)| 00:00:03 | | |
|* 7 | HASH JOIN | | 1 | 274 | 159 (1)| 00:00:03 | | |
| 8 | MERGE JOIN CARTESIAN | | 1 | 87 | 103 (1)| 00:00:02 | | |
|* 9 | HASH JOIN | | 1 | 70 | 4 (25)| 00:00:01 | | |
| 10 | REMOTE | T1 | 1 | 35 | 1 (0)| 00:00:01 | ! | R->S |
| 11 | REMOTE | T2 | 1 | 35 | 2 (0)| 00:00:01 | ! | R->S |
| 12 | BUFFER SORT | | 65M| 1055M| 101 (1)| 00:00:02 | | |
| 13 | REMOTE | T3 | 65M| 1055M| 99 (0)| 00:00:02 | ! | R->S |
| 14 | REMOTE | T4 | 1851 | 338K| 56 (0)| 00:00:01 | ! | R->S |

After uprade the plan changed to

| 6 | NESTED LOOPS | | 1 | 294 | 7 (0)| 00:00:01 | | |
| 7 | NESTED LOOPS | | 1 | 274 | 5 (0)| 00:00:01 | | |
| 8 | NESTED LOOPS | | 1 | 257 | 5 (0)| 00:00:01 | | |
| 9 | NESTED LOOPS | | 1 | 70 | 3 (0)| 00:00:01 | | |
| 10 | REMOTE | T1 | 1 | 35 | 1 (0)| 00:00:01 | ! | R->S |
| 11 | REMOTE | T2 | 1 | 35 | 2 (0)| 00:00:01 | ! | R->S |
| 12 | REMOTE | T3 | 3 | 561 | 2 (0)| 00:00:01 | ! | R->S |
| 13 | REMOTE | T4 | 8843 | 146K| 0 (0)| 00:00:01 | ! | R->S |


After the upgrade optimizer is choosing nested loops instead of hash join. As the join is via the remore table it is hitting the db link for every row.

Have you observed this kind of change in plan anytime and what could be the possible reason and also is hiniting the query to use hash the only solution?
Tom Kyte
February 01, 2013 - 8:34 am UTC

this is hard to read as you have it formatted, but it looks like the estimated cardinality has changed dramatically. can you think of any reason why that might be?

you don't really give much to go on here.

TEMP Space 90+ GB

Mark, February 17, 2013 - 5:55 pm UTC

Hello Tom

Can you help us with this query, when we try to run this query, it blows away 90+ gigs of TEMP space. It runs fast though in 30 something minutes it consumes all the TEMP space we've allocated. We are able to run it with 100GB TEMP, but want to see if there's a scope of optimizing TEMP usage for this.

---------------------------------------------------------------------------------------------------------------------
| Id  | Operation                             | Name                        | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------------------------------------------------
|   0 | INSERT STATEMENT                      |                             |       |       | 12021 (100)|          |
|   1 |  SORT GROUP BY                        |                             |     1 |   174 | 12021   (1)| 00:02:49 |
|   2 |   VIEW                                |                             |     1 |   174 | 12020   (1)| 00:02:49 |
|   3 |    SORT UNIQUE                        |                             |     1 |   223 | 12020   (1)| 00:02:49 |
|   4 |     WINDOW SORT PUSHED RANK           |                             |     1 |   223 | 12020   (1)| 00:02:49 |
|   5 |      NESTED LOOPS OUTER               |                             |     1 |   223 | 12018   (1)| 00:02:49 |
|   6 |       NESTED LOOPS                    |                             |     1 |   213 | 12017   (1)| 00:02:49 |
|   7 |        HASH JOIN                      |                             |     1 |   208 | 12017   (1)| 00:02:49 |
|   8 |         MAT_VIEW ACCESS BY INDEX ROWID| BSC_RPT_REBSUM_STRUCT_LI_MV |    21 |   210 |     1   (0)| 00:00:01 |

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------------------------------------
---------------------------------------------------------------------------------------------------------------------
|   9 |          NESTED LOOPS                 |                             |  8556 |  1387K| 10995   (1)| 00:02:34 |
|  10 |           NESTED LOOPS                |                             |   399 | 62244 | 10598   (1)| 00:02:29 |
|  11 |            HASH JOIN                  |                             |  4924 |   533K|   745   (1)| 00:00:11 |
|  12 |             HASH JOIN                 |                             |  8232 |   546K|   531   (1)| 00:00:08 |
|  13 |              TABLE ACCESS FULL        | BSC_RPT_REBSUM_TEMP         |  8232 |   168K|     7   (0)| 00:00:01 |
|  14 |              TABLE ACCESS FULL        | BSC_RPT_REBSUM_S1           | 87868 |  4033K|   523   (1)| 00:00:08 |
|  15 |             MAT_VIEW ACCESS FULL      | BSC_RPT_REBSUM_MEM_MV       | 52556 |  2206K|   214   (1)| 00:00:03 |
|  16 |            TABLE ACCESS BY INDEX ROWID| MN_BUCKET_LINE              |     1 |    45 |     2   (0)| 00:00:01 |
|  17 |             INDEX RANGE SCAN          | MDK1                        |     1 |       |     1   (0)| 00:00:01 |
|  18 |           INDEX RANGE SCAN            | BSC_RPT_STRUCT_LI_MV_IDX1   |    22 |       |     0   (0)|          |
|  19 |         MAT_VIEW ACCESS FULL          | BSC_RPT_ITEM_PH6_MV         |   641K|    25M|  1018   (1)| 00:00:15 |

PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------------------------------------
---------------------------------------------------------------------------------------------------------------------
|  20 |        INDEX UNIQUE SCAN              | MN_10291_PK                 |     1 |     5 |     0   (0)|          |
|  21 |       TABLE ACCESS BY INDEX ROWID     | BSC_SPLIT_PMT               |     1 |    10 |     1   (0)| 00:00:01 |
|  22 |        INDEX RANGE SCAN               | BSC_904200_IDX1             |     1 |       |     0   (0)|          |
---------------------------------------------------------------------------------------------------------------------

INSERT INTO MDK_TAB1
            (sale_id, struct_doc_id, pdflg, member_id_cust, paid_end_date, payee, map_name, bsc_phlevel, bsc_phcode, bsc_old_material_num, sold_to_cust_id, member_grp_name, 
   prc_program_id, bsc_r_af_type, rebate_pmt_id_num, rebate_pmt_id, sale_inv_qty, sales, earn_rebate_amt)
   SELECT   rpt.sale_id, rpt.struct_doc_id, rpt.pdflg, rpt.member_id_cust, rpt.paid_end_date, rpt.payee, rpt.map_name, rpt.bsc_phlevel,
            rpt.bsc_phcode, rpt.bsc_old_material_num, rpt.sold_to_cust_id, rpt.member_grp_name, rpt.prc_program_id, rpt.bsc_r_af_type, rpt.rebate_pmt_id_num, 
   rpt.rebate_pmt_id, rpt.sales_units, rpt.sales, SUM (rpt.earn_rebate_amt) earn_rebate_amt
       FROM (SELECT DISTINCT buck_li.sale_id, temp.contract_id struct_doc_id,
                             temp.pdflg, s1.member_id_cust,
                             temp.paid_end_date, SPLIT.payee,
                             item_vw.map_name, item_vw.bsc_phlevel,
                             item_vw.bsc_phcode, item_vw.bsc_old_material_num,
                             buck_li.sale_contracted_cust_id sold_to_cust_id,
                             mem_mv.child_name member_grp_name, s1.prc_program_id, s1.bsc_r_af_type,
                             s1.rebate_pmt_id_num, s1.rebate_pmt_id,
                             buck_li.sale_inv_qty AS sales_units,
                             NULLIF (buck_li.sale_ext_amt, 0) sales,
                             NULLIF
                                 (buck_li.bsc_payment_amount, 0) earn_rebate_amt,
                             ROW_NUMBER () OVER (PARTITION BY buck_li.bucket_line_id ORDER BY item_vw.bsc_phlevel DESC)
                   rnk
                        FROM bsc_rpt_rebsum_s1 s1,
                             mn_bucket_line buck_li,
                             bsc_rpt_item_ph6_mv item_vw,
                             bsc_rpt_rebsum_struct_li_mv limv,
                             bsc_rpt_rebsum_mem_mv mem_mv,
                             bsc_rpt_rebsum_temp temp,
                             bsc_split_pmt SPLIT,
                             mn_prc_program prc
                       WHERE temp.contract_id = s1.contract_id
                         AND temp.rebate_pmt_id = s1.rebate_pmt_id
                         AND temp.rebate_pmt_id = SPLIT.rebate_pmt_id(+)
                         AND temp.rebate_pmt_id = buck_li.rebate_pmt_id
                         AND limv.prc_program_id = s1.prc_program_id
                         AND prc.prc_program_id = s1.prc_program_id
                         AND mem_mv.prc_program_id = s1.prc_program_id
                         AND mem_mv.parent_member_id = s1.member_id_cust
                         AND limv.cat_map_id = item_vw.cat_map_id
                         AND item_vw.item_id = buck_li.sale_item_id
                         AND mem_mv.child_member_id = buck_li.sale_contracted_cust_id
                         AND buck_li.pmt_benefit_id IS NOT NULL
                         AND buck_li.inclusion_type = 'INC') rpt
      WHERE rpt.rnk = 1
   GROUP BY rpt.sale_id,
            rpt.struct_doc_id,
            rpt.pdflg,
            rpt.member_id_cust,
            rpt.paid_end_date,
            rpt.payee,
            rpt.map_name,
            rpt.bsc_phlevel,
            rpt.bsc_phcode,
            rpt.bsc_old_material_num,
            rpt.sold_to_cust_id,
            rpt.member_grp_name,
            rpt.prc_program_id,
            rpt.bsc_r_af_type,
            rpt.rebate_pmt_id_num,
            rpt.rebate_pmt_id,
            rpt.sales_units,
            rpt.sales;

transformed query?

pranav, February 25, 2013 - 9:55 am UTC

Hi Tom,

Once CBO transforms the query(during query transformation), does ORACLE store the new sql anywhere? I tried to lookup in 10053 but I didn't see the "transformed query". However, new plan is visible in explain plan/10053 trace.

How can we pull the new transformed query? Please let me know. Thanks!!
Tom Kyte
February 25, 2013 - 11:41 am UTC

current releases show the transformed query in the trace file, what release are you on.

transformed query?

pranav, February 25, 2013 - 2:51 pm UTC

Hi Tom,

It is 11.2.0.2. I generated 10053 for one of the trace file. I couldn't see the transformed query in it. Do you mean some other trace? Thanks!!
Tom Kyte
February 25, 2013 - 4:22 pm UTC

give an example of a schema and query you feel should be transformed and you don't see in the trace file (in other words, help me reproduce the situation)



for example


create table dept
as
select * from scott.dept;
alter table dept
add constraint dept_pk primary key(deptno);
create materialized view log on dept;
pause

clear screen
create table emp
as
select * from scott.emp;
alter table emp add constraint emp_pk primary key(empno);
alter table emp add constraint emp_fk_dept
foreign key(deptno) references dept(deptno);
alter table emp modify deptno not null ;
create materialized view log on emp;
pause

clear screen
create materialized view mv
ENABLE QUERY REWRITE
as
select emp.empno, emp.ename, dept.dname
  from emp, dept
 where emp.deptno = dept.deptno;
pause

clear screen
begin
   dbms_stats.set_table_stats
   ( user, 'EMP', numrows=>1000000, numblks=>100000 );
   dbms_stats.set_table_stats
   ( user, 'DEPT', numrows=>100000, numblks=>10000 );
   dbms_stats.set_table_stats
   ( user, 'MV', numrows=>1000000, numblks=>10000 );
end;
/
pause

clear screen
set autotrace on explain
@10053
select count(ename)
  from emp, dept
 where emp.deptno = dept.deptno;
@vitrc


in trace file, I find:


Final query after transformations:******* UNPARSED QUERY IS *******
SELECT COUNT("MV"."ENAME") "COUNT(ENAME)" FROM "OPS$TKYTE"."MV" "MV"





give me something at that level of detail to review for you.

how is a sql confirm read which blocks from the datafiles?

A reader, March 24, 2013 - 10:19 pm UTC

hi,tom:
i have a question all the time,wo know a sql Statement Processing have four steps, parsing,bind,exec,fetch,
i do not know how a sql besure need read which blocks from datafiles and which steps ensure?
i think when a sql Statement confirm its execution plan that a sql statement can confirm need read which blocks,is it correct?
thanks!
Tom Kyte
March 25, 2013 - 7:36 pm UTC

once we have a plan, we know what blocks we need to read to START the query, but we don't know what blocks we really need until we start running the query.


for example, the query is:

select * from t where x = 5;


and there is an index on X and we decide to use it. All we know when we compile the plan is "we need the root index block of the index on X"

we don't know what block that is - what file/block it is on - not until we start running. And after that - we don't know what the second block we'll need until we get the first block and so on and so on.

Tuning Dilemma

Oracle User, April 26, 2013 - 12:58 am UTC

Hi Tom,

I have often faced a tuning dillema, when you are trying to tune a statement and you run the SQL - for example say you want to assess advantage of using text index by comparing

a) LIKE SQL
-----------


select * FROM c_party
INNER JOIN
c_ind_restr_flag
ON c_ind_restr_flag.ind_restr_flag_cd = c_party.ind_restr_flag_cd
INNER JOIN
c_party_type
ON c_party_type.party_type_cd = c_party.party_type_cd
inner JOIN am_c_party_alias am_c_party_alias
ON (c_party.rowid_object = am_c_party_alias.party_rowid AND am_c_party_alias.hub_state_ind = 1)
where party_alias like '%PRUDENTIAL%'

b) CONTAINS SQL
select * FROM c_party
INNER JOIN
c_ind_restr_flag
ON c_ind_restr_flag.ind_restr_flag_cd = c_party.ind_restr_flag_cd
INNER JOIN
c_party_type
ON c_party_type.party_type_cd = c_party.party_type_cd
inner JOIN am_c_party_alias am_c_party_alias
ON (c_party.rowid_object = am_c_party_alias.party_rowid AND am_c_party_alias.hub_state_ind = 1)
where contains( party_alias, 'PRUDENTIAL' ) > 0;

now as you are tuning, and running these SQL's again and again - oracle i am sure is caching all teh data in memory and both run in 2 second

we could try changing the seach parameter - but with a large chunk of the table data probaly in memory - those two also run quite fast

Is there a way to get rid of that side impact of large chunk of table getting loaded in memory ?

Will writing your querioes as SELECT COUNT(*) help ?

Thanks in advance for your help


Tom Kyte
April 26, 2013 - 1:50 pm UTC

#1 - the cache will never be empty - some of the IO's will be 100% logical IO's, some will be physical+logical IO's (and some could be 100% direct path reads - all physical and no logical io's)...

so, please do not flush the cache or anything like that (search for secondary SGA for why this can be really really really misleading).

Trace the SQL. Look at the work performed (cpu, elapsed, IO's). Run query with many different inputs (simulating real life). Look at the total work performed by many executions with varied inputs over a duration of time.

If running the query with different inputs results in "hey, the first query cached what we needed" - why wouldn't that happen in real life too? That is fine. The cache will have stuff in it in real life.




#2 - NEVER EVER USE A SELECT COUNT(*) to test your queries. I've seen it a million times - someone takes a big query Q that does a lot of work and says "we want to just test it - not see the rows - so we will execute:

select count(*) from (Q);

or just replace the select list items of Q with count(*)"


that can, will and many times DOES change the execution plan!!!!

consider:


ops$tkyte%ORA11GR2> create table t ( x int, y int, z int );

Table created.

ops$tkyte%ORA11GR2> create index t_idx on t(x,y);

Index created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> variable x number
ops$tkyte%ORA11GR2> variable y number
ops$tkyte%ORA11GR2> set autotrace traceonly explain
ops$tkyte%ORA11GR2> select * from t where x = :x and y = :y order by z;

Execution Plan
----------------------------------------------------------
Plan hash value: 1454352066

--------------------------------------------------------------------------------------
| Id  | Operation                    | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |       |     1 |    39 |     2  (50)| 00:00:01 |
|   1 |  SORT ORDER BY               |       |     1 |    39 |     2  (50)| 00:00:01 |
|   2 |   TABLE ACCESS BY INDEX ROWID| T     |     1 |    39 |     1   (0)| 00:00:01 |
|*  3 |    INDEX RANGE SCAN          | T_IDX |     1 |       |     1   (0)| 00:00:01 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   3 - access("X"=TO_NUMBER(:X) AND "Y"=TO_NUMBER(:Y))

Note
-----
   - dynamic sampling used for this statement (level=2)

ops$tkyte%ORA11GR2> select count(*) from ( select * from t where x = :x and y = :y order by z);

Execution Plan
----------------------------------------------------------
Plan hash value: 293504097

---------------------------------------------------------------------------
| Id  | Operation         | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |       |     1 |    26 |     1   (0)| 00:00:01 |
|   1 |  SORT AGGREGATE   |       |     1 |    26 |            |          |
|*  2 |   INDEX RANGE SCAN| T_IDX |     1 |    26 |     1   (0)| 00:00:01 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   2 - access("X"=TO_NUMBER(:X) AND "Y"=TO_NUMBER(:Y))

Note
-----
   - dynamic sampling used for this statement (level=2)

ops$tkyte%ORA11GR2> set autotrace off




guess which "plan" runs better than the other? the optimizer removed a sort order by (which could be sorting a large number of rows, spilling to disk), a table access by index rowid (which could result in hundreds, thousands or more single block reads) and simply does an index range scan that will increment a counter (no spilling to temp, hundreds or thousands or more less single block reads)



How to find how long a sql has been running

A reader, April 30, 2013 - 3:40 pm UTC

Tom,

How to find how long a sql has been running? V$sql.ELAPSED_TIME is an accumulated one is the sql has been executed before.

Thanks
Tom Kyte
April 30, 2013 - 3:57 pm UTC

if it is a long running query that is not returning bits of data to a client outside of the database - last_call_et in v$session can see how long it has been active. that is a timer on a session while it is in a call.


if it is doing a query like "select * from really_big_table", this won't work since control returns to a client after each fetch and the counter resets.

if it is doing something like "select count(*) from really_big_table" where the first row cannot return until the last row is processed - it will work.


there is also the real time sql monitor as part of enterprise managers tuning/diagnostic pack. it can show you this as well.


How to find how long a sql has been running

A reader, April 30, 2013 - 5:22 pm UTC

Thanks, Tom.
It's very interesting that Oracle doesn't track how long a perticular sql has been running. It's very useful for troubleshooting. We are asked to alert users when any sql won't complete in certain amount of time. Do you have any suggestion?

Tom Kyte
May 06, 2013 - 1:19 pm UTC

well, you can find a sql statement that is taking a long time to return the first row - that is usually what people think of as a long running sql statement.

In order to get that first row - you have to make a call to the database. If that first row takes a really long time to get - the entry for that session in v$session will show how long that call has been active in last_call_et.


Now, on the other hand, if you have a query like:


select /*+ index( t t_idx ) */ * from really_big_table where indexed_column > 0;

and the index is on indexed_column and all values are greater than zero - each individual fetch - from the first to the last - will be "fast", but this will be a super long running query since getting many rows via an index is going to be slow. So this too will be a long running query - however, last_call_et in v$session won't show you this since each call to the database is fast (unless of course, you put the query into a stored procedure, then the stored procedure will be "slow" and the stored procedure is the call and hence last_call_et will advance).



which is what I said right above...

we do track this for the situation you are interested in. and in fact you can set up a profile to automatically stop any long running query like that.

http://docs.oracle.com/cd/B28359_01/server.111/b28286/statements_6010.htm

Tuning transient high buffer gets from AQ

Vijay Devadhar, May 06, 2013 - 12:51 am UTC

Tom,

I have Oracle AQ's listen/dequeue running very well with 1000-2000 gets/dequeue for the combination and system performing well; Off late, in a couple of instances the gets/dequeue jumped to 500k (yeah, half a million gets per dequeue) in matter of minutes. Queue itself did not have any major traffic hitting it. We also run AQ IOT coalesce every hour. Only thing odd ball was every time this happens, there is another SQL unrelated to Oracle AQ running for long, long time. We suspected that, and killed that Session. As soon as that session rolled back, AQ was back to normal health. There is no relation between that SQL and AQ. It is not touching AQ tables or indexes.

Each time this happens, there is high contention on the "Latch: cache buffers chains" reported in the AWR. (163 million waits in an hour. Good hour has 3 million or so) We also see a large number of "CR blocks created" reported in the AWR.

Could it be that the other SQL is creating such long buffer chains that it is causing AQ to not get latches soon enough and causing AQ SQL to do spin gets? 5 billion spin gets reported in that hour.

We are going to try to get rid of the other SQL and see if the problem goes away for good. However, some reasonable theoretical explanation would also be very useful.

Any pointers?

Thanks
Vijay
Tom Kyte
May 06, 2013 - 7:29 pm UTC

Could it be that the other SQL is creating such long buffer chains that it is
causing AQ to not get latches soon enough and causing AQ SQL to do spin gets?
5 billion spin gets reported in that hour.


no, the lists don't have to 'get long', they just have to have blocks that more than one session wants. My suspicion is the other session was doing so many logical IO's so fast (long running query probably overusing indexes...) that it hit the buffer cache really hard and caused contention.

update query

Anand, May 31, 2013 - 7:20 pm UTC

Hi Tom,

I have 2 update query which is slight different in query and now i want to merge into 1 query :


query 1 :


update t1
set flg_process = 'Y'
where exists (select 1
from t2, t3, t4
where t2.col1 = t3.col1
and t3.col1 = t4.col
and t1.col1 = t4.col1)
and exists (select 1 from t5 where t5.col1 = t1.col1)
and flg_process != 'Y'

query 2 :

update t1
set flg_process = 'N'
where exists (select 1
from t2, t3, t4
where t2.col1 = t3.col1
and t3.col1 = t4.col
and t1.col1 = t4.col1)
and not exists (select 1 from t5 where t5.col1 = t1.col1)
and flg_process != 'N'


i want to update in single query(to improve performance) as below to avoid 2 update (following your rules to do it in single query if possible) :

update t1
set flg_process = decode((select count(1) from t5 where t5.col1 = t1.col1),
1,
'Y',
'N')
where exists (select 1
from t2, t3, t4
where t2.col1 = t3.col1
and t3.col1 = t4.col
and t1.col1 = t4.col1)


In above query i dont want to update the row which value is already Y and updating again to Y or value is already N and updating again to N.How can i achieve this ?

The main purpose is to avoid unnecessary update.I cant use merge because i will update the column flg_process.


Tom Kyte
May 31, 2013 - 7:41 pm UTC

no creates
no inserts
no look


it is really hard to write a syntactically correct query without them.

also - make 100% sure to include ALL constraints, very important if you want to write a query, you cannot do it efficiently without them

A reader, May 31, 2013 - 9:31 pm UTC

as tom said given no information its hard to write query.
something like this...


merge into t1 trg
(
 select t1.col1, count(*)over(partition by t1.col1) as cnt
 from t1, t5
 where t1.col1 = t5.col1 and 
 exists (select null
           from t2, t3, t4
          where t2.col1 = t3.col1
            and t3.col1 = t4.col
            and t1.col1 = t4.col1)
)src
on trg.col1=src.col1 and trg.flg_process not in ('Y','N')
when match then update set trg.flg_process = case when src.col1!=0 then 'Y' ELSE 'N' END



Anand, June 01, 2013 - 4:40 pm UTC

Hi Tom,

Sorry for not sharing the insert script :
Below is the table script :

drop table t1
/
create table t1 (col1 CHAR(16),flg_process CHAR(1) DEFAULT 'N')
/
insert into t1
select 1,'Y' from dual
union all
select 2,'Y' from dual
union all
select 3,'Y' from dual
union all
select 4,'Y' from dual
union all
select 5,'Y' from dual
union all
select 6,'N' from dual
union all
select 7,'N' from dual
union all
select 8,'N' from dual
union all
select 9,'N' from dual
union all
select 10,'N' from dual
/
drop table t2
/
create table t2 (col1 CHAR(16))
/
drop table t3
/
create table t3 (col1 CHAR(16))
/
drop table t4
/
create table t4 (col1 CHAR(16))
/
drop table t5
/
create table t5 (col1 CHAR(16))
/
insert all into t2 into t3 into t4
select 1 from dual
union all
select 2 from dual
union all
select 3 from dual
union all
select 4 from dual
union all
select 5 from dual
union all
select 6 from dual
union all
select 7 from dual
union all
select 8 from dual
union all
select 9 from dual
union all
select 10 from dual
/
insert into t5
select 1 from dual
union all
select 4 from dual
union all
select 6 from dual
union all
select 8 from dual
/

I have 2 update query which is slight different in query and now i want to merge into 1 query :


query 1 :


update t1
set flg_process = 'Y'
where exists (select 1
from t2, t3, t4
where t2.col1 = t3.col1
and t3.col1 = t4.col
and t1.col1 = t4.col1)
and exists (select 1 from t5 where t5.col1 = t1.col1)
and flg_process != 'Y'

query 2 :

update t1
set flg_process = 'N'
where exists (select 1
from t2, t3, t4
where t2.col1 = t3.col1
and t3.col1 = t4.col
and t1.col1 = t4.col1)
and not exists (select 1 from t5 where t5.col1 = t1.col1)
and flg_process != 'N'


i want to update in single query(to improve performance) as below to avoid 2 update (following
your rules to do it in single query if possible) :

update t1
set flg_process = decode((select count(1) from t5 where t5.col1 = t1.col1),
1,
'Y',
'N')
where exists (select 1
from t2, t3, t4
where t2.col1 = t3.col1
and t3.col1 = t4.col
and t1.col1 = t4.col1)


In above query i dont want to update the row which value is already Y and updating again to Y or
value is already N and updating again to N.How can i achieve this ?

The main purpose is to avoid unnecessary update.I cant use merge because i will update the column
flg_process.


Tom Kyte
June 03, 2013 - 2:32 pm UTC

I'm so sad. I asked for all constraints and I get - zippo, zero, zilch.

you meant to tell me that in real life your tables have no primary keys? No foreign keys? sigh.... why is it you use a database again?

we might be able to simplify this down to almost NOTHING if you would tell us about these things - like what is not null, what is unique, what refers to what. Heck, I'd take a guess that tables t2, t3, t4 might not even have to be referenced!! If we had a certain set of constraints in place. But no - you'll never give us that information........ not even when asked for it :(



without any of the information I asked for being provided, here is one slow approach:




ops$tkyte%ORA11GR2> update t1
  2     set flg_process = case when flg_process <> 'Y' then 'Y' else 'N' end
  3   where t1.col1 in (select t4.col1
  4                       from t2, t3, t4
  5                      where t2.col1 = t3.col1
  6                        and t3.col1 = t4.col1)
  7     and ( (flg_process <> 'Y' and exists (select null from t5 where t5.col1 = t1.col1))
  8           or
  9           (flg_process <> 'N' and not exists (select null from t5 where t5.col1 = t1.col1))
 10             )
 11  /

5 rows updated.

ops$tkyte%ORA11GR2> select t1.*, t_old.*, decode( t1.flg_process, t_old.flg_process, '', '<<<=====' ) changed
  2    from t1, t1 as of scn &SCN t_old
  3   where t1.col1 = t_old.col1;
old   2:   from t1, t1 as of scn &SCN t_old
new   2:   from t1, t1 as of scn  124690392 t_old

COL1             F COL1             F CHANGED
---------------- - ---------------- - --------
1                Y 1                Y
2                N 2                Y <<<=====
3                N 3                Y <<<=====
4                Y 4                Y
5                N 5                Y <<<=====
6                Y 6                N <<<=====
7                N 7                N
8                Y 8                N <<<=====
9                N 9                N
10               N 10               N

10 rows selected.




there might be a really efficient way to do this, but we'll never know since we have none of the details we really needed... sigh........

Combined Query

Gireesh Puthumana, June 03, 2013 - 5:30 am UTC

Hi Anand,

If you can add a unique/primary key in each of these tables (t1,t2,t3,t4 and t5) on col1, Oracle makes it so easy for you.

update
(
select t1.col1, t1.flg_process, t5.col1 flg
from t1 join t2
on (t1.col1 = t2.col1)
join t3
on (t1.col1 = t3.col1)
join t4
on (t1.col1 = t4.col1)
left outer join t5
on (t1.col1 = t5.col1)
) tmp
set flg_process = decode(flg, null, 'N', 'Y')
where flg_process <> decode(flg, null, 'N', 'Y');

5 rows updated.

It works only if you have the keys. If it is not-feasible, I think you should better go for a simple PL/SQL block with bulk select and bulk update (I would recommend that anyways if tables in question are big)


Tom Kyte
June 03, 2013 - 2:50 pm UTC

i advise against that in general, especially if the tables are big.

and if many or most of the rows are going to be modified, I'd suggest a single cREATE TABLE AS SELECT instead of update.

Anand, June 03, 2013 - 10:09 am UTC

Hi Gireesh,

Thanks for your suggestion.It is not possible to put unique index on these table and this table is quite big.


The above update in my post is bulk update...right ?

Bulk update

Gireesh Puthumana, June 03, 2013 - 2:44 pm UTC

No. Even though it is a single SQL which updates all rows in question at once, still it is not "bulk update".

What I meant is a BULK COLLECT INTO & FORALL .. UPDATE.

If the table is huge, I don't think you want to commit it in one shot (If you want, be ready to face your DBA :)

You can build a simple PL-SQL block as:


DECLARE

CURSOR cur_select
IS
SELECT T1.COL1, T1.ROWID RWID, DECODE(T5.COL1, NULL, 'N', 'Y') FLG
FROM T1 JOIN T2
ON (T1.COL1 = T2.COL1)
JOIN T3
ON (T1.COL1 = T3.COL1)
JOIN T4
ON (T1.COL1 = T4.COL1)
LEFT OUTER JOIN T5
ON (T1.COL1 = T5.COL1)
WHERE T1.FLG_PROCESS <> DECODE(T5.COL1, NULL, 'N', 'Y');

TYPE TBL IS TABLE OF cur_select%ROWTYPE;

lt_tbl TBL;

BEGIN

OPEN cur_select;

LOOP
FETCH cur_select BULK COLLECT INTO lt_tbl LIMIT 1000;
EXIT WHEN lt_tbl.COUNT <= 0;

FORALL i IN lt_tbl.FIRST .. lt_tbl.LAST
UPDATE T1
SET FLG_PROCESS = lt_tbl(i).FLG
WHERE ROWID = lt_tbl(i).RWID;

DBMS_OUTPUT.PUT_LINE(SQL%ROWCOUNT);

COMMIT;

END LOOP;

CLOSE cur_select;

END;
/

DBMS_OUTPUT will be: 5

LIMIT used in above example can be modified (please see more on bulk collect to get it better).
Tom Kyte
June 03, 2013 - 3:01 pm UTC

If the table is huge, I don't think you want to commit it in one shot (If you
want, be ready to face your DBA :)


and be ready to face them with facts such as:


a) it'll generate less redo and undo if you let me do in in a single go
b) it'll generally be faster, much faster, than doing it procedurally
c) it won't have to take days of coding and testing since we don't have to make it restartable (THIS IS WHAT EVERYONE SEEMS TO FORGET, how do you restart your process safely and not give someone a raise again in your loop???? The logic for this can be quite complex)


and so on. Face your DBA with science and you'll be OK. Face them with no supporting information and you'll look bad, this is true - so go for the science.



user from above

A reader, June 03, 2013 - 8:34 pm UTC

sorry my bad :)


merge into t1 trg
using
(
    select t1.col1, FLG_PROCESS, count(t5.col1)over(partition by t1.col1) as cnt
    from t1 Left join t5
    on t1.col1 = t5.col1 
    where  
    exists (select null
              from t2, t3, t4
             where t2.col1 = t3.col1
               and t3.col1 = t4.col1
               and t1.col1 = t4.col1)
)src
on trg.col1=src.col1 and ( (src.cnt=0 and trg.flg_process!='N') OR (src.cnt>0 and trg.flg_process!='Y'))
when matched then update set trg.flg_process = case when src.cnt!=0 then 'Y' ELSE 'N' END


thanks

anand Agrawal, June 04, 2013 - 6:55 am UTC

Hi Tom,

Thanks for your suggestion but we cant create table and rename as we have online process also .That can cause another issue.

From 'N' to 'Y' will be update 30% of the data.And from 'Y' to 'N' will be very less.
Tom Kyte
June 04, 2013 - 1:58 pm UTC

Updating 30% of the data could well cause the entire table to have to be read into the cache (ever single block), and undo generated for every single block (as much undo as table). Be prepared for the physical IO's that will result if this table is large... Not too much you can do about that.

Single update on huge table

Gireesh Puthumana, June 04, 2013 - 11:49 am UTC

Ooops!! I think I was so wrongly convinced about such single updates on huge tables. It is time I should take a re-look.

But Tom, in my previous company, we had about 15 tables each having more than 150 million records. There were about 50 threads at any given time, SELECTing from them for 24X7. And also there were another set of programs running 24X7 to feed data into these tables.

Now the pain part.. Sometimes the feeding programs go bad and we had to correct (update) in tables (say more than 40% of records). And whenever we ran single updates, they ran for hours and hours and never got completed also bringing down the overall performance of other online processes.

Bulk operations had always been the savior for us in such cases. They ran silent, for about 1000 records at a time, writing logs after certain interval. At least we knew they are running and by when they will be completed. On the other hand, single DML left us no clues.
Tom Kyte
June 04, 2013 - 2:21 pm UTC

if I had to correct 40% of the records, it would have been all about DDL, not DML.

if you regularly screwed up 40% of the data, I'd be looking at using the rm command to erase the heinous procedural code that had such a bad bug in it and replacing it with database code written by database savvy developers (who wouldn't mess up the data...)


feeding programs never "go bad", they are just written with bugs in them.

Can't use DDL

Gireesh Puthumana, June 05, 2013 - 10:11 am UTC

Unfortunately, I neither can replace the code nor use DDL. What do you recommend then? Single-Update, Bulk-Collect .. Forall-Update or anything else?
Tom Kyte
June 05, 2013 - 2:12 pm UTC

finding a new position in another job.

I'm serious. If I worked in a place that said "we know our code is wrong, we know our code screws up our data on a recurring basis, we know we waste hours and hours fixing this mistake over and over - but you CANNOT CHANGE CODE"

I would go crazy.



You can use DDL, you have chosen not to.

You can replace the code, you have chosen not to.


There is nothing but you stopping you from fixing this.

Nice one..

Gireesh Puthumana, June 05, 2013 - 2:25 pm UTC

That is a nice one Tom.. :) Perfect answer. And guess what? I already did it..

Explain Plan

PCS, June 26, 2013 - 10:57 am UTC

Hi Tom,

I have total of 2 Years experience in Oracle and now trying to dig in my hand in performance tuning. I have also read your books , but somehow practically working in code things don't clicked up easily.

So I wanted to ask your views on an explain plan for a particular query : Specially in the temp usage section where "HASH UNIQUE" is showing 133 MB of space ...what is that ?? Any other views will be appreciated ... Thanks !!

Execution Plan
----------------------------------------------------------
Plan hash value: 731827679

---------------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 194K| 394M| | 83146 (1)| 00:16:38 | | |
| 1 | VIEW | | 194K| 394M| | 83146 (1)| 00:16:38 | | |
| 2 | UNION-ALL | | | | | | | | |
| 3 | HASH UNIQUE | | 179K| 65M| 133M| 47526 (1)| 00:09:31 | | |
|* 4 | HASH JOIN RIGHT OUTER | | 179K| 65M| 15M| 32987 (1)| 00:06:36 | | |
| 5 | VIEW | MBV_TP_COMMERCIAL_ACCOUNT | 362K| 11M| | 8243 (2)| 00:01:39 | | |
| 6 | NESTED LOOPS | | 362K| 22M| | 8243 (2)| 00:01:39 | | |
|* 7 | HASH JOIN | | 362K| 20M| 11M| 8207 (2)| 00:01:39 | | |
|* 8 | HASH JOIN | | 362K| 7070K| 7416K| 2930 (2)| 00:00:36 | | |
|* 9 | TABLE ACCESS FULL | PARTY_ROLE | 361K| 3175K| | 1144 (2)| 00:00:14 | | |
|* 10 | TABLE ACCESS FULL | PARTY | 556K| 5976K| | 803 (3)| 00:00:10 | | |
| 11 | TABLE ACCESS FULL | ACCOUNT | 935K| 33M| | 2492 (2)| 00:00:30 | | |
|* 12 | INDEX RANGE SCAN | SUBJECT_ID | 1 | 6 | | 0 (0)| 00:00:01 | | |
| 13 | VIEW | | 179K| 59M| | 20915 (1)| 00:04:11 | | |
|* 14 | HASH JOIN RIGHT OUTER | | 179K| 61M| | 20915 (1)| 00:04:11 | | |
| 15 | TABLE ACCESS FULL | ERR_PRE_ADVICE_ITEM | 33718 | 559K| | 344 (1)| 00:00:05 | | |
|* 16 | HASH JOIN RIGHT OUTER| | 15211 | 5050K| | 20567 (1)| 00:04:07 | | |
| 17 | TABLE ACCESS FULL | ERR_PRE_ADVICE_DATA | 2801 | 67224 | | 68 (0)| 00:00:01 | | |
|* 18 | HASH JOIN | | 15211 | 4694K| 4472K| 20498 (1)| 00:04:06 | | |
|* 19 | TABLE ACCESS FULL | PREADVICE_ERROR | 15211 | 4292K| | 18335 (1)| 00:03:41 | | |
| 20 | TABLE ACCESS FULL | ERROR_FSPEC_MANIFEST | 558K| 14M| | 904 (2)| 00:00:11 | | |
| 21 | HASH UNIQUE | | 15211 | 6194K| 12M| 35620 (1)| 00:07:08 | | |
|* 22 | HASH JOIN RIGHT OUTER | | 15211 | 6194K| | 34268 (1)| 00:06:52 | | |
| 23 | TABLE ACCESS FULL | ERR_PRE_ADVICE_ITEM | 33718 | 658K| | 344 (1)| 00:00:05 | | |
|* 24 | HASH JOIN RIGHT OUTER | | 15211 | 5897K| | 33922 (1)| 00:06:48 | | |
| 25 | PARTITION RANGE ALL | | 394 | 7880 | | 183 (0)| 00:00:03 | 1 | 71 |
| 26 | PARTITION HASH ALL | | 394 | 7880 | | 183 (0)| 00:00:03 | 1 | 4 |
| 27 | TABLE ACCESS FULL | PRE_ADVICE_MNFST | 394 | 7880 | | 183 (0)| 00:00:03 | 1 | 284 |
|* 28 | HASH JOIN OUTER | | 15211 | 5600K| 5304K| 33738 (1)| 00:06:45 | | |
|* 29 | HASH JOIN | | 15211 | 5124K| 4472K| 24476 (1)| 00:04:54 | | |
|* 30 | TABLE ACCESS FULL | PREADVICE_ERROR | 15211 | 4292K| | 18335 (1)| 00:03:41 | | |
| 31 | TABLE ACCESS FULL | ERROR_FSPEC_MANIFEST_LINE | 888K| 47M| | 3047 (2)| 00:00:37 | | |
| 32 | VIEW | MBV_TP_COMMERCIAL_ACCOUNT | 362K| 11M| | 8243 (2)| 00:01:39 | | |
| 33 | NESTED LOOPS | | 362K| 22M| | 8243 (2)| 00:01:39 | | |
|* 34 | HASH JOIN | | 362K| 20M| 11M| 8207 (2)| 00:01:39 | | |
|* 35 | HASH JOIN | | 362K| 7070K| 7416K| 2930 (2)| 00:00:36 | | |
|* 36 | TABLE ACCESS FULL| PARTY_ROLE | 361K| 3175K| | 1144 (2)| 00:00:14 | | |
|* 37 | TABLE ACCESS FULL| PARTY | 556K| 5976K| | 803 (3)| 00:00:10 | | |
| 38 | TABLE ACCESS FULL | ACCOUNT | 935K| 33M| | 2492 (2)| 00:00:30 | | |
|* 39 | INDEX RANGE SCAN | SUBJECT_ID | 1 | 6 | | 0 (0)| 00:00:01 | | |
---------------------------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

4 - access("AC"."COMMERCIAL_ACCOUNT_NUMBER"(+)=NVL("EPAI"."ACCOUNT_N0","EFM"."ACCOUNT_NUMBER"))
7 - access("A"."PARTY_ID_ACCOUNT"="P"."ID")
8 - access("P"."ID"="R"."PARTY_ID")
9 - filter("R"."PARTY_ROLE_TYPE_ID"=1)
10 - filter("P"."ID_SUBJECT" IS NOT NULL)
12 - access("P"."ID_SUBJECT"="S"."ID")
14 - access("EPAD"."BATCH_ID"="EPAI"."BATCH_ID"(+))
16 - access("EPAD"."FILE_SERIAL_NO"(+)="EFM"."FILE_SERIAL_NUMBER" AND "EPAD"."CREATED_DATE"(+)="EFM"."ERROR_DATE")
18 - access("ERR"."ERROR_ID"="EFM"."ERROR_ID")
19 - filter("ERR"."ERROR_DATE"=20130101)
22 - access("EFML"."ERROR_DATE"="EPAI"."CREATED_DATE"(+) AND "EFML"."BARCODE"="EPAI"."ITEM_NUMBER"(+))
24 - access("EFML"."ERROR_DATE"=TO_NUMBER(TO_CHAR(INTERNAL_FUNCTION("PAM"."CREATED_DATE"(+)),'YYYYMMDD')) AND
"EFML"."FILE_SERIAL_NUMBER"="PAM"."FILE_SERIAL_NUMBER"(+))
28 - access("AC"."COMMERCIAL_ACCOUNT_NUMBER"(+)="EFML"."ACCOUNT_NUMBER")
29 - access("ERR"."ERROR_ID"="EFML"."ERROR_ID")
30 - filter("ERR"."ERROR_DATE"=20130101)
34 - access("A"."PARTY_ID_ACCOUNT"="P"."ID")
35 - access("P"."ID"="R"."PARTY_ID")
36 - filter("R"."PARTY_ROLE_TYPE_ID"=1)
37 - filter("P"."ID_SUBJECT" IS NOT NULL)
39 - access("P"."ID_SUBJECT"="S"."ID")
Tom Kyte
July 01, 2013 - 7:10 pm UTC

the tmp space is a guess as to how much space in your temporary tablespace that step will use.

we are guessing that we'll need about 133mb of space in temp for that step of the query.

Is this a bug or am I missing something?

Dhruva, July 02, 2013 - 1:48 pm UTC


SELECT * FROM v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.5.0 - 64bi
PL/SQL Release 10.2.0.5.0 - Production
CORE 10.2.0.5.0 Production
TNS for IBM/AIX RISC System/6000: Version 10.2.0.5.0 - Productio
NLSRTL Version 10.2.0.5.0 - Production

SELECT DISTINCT f.f_policy_symbol|| f.f_policy_number policy_no
FROM narep_f_hist_techclm f, com_d_repmonth c
WHERE f.sid_repmonth = c.sid_repmonth
AND f_policy_symbol|| f_policy_number IN ('ULA2003481', 'ULA2003979')
AND c.d_year = 2013
AND c.d_month <= 4;

POLICY_NO
----------
ULA2003481
ULA2003979

CREATE INDEX test_fi_bug ON narep_f_hist_techclm(f_policy_symbol|| f_policy_number);

index TEST_FI_BUG created.

SELECT DISTINCT f.f_policy_symbol|| f.f_policy_number
FROM narep_f_hist_techclm f, com_d_repmonth c
WHERE f.sid_repmonth = c.sid_repmonth
AND f_policy_symbol|| f_policy_number IN ('ULA2003481', 'ULA2003979')
AND c.d_year = 2013
AND c.d_month <= 4;

no rows selected

DROP INDEX test_fi_bug;

index TEST_FI_BUG dropped.

SELECT DISTINCT f.f_policy_symbol|| f.f_policy_number
FROM narep_f_hist_techclm f, com_d_repmonth c
WHERE f.sid_repmonth = c.sid_repmonth
AND f_policy_symbol|| f_policy_number IN ('ULA2003481', 'ULA2003979')
AND c.d_year = 2013
AND c.d_month <= 4;

POLICY_NO
----------
ULA2003481
ULA2003979

This one works!

Dhruva, July 03, 2013 - 10:00 am UTC

If I change the WHERE condition '<= 4>' to '= 4', then it does return the rows, even with the function based index present:
CREATE INDEX test_fi_bug ON narep_f_hist_techclm(f_policy_symbol|| f_policy_number);

index TEST_FI_BUG created.

SELECT DISTINCT f.f_policy_symbol|| f.f_policy_number policy_no
FROM   narep_f_hist_techclm f, com_d_repmonth c 
WHERE  f.sid_repmonth = c.sid_repmonth
AND    f_policy_symbol|| f_policy_number IN ('ULA2003481', 'ULA2003979')
AND    c.d_year  = 2013
AND    c.d_month = 4;

POLICY_NO
----------
ULA2003481                           
ULA2003979 

A perculiar instance where adding an index actually stops the query from working. One for support?
Tom Kyte
July 16, 2013 - 12:23 pm UTC

if you have a case where the addition of an index changes the answer, yes, that is for support.

Data from single table only

Pradeep Sorari, August 06, 2013 - 6:18 am UTC

Hi Tom,
Hope you are doing great !!

We have an application in front end which fetches data from database and displays it in website. We have built a packaged SP which provides data as SYS Refcursor.
The query is simple and fetched data from one single table. From quite sometime, for some cases the application is receiving 504 Gateway timeout error (Threshold of Front end system is 3 minutes).

We have created index on Error_date column, which has made query faster but still it is throwing erors for some cases like below :

Info :

TODSPRD>select count(*) from preadvice_error_temp;

COUNT(*)
----------
22348125
Elapsed: 00:02:42.48


TODSPRD>select count(*),error_date from preadvice_error_temp where error_date between 20130725 and 20130730 group by error_date order by error_date;

COUNT(*) ERROR_DATE
---------- ----------
225421 20130725
188429 20130726
30373 20130727
34917 20130728
321545 20130729
234229 20130730

Created index PREADVICE_ERROR_TEMP_IDX on ERROR_DATE column .




For 25/07/2013 , it is running and showing result in 00:01:52.48 minutes in Db side however throwing 504 gateway timeout in front end

PRD>SELECT acc_num ,acc_name ,serialnum ,mnfstdate ,errplace ,severity ,barcode ,des ,
TO_CHAR(TO_DATE(lpad(error_date,'8','0')||' '||lpad(error_time,'6','0') ,'YYYYMMDDHH24MISS'),'DD/MM/YYYY HH24:MI') erd
FROM PREADVICE_ERROR_TEMP
where ERROR_DATE between
to_number(to_char(to_date('25/07/2013','dd/mm/yyyy'),'yyyymmdd')) and --PvchFromDate
to_number(to_char(to_date('25/07/2013','dd/mm/yyyy'),'yyyymmdd'))--PvchToDate
order by acc_num, serialnum, error_date,error_time DESC;

Elapsed: 00:00:00.01

Execution Plan
----------------------------------------------------------
Plan hash value: 2853613553

-----------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 254K| 35M| | 126K (1)| 00:25:18 |
| 1 | SORT ORDER BY | | 254K| 35M| 84M| 126K (1)| 00:25:18 |
| 2 | TABLE ACCESS BY INDEX ROWID| PREADVICE_ERROR_TEMP | 254K| 35M| | 118K (1)| 00:23:39 |
|* 3 | INDEX RANGE SCAN | PREADVICE_ERROR_TEMP_IDX | 254K| | | 611 (1)| 00:00:08 |
-----------------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

3 - access("ERROR_DATE"=20130725)



For date range between 27/07/2013 to 29/07/2013 -taking time -00:02:42.48 in db (while running query in database) but throwing error at front end .

set autotrace traceonly explain

Execution Plan
----------------------------------------------------------
Plan hash value: 4151241074

---------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes |TempSpc| Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 381K| 53M| | 139K (1)| 00:27:53 |
| 1 | SORT ORDER BY | | 381K| 53M| 126M| 139K (1)| 00:27:53 |
|* 2 | TABLE ACCESS FULL| PREADVICE_ERROR_TEMP | 381K| 53M| | 127K (1)| 00:25:25 |
---------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("ERROR_DATE">=20130727 AND "ERROR_DATE"<=20130729)


As the data is fetched from a single table , I am expecting result in around 20 seconds of time, Am I doing something wrong ,
OR can we do this kind of stuff more efficiently ?

Many Thanks!!


P.S : We have advised customer to re build application with scrolable result set but customer didn't approved the budget and we are required to tune this query only.


Tom Kyte
August 08, 2013 - 4:33 pm UTC

.. For 25/07/2013 , it is running and showing result in 00:01:52.48 minutes in Db
side however throwing 504 gateway timeout in front end ...

then perhaps the issue is in the application, not the database..... the application must account for the rest of the time.


if it is taking over 2 1/2 minutes to count 22,000,000 records - I'd say you either have a really overloaded server or you have really slow IO


are you really truly displaying 245,000 rows on a web page????? seriously???


One who tries to learn sql tuning

j_dba_sourav, August 08, 2013 - 8:11 pm UTC

Hello Tom,

It is really a privilege to be able to writing to you. Thanks a lot for letting us know so very facts with optimum acceptance.

Admiring your work here I would like to get few of my doubts clear. Please try to help me.

I got few queries in my prod DB. I found those queries while they were taking lots of time to run from application. Anyways. The queries are showing cost in CROREs. It has a lot of subqueries, distinct rows( with combinations of cols) aggregate function and plenty of AND conditions.
Also they have inline views.

The same query in Test system with almost same data showing 5000-6000 cost. The data got refresh a month ago by the PROD and in Prod the statistics job which is running is a default one, i.e. gather_schema_job(schemaname); which I found faulty and thus creating problem.
The test instance has the same stats while it was refreshed and auto stat job in scheduler is on, where as my fellow workers unnoticed that. :(
They don't collect stat on test as data is not change bound there.

I hope you got my problem statement.
What could be the differentiating factor behind that much cost difference?
especially at the time of refresh when they carried same kind of stat in test from Prod.
Data are close to same in both the systems ??

Please let me know if you need any more information from my side!!

N.B. I checked in Prod as well as test about the last_analyzed and num_rows, none of them are giving me correct data(expected here) but somewhat close to correct data and last_analyzed in prod is 5-6 older and in test most of the time it the day when refreshed and in very few tables due to auto_stat job recent days.

-Regards,
A.S

Tom Kyte
August 08, 2013 - 9:35 pm UTC

the stats are different in test and prod, or the init.ora parameters are different.

the cost is an estimate based on the statistics, the cost doesn't necessarily mean it will use or not use X amount of resources, it is a number computed based on the statistics and the query.


so, your statistics are different in the two environments, leading to a different cost. leading to potentially different plans being used in the two environments.

the one with statistics that are not representative of the data is probably wrong.



if you want, you can run a 10053 trace in the two environments and diff those two files, that will give you a quick heads up as to what is different.

review

A.S, August 14, 2013 - 11:42 am UTC

Hi Tom,

I have few queries which have a higher costs and take a greater time to execute. I believe they need tuning. Could you please give me some idea about how to make queries better in respect of below one. Actually I have plenty and this is one smaller.

select
count(distinct emplid)
FROM PS_JOB A, PS_POS_DUP X, ps_location_tbl Y
WHERE A.EMPL_RCD = (
SELECT MAX(B.EMPL_RCD)
FROM PS_JOB B
WHERE B.EMPLID =A.EMPLID
AND b.empl_status='A'
AND B.EFFDT = (
SELECT MAX(C.EFFDT)
FROM PS_JOB C
WHERE C.EMPLID = B.EMPLID
AND c.empl_rcd=b.empl_rcd
AND C.EFFDT <= to_date(SYSDATE)))
AND A.EFFDT = (
SELECT MAX(C.EFFDT)
FROM PS_JOB C
WHERE C.EMPLID = A.EMPLID
AND C.EFFDT <= to_date(SYSDATE)
AND c.empl_rcd=a.empl_rcd)
AND A.EFFSEQ = (
SELECT MAX(D.EFFSEQ)
FROM PS_JOB D
WHERE D.EMPLID = A.EMPLID
AND D.EFFDT = A.EFFDT
AND A.EMPL_STATUS = 'A'
AND d.empl_rcd=a.empl_rcd)
and A.POSITION_NBR=X.POSITION_NBR(+)
and A.location=Y.location(+)
and A.deptid like '%TE'


Explain plan:

Execution Plan
----------------------------------------------------------
Plan hash value: 1575893115

--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 53 | 296K (1)| 00:59:23 |
| 1 | SORT GROUP BY | | 1 | 53 | | |
|* 2 | FILTER | | | | | |
| 3 | NESTED LOOPS OUTER | | 21420 | 1108K| 9171 (1)| 00:01:51 |
| 4 | NESTED LOOPS OUTER | | 21420 | 1024K| 9170 (1)| 00:01:51 |
|* 5 | TABLE ACCESS FULL | PS_JOB | 21420 | 899K| 9169 (1)| 00:01:51 |
|* 6 | INDEX RANGE SCAN | PS_POS_DUP | 1 | 6 | 0 (0)| 00:00:01 |
|* 7 | INDEX RANGE SCAN | PSALOCATION_TBL | 1 | 4 | 0 (0)| 00:00:01 |
| 8 | SORT AGGREGATE | | 1 | 19 | | |
|* 9 | INDEX RANGE SCAN | PSAJOB | 1 | 19 | 3 (0)| 00:00:01 |
| 10 | SORT AGGREGATE | | 1 | 21 | | |
|* 11 | TABLE ACCESS BY INDEX ROWID| PS_JOB | 1 | 21 | 4 (0)| 00:00:01 |
|* 12 | INDEX RANGE SCAN | PSAJOB | 1 | | 3 (0)| 00:00:01 |
| 13 | SORT AGGREGATE | | 1 | 19 | | |
|* 14 | INDEX RANGE SCAN | PSAJOB | 1 | 19 | 3 (0)| 00:00:01 |
| 15 | SORT AGGREGATE | | 1 | 22 | | |
|* 16 | FILTER | | | | | |
|* 17 | INDEX RANGE SCAN | PSAJOB | 1 | 22 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter("SYS_ALIAS_7"."EFFDT"= (SELECT
MAX(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))) FROM "SYSADM"."PS_JOB" "C" WHERE
SYS_OP_DESCEND("EFFDT") IS NOT NULL AND SYS_OP_DESCEND("EFFDT")>=SYS_OP_DESCEND(TO_DATE(TO
_CHAR(SYSDATE@!))) AND "C"."EMPL_RCD"=:B1 AND "C"."EMPLID"=:B2 AND
SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))<=TO_DATE(TO_CHAR(SYSDATE@!))) AND
"SYS_ALIAS_7"."EMPL_RCD"= (SELECT MAX("SYS_ALIAS_2"."EMPL_RCD") FROM "SYSADM"."PS_JOB"
"SYS_ALIAS_2" WHERE "SYS_ALIAS_2"."EMPLID"=:B3 AND "SYS_ALIAS_2"."EMPL_STATUS"='A' AND
SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))= (SELECT
MAX(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))) FROM "SYSADM"."PS_JOB" "C" WHERE
SYS_OP_DESCEND("EFFDT") IS NOT NULL AND SYS_OP_DESCEND("EFFDT")>=SYS_OP_DESCEND(TO_DATE(TO
_CHAR(SYSDATE@!))) AND "C"."EMPL_RCD"=:B4 AND "C"."EMPLID"=:B5 AND
SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))<=TO_DATE(TO_CHAR(SYSDATE@!)))) AND
"SYS_ALIAS_7"."EFFSEQ"= (SELECT MAX(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFSEQ"))) FROM
"SYSADM"."PS_JOB" "D" WHERE :B6='A' AND SYS_OP_DESCEND("EFFDT")=SYS_OP_DESCEND(:B7) AND
"D"."EMPL_RCD"=:B8 AND "D"."EMPLID"=:B9 AND SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))=:B10
))
5 - filter("SYS_ALIAS_7"."DEPTID" LIKE '%TE')
6 - access("SYS_ALIAS_7"."POSITION_NBR"="X"."POSITION_NBR"(+))
7 - access("SYS_ALIAS_7"."LOCATION"="Y"."LOCATION"(+))
9 - access("C"."EMPLID"=:B1 AND "C"."EMPL_RCD"=:B2 AND
SYS_OP_DESCEND("EFFDT")>=SYS_OP_DESCEND(TO_DATE(TO_CHAR(SYSDATE@!))) AND
SYS_OP_DESCEND("EFFDT") IS NOT NULL)
filter(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))<=TO_DATE(TO_CHAR(SYSDATE@!)))
11 - filter("SYS_ALIAS_2"."EMPL_STATUS"='A')
12 - access("SYS_ALIAS_2"."EMPLID"=:B1)
filter(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))= (SELECT
MAX(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))) FROM "SYSADM"."PS_JOB" "C" WHERE
SYS_OP_DESCEND("EFFDT") IS NOT NULL AND SYS_OP_DESCEND("EFFDT")>=SYS_OP_DESCEND(TO_DATE(TO
_CHAR(SYSDATE@!))) AND "C"."EMPL_RCD"=:B1 AND "C"."EMPLID"=:B2 AND
SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))<=TO_DATE(TO_CHAR(SYSDATE@!))))
14 - access("C"."EMPLID"=:B1 AND "C"."EMPL_RCD"=:B2 AND
SYS_OP_DESCEND("EFFDT")>=SYS_OP_DESCEND(TO_DATE(TO_CHAR(SYSDATE@!))) AND
SYS_OP_DESCEND("EFFDT") IS NOT NULL)
filter(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))<=TO_DATE(TO_CHAR(SYSDATE@!)))
16 - filter(:B1='A')
17 - access("D"."EMPLID"=:B1 AND "D"."EMPL_RCD"=:B2 AND
SYS_OP_DESCEND("EFFDT")=SYS_OP_DESCEND(:B3))
filter(SYS_OP_UNDESCEND(SYS_OP_DESCEND("EFFDT"))=:B1)

could you please help me under understand the process?

-Regads,
A.S

confusing question!

Dave, August 21, 2013 - 7:43 pm UTC

In our application developement team meeting, it was suggested that there is a way to force optimizer to evaluate a certain predicate first in a sql statement. However, we and our DBAs do not seem to be aware of how to do it.

example:

select...
from...
where...
and...
and....
and (sub query here..)<---- we want this to be addressed by optimizer first
and..
and...(sub query...)

Is this possible? Thnaks for your time.
Tom Kyte
August 28, 2013 - 5:53 pm UTC

sql is non procedural. the optimizer is free to merge, reorganize and process in any order it sees fit.


the optimizer used estimated cardinalities and cpu costs to decide what to process in what order.


I'd need a more concrete example to suggest a possible way to accomplish your goal.

Column Name in INDEX hint

AL SWAMY, September 06, 2013 - 5:07 pm UTC

Tom,

I would like to avoid hard-coding index name in INDEX hint because index name varies from environment as the table and indexes are dynamically created when we install the application. Is there a way to just mention the colum name inpalce of index name in the INDEX hint? Is there any other work around?

Thanks in advance.
Tom Kyte
September 10, 2013 - 9:30 am UTC

why are you using an index hint in the first place - that would be my first question. an index hint should be a "temporary workaround that we will be removing at the first opportunity".


but read about index hints, you don't need to use the name of the index, you can use the set of columns instead...

but don't use the hint... try instead to determine why the hint seems to be necessary. It will be because the estimated cardinality is "off". for example - we estimated we would get 100,000 rows from a table - but we only get 5. If we only get 5 - index makes sense. if we get 100,000 index would not make sense. So - because we got the wrong estimate we got the wrong plan.

so, why did we get the wrong estimate? could be many reasons (here is where your knowledge of how things work comes into play). it could be the stats are not representative of the data. it could be that the data is skewed and there were no histograms. it could be that it was a predicate on two columns (where x=5 and y=10) and there was a correlation between x and y we were not aware of - dynamic sampling level>=3, or sql profiles, or extended statistics might be useful. or maybe a sql plan baseline can be used and so on (notice the lack of hints here).

or maybe the query needs to be optimized to get the first 25 rows as soon as possible - it needed a first_rows(25) optimizer mode or hint (that is an ok hint, it adds information -- it doesn't tell the optimizer what to do, it helps it find the right plan naturally)

@ Dave from Chicago

Alistair, September 09, 2013 - 1:11 pm UTC

You can use short circuit evaluation to order the conditions if you rewrite your where clause:

where case
when [first condition] then 1
when other condition then 1
...
else 0
end = 1

I thought Oracle always used short circuit evaluation, but in SQL, it is only documented for case, coalesce and decode. Logical operators are only shortcircuited in PL/SQL.
Tom Kyte
September 10, 2013 - 9:48 am UTC

ummm, we do short circuit, what do you mean????

ops$tkyte%ORA11GR2> create table t ( x int, y int );

Table created.

ops$tkyte%ORA11GR2>
ops$tkyte%ORA11GR2> insert into t values ( 1, 0 );

1 row created.

ops$tkyte%ORA11GR2> select * from t where x >0 or x/y = 5;

         X          Y
---------- ----------
         1          0




you cannot control the *order of evaluation*, but things short circuit all of the time.

re short circuit

Alistair, September 10, 2013 - 1:43 pm UTC

That's what I thought, but I checked the SQL reference and could not find any guarantees.
Tom Kyte
September 23, 2013 - 5:31 pm UTC

all expressions will short circut,

they just might not short circut in the order you think they "should". we rewrite/merge/push/add new predicates all of the time. what you see is not what you get.

regarding "cant control order of evaluation "

Ranjan, September 23, 2013 - 9:25 am UTC

Hi Tom,

I am partially not agree with your statement "You cannot control the *order of evaluation*.
But totally agree with "but things short circuit all of the time".

BUT UNDER COST BASED OPTIMIZING YOUR FIRST STATEMENT IS TRUE,I AGREE WITH THAT.

I think under "rule based optimizer" one can control the *order of evaluation* as produced below.

############################
SQL*Plus: Release 10.2.0.1.0 - Production on Mon Sep 23 14:38:17 2013

Copyright (c) 1982, 2005, Oracle.  All rights reserved.

Enter password: *****

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options

SQL> create table t ( x int, y int );

Table created.

SQL> insert into t values ( 1, 0 );

1 row created.

SQL> commit;

Commit complete.

SQL> select * from t where x >0 or x/y = 5;

         X          Y
---------- ----------
         1          0

SQL> select * from t where x/y = 5 or x > 0;

         X          Y
---------- ----------
         1          0

SQL> set autotrace traceonly explain
SQL> select * from t where x >0 or x/y = 5;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |    26 |     3   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| T    |     1 |    26 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("X">0 OR "X"/"Y"=5)

Note
-----
   - dynamic sampling used for this statement

SQL>  select * from t where x/y = 5 or x > 0;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     5 |   130 |     3   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| T    |     5 |   130 |     3   (0)| 00:00:01 |
--------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("X">0 OR "X"/"Y"=5)

SQL> select /*+ rule */ from t where x>0 or x/y=5;
select /*+ rule */ from t where x>0 or x/y=5
                   *
ERROR at line 1:
ORA-00936: missing expression


SQL> select /*+ rule */  * from t where x>0 or x/y=5;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

----------------------------------
| Id  | Operation         | Name |
----------------------------------
|   0 | SELECT STATEMENT  |      |
|*  1 |  TABLE ACCESS FULL| T    |
----------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("X">0 OR "X"/"Y"=5)

Note
-----
   - rule based optimizer used (consider using cbo)

SQL> select /*+ rule */  * from t where x/y=5 or x>0;

Execution Plan
----------------------------------------------------------
Plan hash value: 1601196873

----------------------------------
| Id  | Operation         | Name |
----------------------------------
|   0 | SELECT STATEMENT  |      |
|*  1 |  TABLE ACCESS FULL| T    |
----------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("X"/"Y"=5 OR "X">0)

Note
-----
   - rule based optimizer used (consider using cbo)

SQL> set autotrace off
SQL> select /*+ rule */  * from t where x/y=5 or x>0;
select /*+ rule */  * from t where x/y=5 or x>0
                                    *
ERROR at line 1:
ORA-01476: divisor is equal to zero      -------------- THAT IS WHY IT GAVE ERROR.

#################

Could you please clarify my above test.

Regards,
ranjan.

order of evaluation

Alistair, September 30, 2013 - 2:21 pm UTC

The documentation for 11.2 ( http://docs.oracle.com/cd/E11882_01/server.112/e41084/conditions001.htm#i1034172 ) says:

Oracle evaluates conditions with equal precedence from left to right within an expression, with the following exceptions:

Left to right evaluation is not guaranteed for multiple conditions connected using AND

Left to right evaluation is not guaranteed for multiple conditions connected using OR

tkprof execute different after stats import

Andre, October 30, 2013 - 12:07 pm UTC

Hi Tom,

I have tried to check for any difference in performance in a view built on a set of 48 Global Temp tables - defined with a TXN number as a PK.
The population of these GTT is the same within any session, however there are differences between sessions and these vary between 8000 rows in all 48 GTT and 300 rows.

I had executed this merge within a procedure = a loop with bulk collect from this view with limit of 1000.

I had timed executions in 2 scenarios: (a) with the stats on GTT being available and (b) stats being deleted.

Then I ran the same procedure repeating the read from the view to merge the same data from the 48 GTT however with stats being available not - as follows:
1) Initial gather stats on all 48 GTT pop 8000 rows
2) Stats deleted
3) Stats imported with statid corresponding to 8000 rows
4) Stats deleted
5) Stats imported with statid corresponding to 480 rows
6) Stats deleted
7) Stats imported with statid corresponding to 8000 rows

I had used dbms_monitor with waits and binds => TRUE and then I examined the generated TRC file with TKPROF - however stipulating Aggregate = NO - so that I could see outputs for every one of the 7 sets of executions

PARSE was 1 sec for the first then 0 for all other 6 = OK.
FETCH was count=8 (i.e. 8 loops) approx 3 sec - however showing consistently shorter time WITHOUT stats on GTT available

EXECUTE however was showing 0 sec when stats were deleted and approx 1 cpu-sec with stats present

Please see below the 7 segments from TKPROF related to the bulk collect from the view based on 48 GTT:

I would appreciate some explanation for this - or suggestion as to a different test

Thank you
Andre

STEP-01:
========
SQL ID: d69kfu8a83rsq
Plan Hash: 832837433
SELECT *
FROM
EXT_TMIS_LOAD_XV


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.97 1.10 0 1 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 8 3.49 3.88 1494 6389 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 10 4.46 4.99 1494 6390 0 7906


STEP-02:
========
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 8 3.23 6.29 0 5093 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 3.23 6.29 0 5093 0 7906

STEP-03:
========
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 1.03 1.09 0 1 0 0
Fetch 8 3.29 3.68 0 5093 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 4.32 4.78 0 5094 0 7906

STEP-04:
========
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 8 3.05 3.43 0 5093 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 3.05 3.43 0 5093 0 7906

STEP-05:
========
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.98 1.03 0 1 0 0
Fetch 8 3.18 3.46 0 5093 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 4.16 4.50 0 5094 0 7906

STEP-06:
========
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 0.01 0.00 0 0 0 0
Fetch 8 3.04 3.13 0 5093 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 3.05 3.13 0 5093 0 7906

STEP-07:
========
call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 0 0.00 0.00 0 0 0 0
Execute 1 1.15 2.29 0 1 0 0
Fetch 8 3.34 6.90 0 5093 0 7906
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 9 4.49 9.19 0 5094 0 7906


SQL Query Help

Vikas, November 03, 2014 - 5:10 pm UTC

Dear Mr. Kyte,

Greetings. Hope you are doing great.:-)

First of all my apologies if this is a wrong category/section, under which I am posting me question.

I have the following scenario where by I have-

1) A regular user-segments (system table)
2) A set of few tables which have a column by the name "When_created timestamp"

Requirement:
============
To generate a report that would provide -

Tablename (segment name from user_segments).
Oldest Record (min(when created from the actual tables.
Size of Tables (bytes/1024/1024/1024 from user_segments).

Ex -
=====

TABLE NAME                 TABLE SIZE (GB)        WHEN_CREATED (OLDEST)
=======================   =================    ===========================
TABLE-1                          8.61        27-SEP-11 22.15.03.000000
TABLE-2                            16.25        07-JUN-12 21.53.52.000000
TABLE-3                          2.06        27-SEP-11 22.15.03.000000

Though I was able to do this using Pl/Sql, but I was just wondering if i could have done this using simple SQL?

I tried achieving this using various SQL queries, but couldn't get it right, either I was able to get the above details for just one table or the script just failed returning errors.


Need your Insight:
==================
Would you please let me know -
1) If this is doable using the simple SQL at all?
2) If yes, for my better understanding, can you share the SQL code that shows how once can achieve this in SQL?
3) What tip would you like to give us when met be such requirements, how can we fasten up the performance from such queries?

Thanks & regards
Vikas.

Code Redundancy

Paras, June 23, 2015 - 2:48 pm UTC

Hi,

Need help on avoid such redundancy in the sql code

select dname from dept where deptno = xx.

Below is the example for such sql:

select column1,
column2,
(select dname from dept where deptno=10) dept10,
(select dname from dept where deptno=20) dept20
from dual
where column1 = xyz;

how it can be achieved in some other way

good

A reader, July 01, 2019 - 9:13 pm UTC

You can do explain plan set statement_id=some id
for paste the SQL here

look for index scan, bad index scan, full table scans etc
or do a set autotrace on and run the sql

hope it works for you

good

A reader, July 01, 2019 - 9:13 pm UTC

You can do explain plan set statement_id=some id
for paste the SQL here

look for index scan, bad index scan, full table scans etc
or do a set autotrace on and run the sql

hope it works for you

More to Explore

Performance

Get all the information about database performance in the Database Performance guide.