Re: Force specific plan to be used

From: Jonathan Lewis <jonathan_at_jlcomp.demon.co.uk>
Date: Thu, 31 Oct 2019 19:07:35 +0000
Message-ID: <CWXP265MB1750CDDF3AB6B44971AF81CDA5630@CWXP265MB1750.GBRP265.PROD.OUTLOOK.COM>


I think I must have hit "reply" instead of "reply" all on the last message.

The two rows you've sent have four columns labelle I I I I - I'm guessing that the last two are "is_bind_aware" and "is_bind_sensitive", and the first child has both of these as Y - which makes you wonder how a statement with only literals can be bind_aware.

The query is against user_tables, etc. So one thing to check is whether the parsing_user_id, parsing_schema_id are the same in both cases. I think the dictionary views you query also have scalar subqueries and functions in the select list that could do different amounts of work for different users, and there are plenty of calls to sys_context() in them that could result in different amounts of work for the same plan.

If the queries run a few dozen times an hour you might inject a /*+ monitor */ hint into them as an SQL_Patch if you're licensed to use the diagnostic and performance packs - this might let you see what's different between different rates of execution and where the different plans do their work.

Regards
Jonathan Lewis



From: oracle-l-bounce_at_freelists.org <oracle-l-bounce_at_freelists.org> on behalf of Jeffrey Beckstrom <jbeckstrom_at_gcrta.org> Sent: 31 October 2019 18:27
To: Chris Taylor
Cc: oracle-l-freelist
Subject: Re: Force specific plan to be used

As stated, the parent and child cursor have the same plan_hash value. The SQL uses literals and they are the same. In the good child, it states "statistics feedback used for this statement" - that makes it better.
>>> Chris Taylor <christopherdtaylor1994_at_gmail.com> 10/31/19 2:22 PM >>>
So, to be clear, the all the cursors have the same plan ? (Both good and bad) ? If that's true , then a sql plan isn't the problem. Sounds like one of the child cursors is working on a lot less data if its using the same execution plan and performing much better.

However, if the one good cursor is showing a different plan, look up the coe_xfr_sql_profile.sql from Carlos. It takes a SQL_ID and a PLAN_HASH_VALUE and creates an sql script to force a SQL profile for that specific plan. Then you execute the sql script that is generated to create the profile in the db.

Chris

On Thu, Oct 31, 2019 at 2:03 PM Jeffrey Beckstrom <jbeckstrom_at_gcrta.org<mailto: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



This email has been scanned for spam and viruses. Click here<https://attseg.cloud-protect.net/index01.php?mod_id=11&mod_option=logitem&mail_id=1572546192-5KRkM39NwgMG&r_address=jbeckstrom%40gcrta.org&report=1> to report this email as spam.
--
http://www.freelists.org/webpage/oracle-l
Received on Thu Oct 31 2019 - 20:07:35 CET

Original text of this message