I'm spending some time today experimenting with buffer pools in 8.1.7. I have two
tables that I have assigned to the RECYCLE pool. I have been running various queries
that perform full table scans, then checking the buffers to see what gets aged out.
During my testing, it seems like the first blocks to get into the RECYCLE buffer pool
will stay there. The following two tables are assigned to the RECYCLE pool. No
other segments are assigned to it:
WORK_ORDER_STEP - 428 blocks of data
ALRA_TRANSACTION_HISTORY - 14152 blocks of data
The RECYCLE pool has 1000 blocks.
I startup the database, query the WORK_ORDER_STEP table (1 time), then run multiple
queries against the ALRA_TRANSACTION_HISTORY table (6 times), I see the following in
the buffers (the source for this query is at the end of my email):
BP_NAME OBJ_OWNER NAME BLOCKS
MAX_TOUCH MIN_TOUCH AVG_TOUCH
-------------------- --------------- ------------------------------ ----------
--------- --------- ---------
RECYCLE BIS ALRA_TRANSACTION_HISTORY 569
14 0 .02
RECYCLE WRKORD WORK_ORDER_STEP 431
1 0 .00
If I startup the database, query the ALRA_TRANSACTION_HISTORY table (1 time), then run
multiple queries against the WORK_ORDER_STEP table (6 queries), I get these results:
First query - 1000 blocks are used as expected
BP_NAME OBJ_OWNER NAME BLOCKS
MAX_TOUCH MIN_TOUCH AVG_TOUCH
-------------------- --------------- ------------------------------ ----------
--------- --------- ---------
RECYCLE BIS ALRA_TRANSACTION_HISTORY 1000
2 0 .00
After querying the second table multiple times, I expected more than just 9 blocks to
be given up. I expected more like 431 blocks.
BP_NAME OBJ_OWNER NAME BLOCKS
MAX_TOUCH MIN_TOUCH AVG_TOUCH
-------------------- --------------- ------------------------------ ----------
--------- --------- ---------
RECYCLE BIS ALRA_TRANSACTION_HISTORY 991
2 0 .00
RECYCLE WRKORD WORK_ORDER_STEP 9
4 0 .44
I expected the blocks (from the table that was queried first) to be aged out as I
queried the second table (over and over). This does not occur. Am I hitting a bug or
just misunderstanding the buffer management algorithms? ALRA_TRANSACTION_HISTORY
blocks should be LRU as I hit the WORK_ORDER_STEP table over and over.
Thanks,
Jay
Here is the query that I use to check what is in the buffer pools:
select bpd.bp_name,
u.name obj_owner,
o.name,
count(*) BLOCKS,
max(tch) max_touch,
min(tch) min_touch,
avg(tch) avg_touch
from x$kcbwds wds, /* working data sets */
x$kcbwbpd bpd, /* buffer pools */
x$bh bh, /* buffer headers */
obj$ o, /* objects */
user$ u
where wds.set_id >= bpd.bp_lo_sid
and wds.set_id <= bpd.bp_hi_sid
and bpd.bp_size != 0
and bh.indx between wds.start_buf# and wds.end_buf#
and o.dataobj# = bh.obj
and bh.state !=0
and o.owner# !=0 /* exclude sys */
and o.owner# = u.user#
group by bpd.bp_name, u.name, o.name
order by bpd.bp_name, u.name, o.name
;
**DISCLAIMER
This e-mail message and any files transmitted with it are intended for the use of the
individual or entity to which they are addressed and may contain information that is
privileged, proprietary and confidential. If you are not the intended recipient, you
may not use, copy or disclose to anyone the message or any information contained in
the message. If you have received this communication in error, please notify the
sender and delete this e-mail message. The contents do not represent the opinion of
D&E except to the extent that it relates to their official business.
--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Jay Hostetter
INET: [EMAIL PROTECTED]
Fat City Network Services -- 858-538-5051 http://www.fatcity.com
San Diego, California -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (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).