RE: Memory Issue

From: Noveljic Nenad <nenad.noveljic_at_vontobel.com>
Date: Wed, 23 Dec 2020 12:29:26 +0000
Message-ID: <22912_1608726584_5FE33838_22912_9373_1_3959f5a930ce41b7aba9422fdb449e50_at_vontobel.com>



“My first guess (on a bare minimum of information) would be that you have a statement with a monster IN-list”

In this case, it’s worth checking if Pap hits the bug “16825679 : PARSING NEVER ENDS”. The bug strikes when there’s a long IN lists on a column that is a part of extended statistics. The workaround is: _optimizer_extended_stats_usage_control = 224.

“I tried executing the query manually by passing some sample bind values(which again may not be the actual binds which caused the issue). i see the query finishing in seconds even with and without rows.”

You might be reusing the cached execution plan when executing the query manually.

Best regards,

Nenad

From: oracle-l-bounce_at_freelists.org <oracle-l-bounce_at_freelists.org> On Behalf Of Pap Sent: Mittwoch, 23. Dezember 2020 13:14 To: jlewisoracle_at_gmail.com
Cc: Oracle L <oracle-l_at_freelists.org> Subject: Re: Memory Issue

I see the top_level_sql_id is getting populated with same sql_id and the sql_exec_id column is all null along with sql_exec_start for all of those ~30K samples. Now i also checked gv$sql and see the last_load_time showing as ~2 days back and the EXECUTIONs column showing figure 15, so which means even i just consider today's ~30 minutes execution happen for that same sql , it still looks lot more for those total ~15 executions.

I tried executing the query manually by passing some sample bind values(which again may not be the actual binds which caused the issue). i see the query finishing in seconds even with and without rows. So is it possible that some specific bind is causing the issue?

On Wed, Dec 23, 2020 at 5:32 PM Jonathan Lewis <jlewisoracle_at_gmail.com<mailto:jlewisoracle_at_gmail.com>> wrote: A couple of thoughts.
First - the AWR output looks a little odd - the Total Executions is lower than the Total Parse Calls. Any idea why ? (It may be completely unrelated to your problem, of course).

Secondly - this looks like a sys-recursive statement that would be executed while a statement is being parsed, but normally such a statement would only be called a few times because it would be populating the dictionary cache (v$rowcache). There are some bit of the dictionary, that don't get cached, though (parts of views, parts of histograms, maybe) so it's possible that what you're seeing is a strange parsing issue relating to a parent statement. When you see this SQL (sql_id) in the sample there are two other columns you can check: top_level_sql_id, and sql_exec_id. THe former MAY tell you about a statement that is being parsed, the latter may give you an idea of how many times this statement is actually called.

My first guess (on a bare minimum of information) would be that you have a statement with a monster IN-list and Oracle is trying to optimize a massive UNION ALL where every branch is accessing a view.

Regards
Jonathan Lewis

ASH / v$active_session_history from your 25 minute run with 25,000 samples. One of the columns of

On Tue, 22 Dec 2020 at 18:12, Pap <oracle.developer35_at_gmail.com<mailto:oracle.developer35_at_gmail.com>> wrote:

Hello Friends, this is version 11.2.0.4 database. I am struggling to understand the reason behind sudden memory saturation in one of our hosts causing multiple databases to be brought to its knee. The host memory utilization went up from ~30% to 100%(~500GB) within ~3-4hrs. After digging into this we found it's one of the databases whose pga was bumped to almost ~500+ GB and the oem was filled with concurrency wait (Library cache: mutex X) with the below sql being highlighted was singled out as the one.We end up killing all the processes related top this query and few others after which the other databases in that host then came up to speed. And also this query was showing the program as "Jdbc Thin client".

However in the AWR i don't see any oddity i.e. this below query was not showing in the top in those parse or version count sections in the AWR. And in the dba_hist_active_sess_history the flags "in_parse" ,"in_sql_execution","IN_HARD_PARSE" were all showing as "N" throughout the issue period.

So wanted to check if anybody else has encountered such an issue because this sql seems to be a normal one (or say some recursive sql). So if there are any chances of memory leak or any related stuff? Also i saw there were not many sessions running this query , so wondering how come this query can cause such drastic memory consumption?

SELECT obj#, type#, ctime, mtime, stime, status,dataobj#, flags,oid$,spare1,spare2

 FROM obj$

 WHERE owner# = :1 AND name = :2

    AND namespace = :3 AND (remoteowner = :4 OR remoteowner IS NULL AND :4 IS NULL)

    AND (linkname = :5 OR linkname IS NULL AND :5 IS NULL)

    AND (subname = :6 OR subname IS NULL AND :6 IS NULL)

Section of AWR:-

<https://us.v-cdn.net/6032257/uploads/35FPPSKFLLVS/image.png>



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

<html xmlns="http://www.w3.org/1999/xhtml">
<head>
<meta http-equiv="Content-Type" content="text/html; charset=iso-8859-1">
<style type="text/css">p { font-family: Arial;font-size:9pt }</style>
</head>
<body>
<p>
<br>Important Notice</br>
<br />

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.<br /> 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.<br /> 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.</br> 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.<br /> 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 <a href="https://www.vontobel.com">www.vontobel.com</a>.<br />
</p>
</body>
</html>

--
http://www.freelists.org/webpage/oracle-l
Received on Wed Dec 23 2020 - 13:29:26 CET

Original text of this message