 |
|
Oracle KEEP Pool
Oracle Tips by Burleson Consulting |
Automatically Generate KEEP Syntax
A DBA can easily write a script that automatically identifies
candidates for the KEEP pool and generates the syntax to move the
tables into the pool. The placement criteria for tables and indexes
into the KEEP buffer are straightforward:
§
The threshold for access can be
adjusted in the script.
§
Any table that has more than 80% of
its blocks in the data buffer should be cached in the KEEP pool.
The approach to identifying tables for the KEEP pool is simple. All
objects that have more than 80% of their data blocks in the buffer
should be assigned to the KEEP pool. The following section contains
scripts for each of these methods.
Automating the Assignment of KEEP Pool
Contents
Another method for identifying tables and indexes for the KEEP pool
involves the examination of the current blocks in the data buffer.
For the
buf_keep_pool.sql query, the rules are simple.
§
Use the KEEP pool if the object
consumes more than 10% of the total size of the data buffer.
§
Use the KEEP pool if more than 50% of the objects
blocks already resides in the data buffer, according to an x$bh
query.
It is highly unlikely that an undeserving table or index would meet
this criterion. Of course, this script would need to be run at
numerous times during the day because the buffer contents change
very rapidly.
The following script can be run every hour via
dbms_job
and
will automate the monitoring of KEEP pool candidates. Every time it
finds a candidate, the DBA will execute the syntax and adjust the
total KEEP pool size to accommodate the new object.
-- *************************************************
-- Copyright © 2005 by Rampant TechPress
-- This script is free for non-commercial purposes
-- with no warranties. Use at your own risk.
--
-- To license this script for a commercial purpose,
-- contact info@rampant.cc
-- *************************************************
set pages 999
set lines 92
spool keep_syn.lst
drop table t1;
create table t1 as
select
o.owner owner,
o.object_name object_name,
o.subobject_name subobject_name,
o.object_type object_type,
count(distinct file# || block#) num_blocks
from
dba_objects o,
v$bh bh
where
o.data_object_id = bh.objd
and
o.owner not in ('SYS','SYSTEM')
and
bh.status != 'free'
group by
o.owner,
o.object_name,
o.subobject_name,
o.object_type
order by
count(distinct file# || block#) desc
;
select
'alter '||s.segment_type||' '||t1.owner||'.'||s.segment_name||'
storage (buffer_pool keep);'
from
t1,
dba_segments s
where
s.segment_name = t1.object_name
and
s.owner = t1.owner
and
s.segment_type = t1.object_type
and
nvl(s.partition_name,'-') = nvl(t1.subobject_name,'-')
and
buffer_pool <> 'KEEP'
and
object_type in ('TABLE','INDEX')
group by
s.segment_type,
t1.owner,
s.segment_name
having
(sum(num_blocks)/greatest(sum(blocks), .001))*100 > 80
;
spool off;
The following is sample of the output from this script.
alter TABLE
BOM.BOM_DELETE_SUB_ENTITIES storage (buffer_pool keep);
alter TABLE
BOM.BOM_OPERATIONAL_ROUTINGS storage (buffer_pool keep);
alter INDEX BOM.CST_ITEM_COSTS_U1
storage (buffer_pool keep);
alter TABLE
APPLSYS.FND_CONCURRENT_PROGRAMS storage (buffer_pool keep);
alter TABLE
APPLSYS.FND_CONCURRENT_REQUESTS storage (buffer_pool keep);
alter TABLE GL.GL_JE_BATCHES storage
(buffer_pool keep);
alter INDEX GL.GL_JE_BATCHES_U2
storage (buffer_pool keep);
alter TABLE GL.GL_JE_HEADERS storage
(buffer_pool keep);
alter TABLE INV.MTL_DEMAND_INTERFACE
storage (buffer_pool keep);
alter INDEX
INV.MTL_DEMAND_INTERFACE_N10 storage (buffer_pool keep);
alter TABLE INV.MTL_ITEM_CATEGORIES
storage (buffer_pool keep);
alter TABLE INV.MTL_ONHAND_QUANTITIES
storage (buffer_pool keep);
alter TABLE
INV.MTL_SUPPLY_DEMAND_TEMP storage (buffer_pool keep);
alter TABLE
PO.PO_REQUISITION_LINES_ALL storage (buffer_pool keep);
alter TABLE AR.RA_CUSTOMER_TRX_ALL
storage (buffer_pool keep);
alter TABLE
AR.RA_CUSTOMER_TRX_LINES_ALL storage (buffer_pool keep);
alter INDEX
WIP.WIP_REQUIREMENT_OPERATIONS_N3 storage (buffer_pool keep);
In sum, there are two ways to identify tables and indexes for full
caching in the KEEP pool. The first step is to explain all of the
SQL in the databases that are looking for small-table, full-table
scans. Next, the data buffer cache should be examined repeatedly in
order to identify any objects that have more than 80% of their
blocks in RAM. The next section covers how the job is finished and
how the KEEP pool can be resized to accommodate the new objects.
SEE CODE DEPOT FOR FULL SCRIPTS
 |
This is an excerpt from my latest book "Oracle
Tuning: The Definitive Reference".
You can buy it direct from the publisher for 50%-off and get
instant access to the code depot of Oracle tuning scripts: |
http://www.rampant-books.com/book_1002_oracle_tuning_definitive_reference_2nd_ed.htm
 |
Expert Remote DBA
BC is America's oldest and largest Remote DBA Oracle support
provider. Get real Remote DBA experts, call
BC Remote DBA today. |
 |
|