RE: ora-04031

  • From: Michael Milligan <Michael.Milligan@xxxxxxxxxxx>
  • To: "'oracle-l@xxxxxxxxxxxxx'" <oracle-l@xxxxxxxxxxxxx>
  • Date: Thu, 11 Mar 2004 10:58:40 -0600

The error means an object is trying to load in shared memory and can not
find contiguous space to do so. 

Set your sga_max_size higher, so it allows you to dynamically alter sga size
with the DB running. Also, set your values for shared_memory and
shared_memory_reserved_space higher. The shared_memory_reserved_space should
be 10% of your shared_memory space. This reserves space for large
objects(not talking about LOBs here, just large packages, etc.) that would
not ordinarily fit.

HTH

Mike

-----Original Message-----
From: Feighery Raymond [mailto:Raymond.Feighery@xxxxxxxxxxxxx]
Sent: Thursday, March 11, 2004 4:53 AM
To: 'oracle-l@xxxxxxxxxxxxx'
Subject: RE: ora-04031


I had a similar problem with 9iAS, MTS and the Large Pool. As Apache was
indefinitely reusing each HTTP child server process for multiple requests
the memory the child process required in the Large Pool constantly increased
until ORA-4031.

The solution was to set MaxRequestsPerChild to > 0 (e.g. 50). It defaults to
0 (unlimited). Setting it to non-zero may incur a small performance hit.

Here's a script I copied from somewhere (sorry unknown author) which may
help diagnose your problem. 

It may also help to set an event e.g. event = "4031 trace name errorstack
level 4" to generate a trace when the error occurs.

By the way, what version of iAS, RDBMS and OS are you on?

Ray


prompt *********************************** 
prompt *********************************** 
prompt Diagnosing ORA-4031 
prompt *********************************** 
prompt *********************************** 
prompt THE SGA 
select * from v$sgastat; 
PROMPT SHARED_POOL_RESERVED_MIN_ALLOC 
select val.ksppstvl VALUE 
from x$ksppi nam, 
x$ksppsv val 
where nam.indx = val.indx 
and nam.ksppinm = '_shared_pool_reserved_min_alloc' 
order by 1 
/ 
SELECT free_space, avg_free_size, used_space, 
avg_used_size, request_failures, last_failure_size 
FROM v$shared_pool_reserved; 
prompt The ORA-04031 is a result of lack of contiguous space in the shared
pool 
prompt reserved space if: 
prompt REQUEST_FAILURES is > 0 and LAST_FAILURE_SIZE is > 
prompt SHARED_POOL_RESERVED_MIN_ALLOC. 
prompt To resolve this consider increasing SHARED_POOL_RESERVED_MIN_ALLOC to
lower 
prompt the number of objects being cached into the shared pool reserved
space and 
prompt increase SHARED_POOL_RESERVED_SIZE and SHARED_POOL_SIZE to increase
the 
prompt available memory in the shared pool reserved space. 
prompt The ORA-04031 is a result of lack of contiguous space in the library
cache if: 
prompt REQUEST_FAILURES is > 0 and LAST_FAILURE_SIZE is < 
prompt SHARED_POOL_RESERVED_MIN_ALLOC 
prompt or 
prompt REQUEST_FAILURES is 0 and LAST_FAILURE_SIZE is <
SHARED_POOL_RESERVED_MIN_ALLOC 


-----Original Message-----
From: George Leonard [mailto:leonarge@xxxxxxxxxxxxx]
Sent: Thursday, March 11, 2004 10:23 AM
To: oracle-l@xxxxxxxxxxxxx
Subject: RE: ora-04031


Hi there
 
It seems this did not help. (problem was not on the application server
infrastructure database)
 
And as for the production database the shared pool is huge and most of it is
unused and free.
 
I am looking at scripts to see if I can figure out what the problem is.
 
 
 
George
 
________________________________________________
 
George Leonard
Oracle Database Administrator
Dimension Data (Pty) Ltd
(Reg. No. 1987/006597/07)
Tel: (+27 11) 575 0573
Fax: (+27 11) 576 0573
E-mail:george.leonard@xxxxxxxxxxxxx
Web:   http://www.didata.co.za
 
You Have The Obligation to Inform One Honestly of the risk, And As a Person
You Are Committed to Educate Yourself to the Total Risk In Any Activity!
Once Informed & Totally Aware of the Risk, 
Every Fool Has the Right to Kill or Injure Themselves as They See Fit!
 
 
-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx [mailto:oracle-l-bounce@xxxxxxxxxxxxx]
On Behalf Of George Leonard
Sent: 11 March 2004 10:54 AM
To: oracle-l@xxxxxxxxxxxxx
Subject: RE: ora-04031
 
