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: Buffer Busy Waits -- Sanity check please

Re: Buffer Busy Waits -- Sanity check please

From: Stephane Faroult <sfaroult_at_oriole.com>
Date: Tue, 27 Nov 2001 02:53:51 -0800
Message-ID: <F001.003CD773.20011127023517@fatcity.com>

> Thomas Jeff wrote:
>
> We recently had a new website go live. Since then, I'm seeing
> constant buffer busy waits
> and after a period of time, I see sessions hung on the same block#.
> The SQL query
> is always a COUNT(*) (below). It's almost as though one session has
> a lock
> of some sort in the buffer cache and other sessions are blocked.
> Although, I've checked and
> there's no DML ongoing, so I'm unsure as to why we would see this.
> Note that v$session shows
> 78 and 393 to be INACTIVE, while 159 is ACTIVE. So it's like 159
> can't write to
> the buffer cache because 78 and 393 have a lock there. Note that
> these are all defined
> as persistent connections, via the Vignette front-end. I'm sure all
> the clues are there
> but my brain is too fuzzed to piece it together.
>
> SID SQL_TEXT
> O/S User
> ----- ----------------------------------------------------------------
> ---------------
> 159 SELECT COUNT(*) NUM,SUM(TOTAL_CHARGE_AMT) TOT FROM BBN.BBN_SRV
> vignette
> 159 _PAID_WARR_CLAIM WHERE CUSTOMER_ID = :b1 AND ENTERPRISE_CD = :
> vignette
> 159 b2 AND (CHECK_ID IS NOT NULL AND CHECK_ID != 'PENDING' )
> vignette
>
> SID EVENT P1TEXT P1 P2TEXT P2
> P3TEXT P3
> ----- -------------------------- ------------ -- ----------- ------
> ----- ------
> 78 buffer busy waits file# 72 block# 109177
> id 130
> 393 buffer busy waits file# 72 block# 109177
> id 130
> 159 db file scattered read file# 72 block# 109177
> blocks 8
>
> --------------------------------------------
> Jeffery D Thomas
> DBA
> Thomson Information Services
> Thomson multimedia Inc.
>
> Email: thomasje_at_tce.com
> DBA Quickplace: http://gkmqp.tce.com/tis_dba
> --------------------------------------------
>

SELECTs sometimes do some block house-keeping, and thus modify Oracle buffers even if they are not supposed to. I have also witnessed strange behaviours with IOTs. What do other queries do? Have you checked V$SQLAREA to know whether this query is executed very often or not? I guess that at least CUSTOMER_ID is indexed (BTW it would be interesting to know whether the busy block is a data or index block. Try this :

select owner, segment_name, partition_name, segment_type from dba_extents
where file_id = 72
 and block_id <= 109177
  and 109177 < block_id + blocks

If the block is a table block, you can fudge the issue by making Oracle only look into an index storing all referenced columns (which would probably also mean making CHECK_ID not null, side-effects on your code). If it's an index block, it's more delicate to handle.

If your query is executed very often, denormalizing might also be an idea. I am no great fan of denormalisation but a trigger to maintain a count and a sum would be comparable in overhead cost to an additional index.

-- 
HTH,

Stephane Faroult
Oriole Corporation
Voice:  +44  (0) 7050-696-269 
Fax:    +44  (0) 7050-696-449 
Performance Tools & Free Scripts
--------------------------------------------------------------
http://www.oriole.com, designed by Oracle DBAs for Oracle DBAs
--------------------------------------------------------------
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.com
-- 
Author: Stephane Faroult
  INET: sfaroult_at_oriole.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).
Received on Tue Nov 27 2001 - 04:53:51 CST

Original text of this message

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