Thursday, December 17, 2009

How to Calculate Your Shared Pool Size


Subject:
How to Calculate Your Shared Pool Size

Note:1012046.6
Type:
PROBLEM

Last Revision Date:
11-APR-2006
Status:
REVIEWED
 
Problem Description: 
==================== 
 
One very difficult judgement that needs to be made in Oracle7 is to determine  
the proper size of the shared pool.  The following provides some guidelines  
for this.  It should be emphasized that these are just guidelines, there are  
no hard and fast rules here and experimentation will be needed to determine  
a good value.   
 
The shared pool size is highly application dependent. To determine the shared 
pool size that will be needed for a production system, it is generally 
necessary to first develop the application and run it on a test system and 
take some measurements.  The test system should be run with a very large value 
for the shared pool size to make the measurements meaningful.  
 
 
NON MULTI-THREADED SERVER ENVIRONMENT 
------------------------------------ 
 
A) OBJECTS STORED IN THE DATABASE  
   
The amount of shared pool that needs to be allocated for objects that are  
stored in the database like packages and views is easy to measure.  You can  
just measure their size directly with the following statement:  
   
  select sum(sharable_mem) from v$db_object_cache;  
   
This is especially effective because all large pl/sql object should be 'kept'  
in the shared pool at all times.  
   
B) SQL  
   
The amount of memory needed to store sql statements in the shared pool is  
more difficult to measure because of the needs of dynamic sql.  If an  
application has no dynamic sql then the amount of memory can simply  
be measured after the application has run for a while by just selecting  
it out of the shared pool as follows:  
   
  select sum(sharable_mem) from v$sqlarea;  
   
If the application has a  moderate or large amount of dynamic sql, like  
most applications do, then a certain amount of memory will be needed for  
the shared sql, the dynamic sql and extra memory so the dynamic sql does not 
age the shared sql out of the shared  pool.  
   
The amount of memory for the shared sql can be approximated by the following:  
   
  select sum(sharable_mem) from v$sqlarea where executions > 5;  
  (5 just an example that may not fit the criteria of your database) 
 
The remaining memory in v$sqlarea is for dynamic sql.  Some shared pool will  
need to be budgeted for this also, but there are few rules here.  
 
C) PER-USER PER-CURSOR MEMORY  
   
You will need to allow around 250 bytes of memory in the shared pool per  
concurrent user for each open cursor that the user has whether the cursor  
is shared or not.  During the peak usage time of the production system, you  
can measure this as follows:  
   
  select sum(250 * users_opening) from v$sqlarea;  
   
In a test system you can measure it by selecting the number of open cursors  
for a test user and multiplying by the total number of users:  
   
  select 250 * value bytes_per_user  
    from v$sesstat s, v$statname n  
   where s.statistic# = n.statistic#  
    and  n.name = 'opened cursors current'  
    and  s.sid  =  23;    -- replace 23 with session id of user being measured  
   
The per-user per-cursor memory is one of the classes of memory that shows  
up as 'library cache' in v$sgastat.  
 
D) OVERHEAD  
   
You will need to add a minimum of 20-30% overhead to the values calculated  
above to allow for unexpected and unmeasured usage of the shared  
pool other than object memory, shared sql or cursor memory. If the system is 
making heavy use of dynamic SQL 20% may not be enough, since this will come 
out of the runtime heap in the shared pool.  
 
 
MULTI-THREADED SERVER ENVIRONMENT 
--------------------------------- 
   
A)If you are using multi-threaded server, then you will need to allow enough  
memory for all the shared server users to put their session memory in the  
shared pool.  This can be measured for one user with the following query:  
   
  select value sess_mem  
    from v$sesstat s, v$statname n  
   where s.statistic# = n.statistic#  
    and  n.name = 'session uga memory'  
    and  s.sid  =  23;    -- replace 23 with session id of user being measured  
 
A more conservative value to use is the maximum session memory that was  
ever allocated by the user:  
   
  select value sess_max_mem  
    from v$sesstat s, v$statname n  
   where s.statistic# = n.statistic#  
    and  n.name = 'session uga memory max'  
    and  s.sid  =  23;    -- replace 23 with session id of user being measured  
   
To select this value for all the currently logged on users the following query  
can be used:  
  select sum(value) all_sess_mem  
    from v$sesstat s, v$statname n  
   where s.statistic# = n.statistic#  
    and  n.name = 'session uga memory max';  
   
B) OVERHEAD  
 
If the system is making heavy use of dynamic SQL this 20% may not be 
enough, since this will come out of the runtime heap in the shared pool.  
You will need to add a minimum of 20-30% overhead to the values calculated  
above to allow for unexpected and unmeasured usage of the shared  
pool other than object memory, shared sql or cursor memory. If the system is  
making heavy use of dynamic SQL 20% may not be enough, since this will come  
out of the runtime heap in the shared pool.  
 
 
Problem Explanation: 
==================== 
 
