RE: sql_text during parsing

From: Noveljic Nenad <nenad.noveljic_at_vontobel.com>
Date: Tue, 13 Jul 2021 16:00:46 +0000
Message-ID: <3ee6cc7d0c294bd5988d224d42945f9e_at_vontobel.com>



A small add-on to Jonathan’s perfect summary.

The following configuration will kill the monster if it comes again (credits to Sayan Malakshinov - my go-to place for Oracle diagnostic ☺ : https://twitter.com/dbms_xtender/status/1392499158368624641 ):

alter system set events 'trace [SQL_Compiler.*][sql: 99g4t6h9kfumw] {callstack: fname opiParse} controlc_signal()' ;

I’m not a mean person, but this SQL was generated by some convoluted Tableau workflow that shouldn’t run anymore (at least, they said so).

“Thanks”, I said, and then prepared for the worst.

Best regards,

Nenad

From: oracle-l-bounce_at_freelists.org <oracle-l-bounce_at_freelists.org> On Behalf Of Jonathan Lewis Sent: Dienstag, 13. Juli 2021 13:41
To: ORACLE-L (oracle-l_at_freelists.org) <oracle-l_at_freelists.org> Subject: Re: sql_text during parsing

Now that the heavy lifting has been done, I've got a couple of tweaks (which I've already mentioned on twitter) to echo here. In fact it's not going to make much difference to the trace in this example since the text is 70M, but you can reduce the content in the trace.

Looking at the error dump it appears that all we really need is a Session Cursor Dump as the SQL text from sql that is too long for the basic cursor dump format seems to be reported separately at the end of the dump; so change errorstack(2) to cursordump(1).

We trigger the dump on a call to opiparse - but in the test we parse a pl/sql package, we do some recursive SQL parsing, and so on - so opt parse is called a few times when we don't want it to be called; since we know the SQL_ID of the sql we're interested in, limit trace to just that SQL_ID with [SQLxxxxxxxxxxxxx].

Just in case the SQL is called (and has to be parsed) several times in the lifetime of a session, and doesn't end up in the cursor or pl/sql cache avoiding opiparse) let's make sure that we only dump the trace once using the {occurences: ....} option.

So the final thing I tried, based on Sayan's original test looked like this:

alter session set events 'trace [SQL_Compiler][SQL:69153ssxd3180]{callstack: fname opiParse} {occurence: end_after 1} disk=low cursordump(1)';

YMMV, but in a re-run of the tests for this note, the trace file dropped from 5MB to 500KB

Regards
Jonathan Lewis



Please consider the environment before printing this e-mail. Bitte denken Sie an die Umwelt, bevor Sie dieses E-Mail drucken.

Important Notice

This message is intended only for the individual named. It may contain confidential or privileged information. If you are not the named addressee you should in particular not disseminate, distribute, modify or copy this e-mail. Please notify the sender immediately by e-mail, if you have received this message by mistake and delete it from your system. Without prejudice to any contractual agreements between you and us which shall prevail in any case, we take it as your authorization to correspond with you by e-mail if you send us messages by e-mail. However, we reserve the right not to execute orders and instructions transmitted by e-mail at any time and without further explanation. E-mail transmission may not be secure or error-free as information could be intercepted, corrupted, lost, destroyed, arrive late or incomplete. Also processing of incoming e-mails cannot be guaranteed. All liability of Vontobel Holding Ltd. and any of its affiliates (hereinafter collectively referred to as "Vontobel Group") for any damages resulting from e-mail use is excluded. You are advised that urgent and time sensitive messages should not be sent by e-mail and if verification is required please request a printed version. Please note that all e-mail communications to and from the Vontobel Group are subject to electronic storage and review by Vontobel Group. Unless stated to the contrary and without prejudice to any contractual agreements between you and Vontobel Group which shall prevail in any case, e-mail-communication is for informational purposes only and is not intended as an offer or solicitation for the purchase or sale of any financial instrument or as an official confirmation of any transaction. The legal basis for the processing of your personal data is the legitimate interest to develop a commercial relationship with you, as well as your consent to forward you commercial communications. You can exercise, at any time and under the terms established under current regulation, your rights. If you prefer not to receive any further communications, please contact your client relationship manager if you are a client of Vontobel Group or notify the sender. Please note for an exact reference to the affected group entity the corporate e-mail signature. For further information about data privacy at Vontobel Group please consult www.vontobel.com <https://www.vontobel.com>.

--
http://www.freelists.org/webpage/oracle-l
Received on Tue Jul 13 2021 - 18:00:46 CEST

Original text of this message