RE: write consistency/read consistency

  • From: <Ogun.Heper@xxxxxxxxxxxxxxx>
  • To: <henry@xxxxxxxxxxxxxxx>, <oracle-l@xxxxxxxxxxxxx>
  • Date: Tue, 27 Jun 2006 11:03:22 +0300

Hi,

 

If a block of code should be atomic, i.e. it has to be run by only one 
concurrent session in order not to break your data consistency, you can wrap it 
in a user-defined lock block using DBMS_LOCK package as seen below;

 

dbms_lock.allocate_unique('my_lock', v_lock_handle) ;
if dbms_lock.request(v_lock_handle, release_on_commit => true) != 0 then
   rollback ;
   raise e_cant_acquire_lock ;

end if ;
// Your code here

commit ;

 

Best regards.

OgÃn Heper

 

________________________________

From: oracle-l-bounce@xxxxxxxxxxxxx [mailto:oracle-l-bounce@xxxxxxxxxxxxx] On 
Behalf Of Henry Poras
Sent: Monday, June 26, 2006 8:02 PM
To: oracle-l@xxxxxxxxxxxxx
Subject: write consistency/read consistency

 

`I am trying to do an UPDATE in table_a based on the result of a query on 
table_b. For example, update my order (in table_a) if there is inventory in 
stock (in table_b). We can always do this using something along the lines of:

UPDATE table_a 
SET number_ordered = number_ordered+1 
WHERE EXISTS ( 
  SELECT 'x' 
  FROM table_a, table_b 
  WHERE <condition to check table_b for inventory for my order> 
                         ) 

This looks like it should be nice and consistent. Everything in one SQL 
statement. But as has been pointed out to me, it isn't. 

Follow this timeline: 
Session A blocks a record in table_a 
Session B starts the update (time 1). It is blocked by session A 
Session C updates table_b, changing the result of my nested query (time 2) 
Session A commits/rollback (doesn't matter) 
Session B finishes the update using the query result from time 1 which is no 
longer valid (the inventory is actually gone)

This is a bit different from the 'write consisntency' case discussed by Tom 
Kyte 
http://tkyte.blogspot.com/2005/08/something-different-part-i-of-iii.html 
<http://tkyte.blogspot.com/2005/08/something-different-part-i-of-iii.html>  

In his example, the data changed by session C is in table_a, the table being 
updated. In this case, the SELECT is read consistent to the point in time when 
the query began. The update then does a current read on the returned records 
prior to doing the update. If anything has changed, the statement rolls back 
and begins again from a new point in time. In Tom's example, data in table_a 
has changed. In my example, it hasn't.

Here, the query returns a result set based on table_a and table_b. However, 
when table_b is modified, which would change the result set, this is never 
noticed as the query is not rerun. The curent reads of the table_a remain 
unchanged, and so the update completes when the lock is removed. 

Is the only way to do this to break the statement up into multiple pieces and 
use SELECT FOR UPDATE? 

Henry 



************************************************************************
Bu elektronik posta ve onunla iletilen bÃtÃn dosyalar sadece gÃndericisi 
tarafindan almasi amaclanan yetkili gercek ya da tÃzel kisinin kullanimi 
icindir.  Eger sÃz konusu yetkili alici degilseniz bu elektronik postanin 
icerigini aciklamaniz, kopyalamaniz, yÃnlendirmeniz ve kullanmaniz kesinlikle 
yasaktir ve bu elektronik postayi derhal silmeniz gerekmektedir.
TURKCELL bu mesajin icerdigi bilgilerin doÄruluÄu veya eksiksiz oldugu 
konusunda herhangi bir garanti vermemektedir.  Bu nedenle bu bilgilerin ne 
sekilde olursa olsun iceriginden, iletilmesinden, alinmasindan ve 
saklanmasindan sorumlu degildir. Bu mesajdaki gÃrÃsler yalnizca gÃnderen 
kisiye aittir ve TURKCELLin gÃrÃslerini yansitmayabilir
Bu e-posta bilinen bÃtÃn bilgisayar virÃslerine karsi taranmistir.
************************************************************************
This e-mail and any files transmitted with it are confidential and intended 
solely for the use of the individual or entity to whom they are addressed. If 
you are not the intended recipient you are hereby notified that any 
dissemination, forwarding, copying or use of any of the information is strictly 
prohibited, and the e-mail should immediately be deleted.
TURKCELL makes no warranty as to the accuracy or completeness of any 
information contained in this message and hereby excludes any liability of any 
kind for the information contained therein or for the information transmission, 
reception, storage or use of such in any way whatsoever.  The opinions 
expressed in this message belong to sender alone and may not necessarily 
reflect the opinions of TURKCELL.
This e-mail has been scanned for all known computer viruses.
************************************************************************

Other related posts: