Re: Force specific plan to be used
From: Tanel Poder <tanel_at_tanelpoder.com>
Date: Thu, 31 Oct 2019 23:29:43 -0400
Message-ID: <CAMHX9JKkbh7pS88bzfUbymt+k7AkD=m1rvQBG709PhFa15t19w_at_mail.gmail.com>
Date: Thu, 31 Oct 2019 23:29:43 -0400
Message-ID: <CAMHX9JKkbh7pS88bzfUbymt+k7AkD=m1rvQBG709PhFa15t19w_at_mail.gmail.com>
Tanel.
On Thu, Oct 31, 2019 at 11:17 PM Tanel Poder <tanel_at_tanelpoder.com> wrote:
> The OP said that the plan *hash value* didn't change, but since the > predicate placement doesn't affect the hash value, it's worth confirming on > which plan lines the predicates are applied. > > You'd just make sure that the predicates in both plans (with the same plan > hash value) are on the same lines, "operation id"-s as highlighted below: > > SELECT SUM(order_total) FROM soe.orders WHERE order_id = 5 > > Plan hash value: 1761615243 > > ------------------------------------------------------------------- > | Id | Operation | Name | Starts | E-Rows | > ------------------------------------------------------------------- > | 0 | SELECT STATEMENT | | 1 | | > | 1 | SORT AGGREGATE | | 1 | 1 | > | 2 | TABLE ACCESS BY INDEX ROWID| ORDERS | 1 | 1 | > |* 3 | INDEX UNIQUE SCAN | ORDER_PK | 1 | 1 | > ------------------------------------------------------------------- > > Predicate Information (identified by operation id): > --------------------------------------------------- > > * 3 - access("ORDER_ID"=5)* > > > Tanel. > > On Thu, Oct 31, 2019 at 10:39 PM Chris Taylor < > christopherdtaylor1994_at_gmail.com> wrote: > >> But wouldn't that show up in the plan? I must be missing something. >> >> How can you tell by examining the predicate section where the filtering >> is occurring? >> >> Chris >> >> On Thu, Oct 31, 2019, 8:35 PM Tanel Poder <tanel_at_tanelpoder.com> wrote: >> >>> Even if the plan hash values are the same, go still ahead and compare >>> the predicate sections of the good vs bad child cursors. >>> >>> Predicate existence (or placement) is not part of the plan hash value - >>> so how early you're filtering the rows may differ. >>> >>> Tanel Poder >>> https://blog.tanelpoder.com/seminar >>> >>> On Thu, Oct 31, 2019 at 2:03 PM Jeffrey Beckstrom <jbeckstrom_at_gcrta.org> >>> wrote: >>> >>>> I have a couple of SQL statements that have multiple child cursors. >>>> Each child cursor has the same plan hash value. The plans all show "this is >>>> an adaptive plan (rows marked '-' are inactive)". The difference is that on >>>> the "good" child cursor, the plan also shows "statistics feedback used for >>>> this statement". Since all of the plans have the same plan hash value, I >>>> can not use baselines (or can I). >>>> >>>> Any suggestions on how to force Oracle to always use the "good" child >>>> cursor. >>>> >>>> Jeffrey Beckstrom >>>> Lead Database Administrator >>>> Information Technology Department >>>> Greater Cleveland Regional Transit Authority >>>> 1240 W. 6th Street >>>> Cleveland, Ohio 44113 >>>> >>>>
-- http://www.freelists.org/webpage/oracle-lReceived on Fri Nov 01 2019 - 04:29:43 CET