Support has created a script form of the information above. 
 
Solution Description: 
===================== 
 
Here is the script that should give a good indication of shared pool 
utilization if it is run during peak periods. 
 
 
set echo off 
spool pool_est 
/* 
********************************************************* 
*                                                       * 
* TITLE        : Shared Pool Estimation                 * 
* CATEGORY     : Information, Utility                   * 
* SUBJECT AREA : Shared Pool                            * 
* DESCRIPTION  : Estimates shared pool utilization      * 
*  based on current database usage. This should be      * 
*  run during peak operation, after all stored          * 
*  objects i.e. packages, views have been loaded.       * 
* NOTE:  Modified to work with later versions 4/11/06   * 
*                                                       * 
********************************************************/ 
Rem If running MTS uncomment the mts calculation and output 
Rem commands. 
 
set serveroutput on; 
 
declare 
        object_mem number; 
        shared_sql number; 
        cursor_mem number; 
        mts_mem number; 
        used_pool_size number; 
        free_mem number; 
        pool_size varchar2(512); -- same as V$PARAMETER.VALUE 
begin 
 
-- Stored objects (packages, views) 
select sum(sharable_mem) into object_mem from v$db_object_cache; 
 
-- Shared SQL -- need to have additional memory if dynamic SQL used 
select sum(sharable_mem) into shared_sql from v$sqlarea; 
 
-- User Cursor Usage -- run this during peak usage. 
--  assumes 250 bytes per open cursor, for each concurrent user. 
select sum(250*users_opening) into cursor_mem from v$sqlarea; 
 
-- For a test system -- get usage for one user, multiply by # users 
-- select (250 * value) bytes_per_user 
-- from v$sesstat s, v$statname n 
-- where s.statistic# = n.statistic# 
-- and n.name = 'opened cursors current' 
-- and s.sid = 25;  -- where 25 is the sid of the process 
 
-- MTS memory needed to hold session information for shared server users 
-- This query computes a total for all currently logged on users (run 
--  during peak period). Alternatively calculate for a single user and 
--  multiply by # users. 
select sum(value) into mts_mem from v$sesstat s, v$statname n 
       where s.statistic#=n.statistic# 
       and n.name='session uga memory max'; 
 
-- Free (unused) memory in the SGA: gives an indication of how much memory 
-- is being wasted out of the total allocated. 
-- For pre-9i issue
-- select bytes into free_mem from v$sgastat 
--        where name = 'free memory';
 
-- with 9i and newer releases issue
select bytes into free_mem from v$sgastat 
        where name = 'free memory'
        and pool = 'shared pool';
 
 
-- For non-MTS add up object, shared sql, cursors and 20% overhead. 
used_pool_size := round(1.2*(object_mem+shared_sql+cursor_mem)); 
 
-- For MTS mts contribution needs to be included (comment out previous line) 
-- used_pool_size := round(1.2*(object_mem+shared_sql+cursor_mem+mts_mem)); 
 
-- Pre-9i or if using manual SGA management, issue 
-- select value into pool_size from v$parameter where name='shared_pool_size'; 
 
-- With 9i and 10g and and automatic SGA management, issue
select  c.ksppstvl into pool_size from x$ksppi a, x$ksppcv b, x$ksppsv c
     where a.indx = b.indx and a.indx = c.indx
       and a.ksppinm = '__shared_pool_size';
 
-- Display results 
dbms_output.put_line ('Obj mem:  '||to_char (object_mem) || ' bytes'); 
dbms_output.put_line ('Shared sql:  '||to_char (shared_sql) || ' bytes'); 
dbms_output.put_line ('Cursors:  '||to_char (cursor_mem) || ' bytes'); 
-- dbms_output.put_line ('MTS session: '||to_char (mts_mem) || ' bytes'); 
dbms_output.put_line ('Free memory: '||to_char (free_mem) || ' bytes ' || '(' 
|| to_char(round(free_mem/1024/1024,2)) || 'MB)'); 
dbms_output.put_line ('Shared pool utilization (total):  '|| 
to_char(used_pool_size) || ' bytes ' || '(' || 
to_char(round(used_pool_size/1024/1024,2)) || 'MB)'); 
dbms_output.put_line ('Shared pool allocation (actual):  '|| pool_size ||' 
bytes ' || '(' || to_char(round(pool_size/1024/1024,2)) || 'MB)'); 
dbms_output.put_line ('Percentage Utilized:  '||to_char 
(round(used_pool_size/pool_size*100)) || '%'); 
end; 
/ 
 
spool off

1 comment:

  1. I have been checking out a few of your stories and i can state pretty good stuff. I will definitely bookmark your blog https://onohosting.com/

    ReplyDelete