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: Shared Pool Tuneup

RE: Shared Pool Tuneup

From: John Hallas <john.hallas_at_hcresources.co.uk>
Date: Tue, 21 May 2002 13:52:15 -0800
Message-ID: <F001.00466B93.20020521135215@fatcity.com>


Or you can use the method posted by Suzy Vordos on 20/4/02

If on 8i you could use a startup trigger for this. Here's mine:

create or replace trigger sys.pin_db_objects after startup on database
begin

    sys.dbms_shared_pool.keep('SYS.DBMSZEXP_SYSPKGGRNT');
    sys.dbms_shared_pool.keep('SYS.DBMS_ALERT');
    sys.dbms_shared_pool.keep('SYS.DBMS_APPLICATION_INFO');
    sys.dbms_shared_pool.keep('SYS.DBMS_AQADM_SYS');
    sys.dbms_shared_pool.keep('SYS.DBMS_AQ_EXP_QUEUES');
    sys.dbms_shared_pool.keep('SYS.DBMS_AQ_IMPORT_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_AQ_SYS_EXP_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_ASYNCRPC_PUSH');
    sys.dbms_shared_pool.keep('SYS.DBMS_DDL');
    sys.dbms_shared_pool.keep('SYS.DBMS_DDL_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFERGEN');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFERGEN_AUDIT');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFERGEN_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFERGEN_LOB');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFERGEN_UTIL');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER_IMPORT_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER_INTERNAL_SYS');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER_QUERY_UTL');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER_SYS');
    sys.dbms_shared_pool.keep('SYS.DBMS_DEFER_SYS_PART1');
    sys.dbms_shared_pool.keep('SYS.DBMS_DESCRIBE');
    sys.dbms_shared_pool.keep('SYS.DBMS_EXPORT_EXTENSION');
    sys.dbms_shared_pool.keep('SYS.DBMS_IJOB');
    sys.dbms_shared_pool.keep('SYS.DBMS_INTERNAL_TRIGGER');
    sys.dbms_shared_pool.keep('SYS.DBMS_JOB');
    sys.dbms_shared_pool.keep('SYS.DBMS_LOCK');
    sys.dbms_shared_pool.keep('SYS.DBMS_OUTPUT');
    sys.dbms_shared_pool.keep('SYS.DBMS_PRVTRMIE');
    sys.dbms_shared_pool.keep('SYS.DBMS_REFRESH_EXP_LWM');
    sys.dbms_shared_pool.keep('SYS.DBMS_REFRESH_EXP_SITES');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_ADMIN');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_CACHE');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_DECL');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_FLA_UTL');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_MAS');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_RGT_EXP');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_UTL');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_UTL2');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_UTL3');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_UTL4');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_RPC');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPCAT_RPC_UTL');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPUTIL');
    sys.dbms_shared_pool.keep('SYS.DBMS_REPUTIL2');
    sys.dbms_shared_pool.keep('SYS.DBMS_RMGR_GROUP_EXPORT');
    sys.dbms_shared_pool.keep('SYS.DBMS_RMGR_PACT_EXPORT');
    sys.dbms_shared_pool.keep('SYS.DBMS_RMGR_PLAN_EXPORT');
    sys.dbms_shared_pool.keep('SYS.DBMS_SESSION');
    sys.dbms_shared_pool.keep('SYS.DBMS_SNAP_INTERNAL');
    sys.dbms_shared_pool.keep('SYS.DBMS_SQL');
    sys.dbms_shared_pool.keep('SYS.DBMS_STANDARD');
    sys.dbms_shared_pool.keep('SYS.DBMS_SYSTEM');
    sys.dbms_shared_pool.keep('SYS.DBMS_SYS_SQL');
    sys.dbms_shared_pool.keep('SYS.DBMS_UTILITY');
    sys.dbms_shared_pool.keep('SYS.DBMS_ZHELP');
    sys.dbms_shared_pool.keep('SYS.DBMS_ZHELP_IR');
    sys.dbms_shared_pool.keep('SYS.STANDARD');
    sys.dbms_shared_pool.keep('SYS.UTL_RAW');
    sys.dbms_shared_pool.keep('PERFSTAT.STATSPACK');
