118 DBMS_SHARED_POOL

The DBMS_SHARED_POOL package provides access to the shared pool, which is the shared memory area where cursors and PL/SQL objects are stored. DBMS_SHARED_POOL enables you to display the sizes of objects in the shared pool, and mark them for keeping or unkeeping in order to reduce memory fragmentation.

This chapter contains the following topics:


Using DBMS_SHARED_POOL


Overview

The procedures provided here may be useful when loading large PL/SQL objects. When large PL/SQL objects are loaded, users response time is affected because of the large number of smaller objects that need to be aged out from the shared pool to make room (due to memory fragmentation). In some cases, there may be insufficient memory to load the large objects.

DBMS_SHARED_POOL is also useful for frequently executed triggers. You may want to keep compiled triggers on frequently used tables in the shared pool.

Additionally, DBMS_SHARED_POOL supports sequences. Sequence numbers are lost when a sequence is aged out of the shared pool. DBMS_SHARED_POOL is useful for keeping sequences in the shared pool and thus preventing the loss of sequence numbers.


Operational Notes

To create DBMS_SHARED_POOL, run the DBMSPOOL.SQL script. The PRVTPOOL.PLB script is automatically executed after DBMSPOOL.SQL runs. These scripts are not run by as part of standard database creation.


Summary of DBMS_SHARED_POOL Subprograms

Table 118-1 DBMS_SHARED_POOL Package Subprograms

Subprogram Description

ABORTED_REQUEST_THRESHOLD Procedure

Sets the aborted request threshold for the shared pool

KEEP Procedure

Keeps an object in the shared pool

PURGE Procedure

Purges the named object or specified heap(s) of the object

SIZES Procedure

Shows objects in the shared pool that are larger than the specified size

UNKEEP Procedure

Unkeeps the named object



ABORTED_REQUEST_THRESHOLD Procedure

This procedure sets the aborted request threshold for the shared pool.

Syntax

DBMS_SHARED_POOL.ABORTED_REQUEST_THRESHOLD (
   threshold_size NUMBER);

Parameters

Table 118-2 ABORTED_REQUEST_THRESHOLD Procedure Parameters

Parameter Description

threshold_size

Size, in bytes, of a request which does not try to free unpinned (not "unkeep-ed") memory within the shared pool. The range of threshold_size is 5000 to ~2 GB inclusive.


Exceptions

An exception is raised if the threshold is not in the valid range.

Usage Notes

Usually, if a request cannot be satisfied on the free list, then the RDBMS tries to reclaim memory by freeing objects from the LRU list and checking periodically to see if the request can be fulfilled. After finishing this step, the RDBMS has performed a near equivalent of an 'ALTER SYSTEM FLUSH SHARED_POOL'.

Because this impacts all users on the system, this procedure "localizes" the impact to the process failing to find a piece of shared pool memory of size greater than thresh_hold size. This user gets the 'out of memory' error without attempting to search the LRU list.


KEEP Procedure

This procedure keeps an object in the shared pool. Once an object has been kept in the shared pool, it is not subject to aging out of the pool. This may be useful for frequently used large objects. When large objects are brought into the shared pool, several objects may need to be aged out to create a contiguous area large enough.

Syntax

DBMS_SHARED_POOL.KEEP (
   name VARCHAR2, 
   flag CHAR      DEFAULT 'P');

Parameters

Table 118-3 KEEP Procedure Parameters

Parameter Description

name

Name of the object to keep.

The value for this identifier is the concatenation of the address and hash_value columns from the v$sqlarea view. This is displayed by the SIZES procedure.

Currently, TABLE and VIEW objects may not be kept.

flag

(Optional) If this is not specified, then the package assumes that the first parameter is the name of a package/procedure/function and resolves the name.

Set to 'P' or 'p' to fully specify that the input is the name of a package/procedure/function.

Set to 'T' or 't' to specify that the input is the name of a type.

Set to 'R' or 'r' to specify that the input is the name of a trigger.

Set to 'Q' or 'q' to specify that the input is the name of a sequence.

In case the first argument is a cursor address and hash-value, the parameter should be set to any character except 'P' or 'p' or 'Q' or 'q' or 'R' or 'r' or 'T' or 't'.


Exceptions

An exception is raised if the named object cannot be found.

Usage Notes

There are two kinds of objects:

  • PL/SQL objects, triggers, sequences, and types which are specified by name

  • SQL cursor objects which are specified by a two-part number (indicating a location in the shared pool).

For example:

DBMS_SHARED_POOL.KEEP('scott.hispackage') 

This keeps package HISPACKAGE, owned by SCOTT. The names for PL/SQL objects follow SQL rules for naming objects (for example, delimited identifiers and multibyte names are allowed). A cursor can be kept by DBMS_SHARED_POOL.KEEP('0034CDFF, 20348871'). The complete hexadecimal address must be in the first 8 characters.


PURGE Procedure

This procedure purges the named object or specified heap(s) of the object.

Syntax

DBMS_SHARED_POOL.PURGE (
   name    VARCHAR2, 
   flag    CHAR DEFAULT 'P', 
   heaps   NUMBER DEFAULT 1)

Parameters

Table 118-4 PURGE Procedure Parameters

Parameter Description

name

Name of the object to purge.

The value for this identifier is the concatenation of the address and hash_value columns from the v$sqlarea view. This is displayed by the SIZES procedure.

Currently, TABLE and VIEW objects may not be purged.

flag

(Optional) If this is not specified, then the package assumes that the first parameter is the name of a package/procedure/function and resolves the name.

Set to 'P' or 'p' to fully specify that the input is the name of a package/procedure/function.

Set to 'T' or 't' to specify that the input is the name of a type.

Set to 'R' or 'r' to specify that the input is the name of a trigger.

Set to 'Q' or 'q' to specify that the input is the name of a sequence.

In case the first argument is a cursor address and hash-value, the parameter should be set to any character except 'P' or 'p' or 'Q' or 'q' or 'R' or 'r' or 'T' or 't'.

heaps

Heaps to be purged. For example, if heap 0 and heap 6 are to be purged:

1<<0 | 1<<6 => hex 0x41 => decimal 65, so specify heaps =>65.Default is 1, that is, heap 0 which means the whole object would be purged


Exceptions

ORA-6570: An exception is raised if the named object cannot be found

ORA-6570: An object cannot be purged it marked as permanently kept

Usage Notes

All objects supported by the KEEP Procedure are supported for PURGE.


SIZES Procedure

This procedure shows objects in the shared_pool that are larger than the specified size. The name of the object is also given, which can be used as an argument to either the KEEP or UNKEEP calls.

Syntax

DBMS_SHARED_POOL.SIZES ( 
   minsize NUMBER);

Parameters

Table 118-5 SIZES Procedure Parameters

Parameter Description

minsize

Size, in kilobytes, over which an object must be occupying in the shared pool, in order for it to be displayed.


Usage Notes

Issue the SQLDBA or SQLPLUS 'SET SERVEROUTPUT ON SIZE XXXXX' command prior to using this procedure so that the results are displayed.


UNKEEP Procedure

This procedure unkeeps the named object.

Syntax

DBMS_SHARED_POOL.UNKEEP (
   name VARCHAR2, 
   flag CHAR     DEFAULT 'P');

Caution:

This procedure may not be supported in the future if automatic mechanisms are implemented to make this unnecessary.

Parameters

Table 118-6 UNKEEP Procedure Parameters

Parameter Description

name

Name of the object to unkeep. See description of the name object for the KEEP procedure.

flag

See description of the flag parameter for the KEEP procedure.


Exceptions

An exception is raised if the named object cannot be found.