From oracle-l-bounce@freelists.org Fri Mar 11 03:51:39 2005 Return-Path: Received: from air891.startdedicated.com (root@localhost) by orafaq.com (8.12.10/8.12.10) with ESMTP id j2B9pcvl012042 for ; Fri, 11 Mar 2005 03:51:38 -0600 X-ClientAddr: 206.53.239.180 Received: from turing.freelists.org (freelists-180.iquest.net [206.53.239.180]) by air891.startdedicated.com (8.12.10/8.12.10) with ESMTP id j2B9pcem012038 for ; Fri, 11 Mar 2005 03:51:38 -0600 Received: from localhost (localhost [127.0.0.1]) by turing.freelists.org (Avenir Technologies Mail Multiplex) with ESMTP id D5F907F13A; Fri, 11 Mar 2005 03:50:03 -0500 (EST) Received: from turing.freelists.org ([127.0.0.1]) by localhost (turing [127.0.0.1]) (amavisd-new, port 10024) with ESMTP id 20721-04; Fri, 11 Mar 2005 03:50:03 -0500 (EST) Received: from turing (localhost [127.0.0.1]) by turing.freelists.org (Avenir Technologies Mail Multiplex) with ESMTP id 53F277F083; Fri, 11 Mar 2005 03:50:03 -0500 (EST) Message-ID: <008601c52617$139544a0$6702a8c0@Primary> From: "Jonathan Lewis" To: References: Subject: Re: Mutating (SQL) execution plan!?...is that possible...stranges t thing I have every seen Date: Fri, 11 Mar 2005 08:48:14 -0000 MIME-Version: 1.0 Content-type: text/plain; charset=iso-8859-1 Content-Transfer-Encoding: 8bit X-MIMEOLE: Produced By Microsoft MimeOLE V6.00.2900.2180 X-archive-position: 17189 X-ecartis-version: Ecartis v1.0.0 Sender: oracle-l-bounce@freelists.org Errors-To: oracle-l-bounce@freelists.org X-original-sender: jonathan@jlcomp.demon.co.uk Precedence: normal Reply-To: jonathan@jlcomp.demon.co.uk X-list: oracle-l X-Virus-Scanned: by amavisd-new-20030616-p9 (Debian) at avenirtech.net X-Spam-Checker-Version: SpamAssassin 2.60 (1.212-2003-09-23-exp) on air891.startdedicated.com X-Spam-Status: No, hits=0.2 required=5.0 tests=AWL,PLING_QUERY autolearn=no version=2.60 X-Spam-Level: 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" To: ; Cc: 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 -- http://www.freelists.org/webpage/oracle-l