end;
/

John

-----Original Message-----

Sent: 21 May 2002 21:44
To: Multiple recipients of list ORACLE-L

Hamid,

Madhu is right. But comination of execution and load will be more practical .Run following query and see number of executions...

select substr(c.owner,1,5)"OWNER",substr(c.name,1,25)"name",

       round(c.sharable_mem / 1024) K,
       c.loads,
       c.executions,
       c.kept
from v$db_object_cache c,
     sys.obj$ o,
     sys.user$ u

where kept = 'NO'
and u.name = c.owner
  and u.user# = o.owner#
  and o.name = c.name
-- and o.type in (7, 8, 9)

order by 4,2 desc
/

Once you decide to pin run following through a sql file at the time of startup script for database...(just an extract for your guidance)

EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.DBMS_APPLICATION_INFO');
EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.DBMS_DESCRIBE');
EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.DBMS_LOCK');
EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.DBMS_OUTPUT');
EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.DBMS_STANDARD');
EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.DBMS_UTILITY');
EXECUTE SYS.DBMS_SHARED_POOL.KEEP('SYS.STANDARD');
execute sys.dbms_shared_pool.keep('APPS.FND_DCP');
execute sys.dbms_shared_pool.keep('APPS.CSTPPWMX');
execute sys.dbms_shared_pool.keep('APPS.CSTPUTIL');
execute sys.dbms_shared_pool.keep('APPS.AP_APPROVAL_PKG');
execute sys.dbms_shared_pool.keep('SYS.PSTUBT');
exit;

HTH,
Regards
Rafiq

Reply-To: ORACLE-L_at_fatcity.com
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> Date: Tue, 21 May 2002 12:26:53 -0800

Hamid,
what happens , if an object is getting executed once in a while but takes huge sharable memory, we may not be getting full use of pinning it in the shared pool, except wasting the memory, So we need to consider the number of executions also. if the number of executions are high for any object/SQL, its good idea to keep it in shared pool.

--Madhu

-----Original Message-----

Sent: Tuesday, May 21, 2002 2:47 PM
To: Multiple recipients of list ORACLE-L

Hi List,
I have run some scripts for Tune up shared pool,here is the result of one script which i run :
Script:
SELECT name,sharable_mem
FROM v$db_object_cache
WHERE sharable_mem > 10000
AND (TYPE = 'PACKAGE' OR TYPE = 'PACKAGE BODY' OR TYPE = 'FUNCTION' OR
TYPE = 'PROCEDURE')
AND KEPT = 'NO'
ORDER BY 2 DESC here is the result:

NAME                            SHARABLE_MEM

----------------------------- --------------------------
DBMS_JAVA 56373 DBMS_STANDARD 24405 DBMS_UTILITY 24212 DBMS_SPACE_ADMIN 20832 DBMS_UTILITY 20508 DBMS_JAVA 15189 DBMS_OUTPUT 13063 DBMS_APPLICATION_INFO 12461 DBMS_SHARED_POOL 11148 DBMS_SHARED_POOL 10648

Question is, do i have to pin all of these objects in my shared_pool or NOT? Thanks

Hamid Alavi
Office 818 737-0526
Cell 818 402-1987

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Hamid Alavi

   INET: hamid.alavi_at_quovadx.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists

--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Reddy, Madhusudana

   INET: Madhusudana.Reddy_at_bestbuy.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists

--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).

MOHAMMAD RAFIQ



Send and receive Hotmail on your mobile device: http://mobile.msn.com

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: Mohammad Rafiq
  INET: rafiq9857_at_hotmail.com

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists

--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing).

--

Please see the official ORACLE-L FAQ: http://www.orafaq.com
--

Author: John Hallas
  INET: john.hallas_at_hcresources.co.uk

Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
San Diego, California        -- Public Internet access / Mailing Lists

--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in the message BODY, include a line containing: UNSUB ORACLE-L (or the name of mailing list you want to be removed from). You may also send the HELP command for other information (like subscribing). Received on Tue May 21 2002 - 16:52:15 CDT

Original text of this message

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