Re: Mutating (SQL) execution plan!?...is that possible...stranges t thing I have every seen

  • From: "Jonathan Lewis" <jonathan@xxxxxxxxxxxxxxxxxx>
  • To: <oracle-l@xxxxxxxxxxxxx>
  • Date: Fri, 11 Mar 2005 08:48:14 -0000


Steve.

Not only does Oracle re-parse the statement
when it finds there is a predicate on a column
with a histogram - it does bind variable substitution
first and THEN 'de-substitutes'.  So the parse costs
go up (rather than 'just' staying the same) if you
have redundant histograms in place.

I have never seen what Oracle calls an "unsafe"
statement (i.e. <, >, between, those types of
conditions in the where clause) be reparsed
unless the histogram condition was met - have you ?

Even though the claim is lurking somewhere in
an official Oracle document (was it an OW
white-paper), I suspect it is complete rubbish.
(at least up to 9i - it occurs to me that I haven't
repeated that set of tests on 10g yet).


Regards

Jonathan Lewis

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

http://www.jlcomp.demon.co.uk/seminar.html
Public Appearances - schedule updated March 9th 2005






----- Original Message ----- 
From: "Dirschel, Steve" <Steve.Dirschel@xxxxxxxxxxx>
To: <breitliw@xxxxxxxxxxxxx>; <john.kanagaraj@xxxxxxx>
Cc: <oracle-l@xxxxxxxxxxxxx>
Sent: Thursday, March 10, 2005 7:05 PM
Subject: RE: Mutating (SQL) execution plan!?...is that possible...stranges t 
thing I have every seen


I don't know I'd recommend they go to SIMILAR from FORCE if they're
using a lot of histograms.  SIMILAR causes Oracle to reparse sql
statements if they're considered "unsafe" (i.e. <, >, between, those
types of conditions in the where clause).

After much pain we found Oracle has a feature where if SIMILAR is used
and histograms exist on WHERE clause columns Oracle will consider that
statement=20
"unsafe" and reparse (version_count increases for the statement).  Even
if there is a histogram on a PK column and the WHERE clause has WHERE
pk_column =3D value Oracle still reparses it...(every time it executes,
not every time the plan changes).  If they're running FORCE now and they
change to SIMILAR I'd expect them to all of a sudden experience
(assuming a relatively active system) latching related to the parsing
and possible shared pool issues (4031).  It took us 3+ months of working
with Oracle to determine SIMILAR + HISTOGRAMS =3D REPARSING.  But once =
it
was determined that was the case Oracle came back saying the behavior
was expected



--
//www.freelists.org/webpage/oracle-l

Other related posts: