Friday, April 18, 2008

V$BH

The v$bh view of x$bh.

This view gives the status and number of pings for every buffer in the SGA, We can use v$bh to display the data buffer contents.


Column Datatype Description
FILE# NUMBER Datafile identifier number (to find the filename, query DBA_DATA_FILES or V$DBFILE)
BLOCK# NUMBER Block number
CLASS# NUMBER Class number
STATUS VARCHAR2(6) Status of the buffer:
  • free - Not currently in use

  • xcur - Exclusive

  • scur - Shared current

  • cr - Consistent read

  • read - Being read from disk

  • mrec - In media recovery mode

  • irec - In instance recovery mode

XNC NUMBER Number of PCM x to null lock conversions due to contention with another instance. This column is obsolete and maintained for backward compatibility.
LOCK_ELEMENT_ADDR RAW(4 | 8) Address of the lock element that contains the PCM lock that is covering the buffer. If more than one buffer has the same address, then these buffers are covered by the same PCM lock.
LOCK_ELEMENT_NAME NUMBER The address of the lock element that contains the PCM lock that is covering the buffer. If more than one buffer has the same address, then these buffers are covered by the same PCM lock.
LOCK_ELEMENT_CLASS NUMBER The address of the lock element that contains the PCM lock that is covering the buffer. If more than one buffer has the same address, then these buffers are covered by the same PCM lock.
FORCED_READS NUMBER Number of times the block had to be reread from the cache because another instance has forced it out of this instance's cache by requesting the lock on the block in exclusive mode
FORCED_WRITES NUMBER Number of times GCS had to write this block to cache because this instance had used the block and another instance had requested the lock on the block in a conflicting mode
DIRTY VARCHAR2(1) Y - block modified
TEMP VARCHAR2(1) Y - temporary block
PING VARCHAR2(1) Y - block pinged
STALE VARCHAR2(1) Y - block is stale
DIRECT VARCHAR2(1) Y - direct block
NEW VARCHAR2(1) Always set to N. This column is obsolete and maintained for backward compatibility.
OBJD NUMBER Database object number of the block that the buffer represents
TS# NUMBER Tablespace number of block

Show free block in Data Buffer:

SQL> COLUMN STATUS FORMAT A5
SQL> select status , count(1) AS COUNT from v$bh group by status order by count desc;

STATU COUNT
----- ----------
free 19722
xcur 16452
cr 1183


SQL> ALTER SYSTEM FLUSH BUFFER_CACHE;

System altered.

SQL> COLUMN STATUS FORMAT A5
SQL> select status , count(1) AS COUNT from v$bh group by status order by count desc;

STATU COUNT
----- ----------
free 37338
xcur 19

Example: show Buffer Blocks of Objects:

SQL> column owner format a20
SQL> column object_type format a20
SQL> column object_name format a30
SQL> select o.owner, o.object_type, o.object_name, b.status , count(b.objd) from v$bh b , dba_objects o where b.objd = o.object_id and o.owner = 'SCOTT' group by o.owner, o.object_type, o.object_name, b.status;

OWNER OBJECT_TYPE OBJECT_NAME STATUS COUNT(B.OBJD)
-------------------- -------------------- ------------------------------ ---------- -------------
SCOTT TABLE DEPT free 7
SCOTT TABLE TEMP free 3

SQL> select * from scott.dept;

DEPTNO DNAME LOC
---------- -------------- -------------
10 ACCOUNTING NEW YORK
20 RESEARCH DALLAS
30 SALES CHICAGO
40 OPERATIONS BOSTON
99 Test Dept UK

>>> After that we find "SCOTT.DEPT" object in V$BH (xcur status):

SQL> column status format a10
SQL> column owner format a20
SQL> column object_type format a20
SQL> column object_name format a30
SQL> select o.owner, o.object_type, o.object_name, b.status , count(b.objd) from v$bh b , dba_objects o where b.objd = o.object_id and o.owner = 'SCOTT' group by o.owner, o.object_type, o.object_name, b.status;

OWNER OBJECT_TYPE OBJECT_NAME STATUS COUNT(B.OBJD)
-------------------- -------------------- ------------------------------ ---------- -------------
SCOTT TABLE DEPT xcur 6
SCOTT TABLE DEPT free 9
SCOTT TABLE TEMP free 3

>>> V$BH has the all-important “status” column.

>>> FORCED_READS and FORCED_WRITES represent the number of disk i/o's an instance had to perform on each block in the cache due to conflicting lock requests by other instances. These i/o's are wasteful since they occur only due to lock activity and thus they need to be avoided.


Enjoy!

No comments: