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 Connor 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