Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: ORA-04031: unable to allocate 4200 bytes of shared memory

Re: ORA-04031: unable to allocate 4200 bytes of shared memory

From: Tim Hall <timhall1_at_gmail.com>
Date: Fri, 4 Mar 2005 14:53:12 -0800
Message-ID: <6043f3710503041453be587f@mail.gmail.com>


You're right, flushing the shared pool doesn't truly fix anything; if you're lucky, it just makes the problem go away for a while, to give you time to figure out what is really wrong. So...

Keep an eye on what gets stored in the SGA:

Make sure packages, procedures, functions, triggers, etc. are pinned (triggers are easy to forget, and developers sometimes put large chunks of code in triggers that would be better placed in packages).

Make sure developers are assembling code into packages and not submitting large anonymous blocks of PL/SQL throughout the day (especially watch shell scripts and SQL*Plus scripts where substitution variables may be used in place of bind variables, as that will compound the problem by filling up the SGA with nearly-identical large blocks of code).

Make sure dynamic SQL is only used when truly necessary, and when it is used, that variables are appropriately bound. It may be especially worthwhile to perform code reviews on programs written in Java, Perl, and 3GLs, to look for coding style "lapses"...

Keep an eye out for unnecessary or unreasonable traffic into the SGA:

Watch out for "phantom SQL" -- things like indiscriminate use of SYS_CONTEXT or USER in PL/SQL blocks. These generate silly SELECTs from DUAL behind the scenes (maybe not in 10g?). I have seen cases where hundreds of millions of these statements were flooding the SGA without the developers realizing it.

Watch out for "SGA abuse", like silly repeated lookups of static values from the database. I recall a case where a certain small table of static strings was being queried one billion times a day. There were only about 1000 rows in this table. By caching previously-fetched values in a PL/SQL table in the package, we reduced the number of submissions (executions) of the actual SQL statement by over 99.99%.

(Finally, if your ORA-4031 results in a database crash, please call Oracle and complain. There is really no good reason for an ORA-4031 to cause anything more than a brief slowdown or an error in a single session!)

Your mileage may vary. Hope this helps -- Tim

On Thu, 3 Mar 2005 10:54:52 -0800 (PST), A Joshi <ajoshi977_at_yahoo.com> wrote:
> If you have increased the size it is likely bacause of fragmentation. Pin pl/sql on database startup. and pin sql soon after startup. Get dev to use bind variables.
> You could change the cursor_sharing parameter too but that is avoidable.
> Avoid ad hoc sql queries to database.
> "Smith, Ron L." <rlsmith_at_kmg.com> wrote:
> I have a couple of unrelated Oracle 8.1.7 databases that occasionally
> getting the following error:
> ORA-04031: unable to allocate 4200 bytes of shared memory ("shared
> pool","unknown object","sga heap","state objects")=20
>
> Flushing the Shared Pool does not help the problem. The size of the
> Shared Pool has been increased several times, but doesn't appear to
> help. Neither database is very busy.
>
> One of the databases serves as a "Gateway" database between a 7.3.4 and
> a 9.2 database just for connectivity. The other is just a straight
> 8.1.7 OLTP database.
>
> Bouncing the database ALWAYS corrects the problem for several weeks.
>
> Can anyone help be diagnose the problem?
>
> Thanks!
> Ron
>
> Important Notice!!
> If you are not the intended recipient of this e-mail message, any use, =
> distribution or copying of the message is prohibited.
> Please let me know immediately by return e-mail if you have received =
> this message by mistake, then delete the e-mail message.
> Thank you.
> --
> http://www.freelists.org/webpage/oracle-l
>
> ---------------------------------
> Celebrate Yahoo!'s 10th Birthday!
> Yahoo! Netrospective: 100 Moments of the Web
>
> --
> http://www.freelists.org/webpage/oracle-l
>

--
http://www.freelists.org/webpage/oracle-l
Received on Fri Mar 04 2005 - 17:56:23 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US