Oracle8(TM) Server Tuning Release 8.0 A54638-01 |
|
This chapter explains the use of shared SQL to improve performance. Topics in this chapter include
Oracle compares SQL statements and PL/SQL blocks issued directly by users and applications as well as recursive SQL statements issued internally by a DDL statement. If two identical statements are issued, the SQL or PL/SQL area used to process the first instance of the statement is shared, or used for the processing of the subsequent executions of that same statement.
Shared SQL and PL/SQL areas are shared memory areas; any Oracle process can use a shared SQL area. The use of shared SQL areas reduces memory usage on the database server, thereby increasing system throughput.
Shared SQL and PL/SQL areas are aged out of the shared pool by way of a least recently used algorithm (similar to database buffers). To improve performance and prevent reparsing, you may want to prevent large SQL or PL/SQL areas from aging out of the shared pool.
This section describes
Oracle automatically notices when two or more applications send identical SQL statements or PL/SQL blocks to the database. It does not have to parse a statement to determine whether it is identical to another statement currently in the shared pool. Oracle distinguishes identical statements using the following steps:
SELECT * FROM emp;
is not considered identical because the statement references different tables for each user.
Note: Most Oracle products convert the SQL before passing statements to the database. Characters are uniformly changed to upper case, white space is compressed, and bind variables are renamed so that a consistent set of SQL statements is produced.
It is neither necessary nor useful to have every user of an application attempt to use a standardized way of writing SQL statements. Three hundred people writing ad hoc dynamic statements in standardized SQL will not generate the same SQL statements. The chances that they will all want to look at exactly the same columns in exactly the same tables in exactly the same order may be quite remote. A standard for formatting SQL statements would make a difference only if all the foregoing were true. By contrast, 300 people running the same application--executing command files--will generate the same SQL statements.
Within an application there is a very minimal advantage to having 2 statements almost the same, and 300 users using them, versus having one statement used by 600 users.
This section describes two techniques of keeping shared SQL and PL/SQL in the shared pool:
A problem can occur if users fill the shared pool, and then a large package ages out. If someone should then call the large package back in, an enormous amount of maintenance must be done to create space for it in the shared pool. This problem can be avoided if you reserve space for large allocations by setting the SHARED_POOL_RESERVED_SIZE initialization parameter. This parameter sets aside room in the shared pool for allocations larger than the value specified by the SHARED_POOL_RESERVED_SIZE_MIN_ALLOC parameter.
Although Oracle8 uses segmented codes to reduce the need for large areas of contiguous memory, it may still be valuable for performance reasons for you to pin large objects in memory.
The DBMS_SHARED_POOL package allows objects to be kept in shared memory, so that they will not be aged out with the normal LRU mechanism. The DBMSPOOL.SQL and PRVTPOOL.PLB procedure scripts create the package specification and package body for DBMS_SHARED_POOL.
By using the DBMS_SHARED_POOL package and by loading these SQL and PL/SQL areas early (before memory fragmentation occurs), the objects can be kept in memory, instead of aging out with the normal LRU mechanism. This procedure ensures that memory is available and prevents sudden, seemingly inexplicable slowdowns in user response time that occur when SQL and
PL/SQL areas are accessed after aging out.
The procedures provided with the DBMS_SHARED_POOL package may be useful when loading large PL/SQL objects, such as the STANDARD and DIUTIL packages.
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.
Note in addition that 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.
To use the DBMS_SHARED_POOL package to pin a SQL or PL/SQL area, complete the following steps.
This procedure ensures that your system has not run out of the shared memory before the object is loaded. Finally, by pinning the object early in the life of the instance, this procedure prevents the memory fragmentation that could result from pinning a large chunk of memory in the middle of the shared pool.
The procedures provided with the DBMS_SHARED_POOL package are described below.
This procedure shows the objects in the shared pool that are larger than the specified size.
dbms_shared_pool.sizes(minsize IN NUMBER)
Input Parameter:
minsize
Display objects in shared pool larger than this size, where size is measured in kilobytes.
Output Parameters:
To display the results of this procedure, before calling this procedure issue the following command using Server Manager or SQL*Plus:
SET SERVEROUTPUT ON SIZE minsize
You can use the results of this command as arguments to the KEEP or UNKEEP procedures.
For example, to show the objects in the shared pool that are larger than 2000 you would issue the following Server Manager or SQL*Plus commands:
SQL> SET SERVEROUTPUT ON SIZE 2000 SQL> EXECUTE DBMS_SHARED_POOL.SIZES(2000);
This procedure lets you keep an object in the shared pool. This procedure may not be supported in future releases.
dbms_shared_pool.keep(object IN VARCHAR2,
[type IN CHAR DEFAULT P])
Input Parameters:
object
Either the parameter name or the cursor address of the object to be kept in the shared pool. This is the value displayed when you call the SIZES procedure.
type
The type of the object that you want kept in the shared pool. Types include:
P the object is a procedure
C the object is a cursor
R the object is a trigger
Q the object is a sequence
This procedure allows an object that you have requested to be kept in the shared pool to now be aged out of the shared pool.
Note: This procedure may not be supported in the future.
dbms_shared_pool.unkeep(object IN VARCHAR2,
[type IN CHAR DEFAULT P])
Input Parameters:
object
Either the parameter name or the cursor address of the object that you no longer want kept in the shared pool. This is the value displayed when you call the SIZES procedure.
type
Type of the object that you want aged out of the shared pool. Types include:
P the object is a procedure
C the object is a cursor
R the object is a trigger
Q the object is a sequence