Hi there

We found something interesting, it normally happens on a specific set of
queries, big ones. What we found if execute via the front end (Oracle
Application server involved) we get this error, if executed via toad
directly on the back end we have no problems.

What we are thinking is that the error is actually produced by the
application servers infrastructure database. We are altering the shared
pool and buffer cache parameters for this and restarting the environment
to see if this resolves our problems.

George

________________________________________________

George Leonard
Oracle Database Administrator
Dimension Data (Pty) Ltd
(Reg. No. 1987/006597/07)
Tel: (+27 11) 575 0573
Fax: (+27 11) 576 0573
E-mail:george.leonard@xxxxxxxxxxxxx
Web: http://www.didata.co.za

You Have The Obligation to Inform One Honestly of the risk, And As a
Person
You Are Committed to Educate Yourself to the Total Risk In Any Activity!
Once Informed & Totally Aware of the Risk, 
Every Fool Has the Right to Kill or Injure Themselves as They See Fit!



-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx] On Behalf Of
chris@xxxxxxxxxxxxxxxxxxxxx
Sent: 11 March 2004 10:47 AM
To: oracle-l@xxxxxxxxxxxxx
Subject: Re: ora-04031

George, 

Does this always happen even after a shutdown and restart of the
database? 
It might help to look at the size of the free chunks in the SGA. Steve
Adam's 
ixora site (www.ixora.com.au) has some excellent scripts for getting the
size 
of each of the free chunks. 

HTH 

Chris 


Quoting George Leonard : 

> Hi all, weird thing, the developers is executing pretty big queries
via 
> java. Sometimes on some of the queries they get this error, if they
take 
> the SQL and execute it via sqlplus immediate it works no errors. 
> 
> java.sql.SQLException: ORA-04031: unable to allocate 1553024 bytes of 
> shared memory ("shared pool","select (isoyear * 100) + 
> iso...","Typecheck heap","qry_text : qcpisqt") 
> 
> George 
> 
> ________________________________________________ 
> 
> George Leonard 
> Oracle Database Administrator 
> Dimension Data (Pty) Ltd 
> (Reg. No. 1987/006597/07) 
> Tel: (+27 11) 575 0573 
> Fax: (+27 11) 576 0573 
> E-mail:george.leonard@xxxxxxxxxxxxx 
> Web: http://www.didata.co.za 
> 
> You Have The Obligation to Inform One Honestly of the risk, And As a 
> Person 
> You Are Committed to Educate Yourself to the Total Risk In Any
Activity! 
> Once Informed & Totally Aware of the Risk, 
> Every Fool Has the Right to Kill or Injure Themselves as They See Fit!

> 
> 
> 
> 
> "This e-mail is sent on the Terms and Conditions that can be accessed
by 
> Clicking on this link http://www.vodacom.net/legal/email.asp " 
> 


Chris Dunscombe 

chris@xxxxxxxxxxxxxxxxxxxxx 

------------------------------------------------- 
Everyone should have http://www.freedom2surf.net/ 
----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to: oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
----------------------------------------------------------------- "This
e-mail is sent on the Terms and Conditions that can be accessed by Clicking
on this link http://www.vodacom.net/legal/email.asp " 
"This e-mail is sent on the Terms and Conditions that can be accessed by
Clicking on this link http://www.vodacom.net/legal/email.asp " 

___________________________________________________________________________ 


This email and any attached to it are confidential and intended only for the
individual or entity to which it is addressed.  If you are not the intended
recipient, please let us know by telephoning or emailing the sender.  You
should also delete the email and any attachment from your systems and should
not copy the email or any attachment or disclose their content to any other
person or entity.  The views expressed here are not necessarily those of
Churchill Insurance Group plc or its affiliates or subsidiaries. Thank you. 

Churchill Insurance Group plc.  Company Registration Number - 2280426.
England. 

Registered Office: Churchill Court, Westmoreland Road, Bromley, Kent BR1
1DP. 


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------


This e-mail, including attachments, may include confidential and/or
proprietary information, and may be used only by the person or entity to
which it is addressed. If the reader of this e-mail is not the intended
recipient or his or her authorized agent, the reader is hereby notified that
any dissemination, distribution or copying of this e-mail is prohibited. If
you have received this e-mail in error, please notify the sender by replying
to this message and delete this e-mail immediately.
----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

Other related posts: