RE: write consistency/read consistency

  • From: "Yasin Baskan" <yasbs@xxxxxxxxxxxxxx>
  • To: <henry@xxxxxxxxxxxxxxx>, <oracle-l@xxxxxxxxxxxxx>
  • Date: Tue, 27 Jun 2006 11:54:27 +0300


I think there is a problem with this query. I do not know your where
clause for the inner query, but it can update all table_a if it is like
this:



Create table table_a(id number,number_ordered number);

insert into table_a select object_id,object_id from all_objects;



Create table table_b(id number);

insert into table_b select object_id from all_objects where rownum<100;



Update table_a

Set number_ordered=number_ordered+1

Where exists (select 'x' from table_a,table_b

                  Where table_a.id=table_b.id);



This updates all of the rows of table_a because the inner query always
returns a row.



Update table_a

Set number_ordered=number_ordered+1

Where exists (select 'x' from table_b

                  Where table_a.id=table_b.id)



This updates only the matching rows.

________________________________

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.htm
l> 

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 mesaj ve onunla iletilen tum ekler gonderildigi kisi ya da kuruma ozel ve 
Bankalar Kanunu geregince, gizlilik yukumlulugu tasiyor olabilir. Bu mesaj, 
hicbir sekilde, herhangi bir amac icin cogaltilamaz, yayinlanamaz ve para 
karsiligi satilamaz; mesajin yetkili alicisi veya alicisina iletmekten sorumlu 
kisi degilseniz, mesaj icerigini ya da eklerini kopyalamayiniz, yayinlamayiniz, 
baska kisilere yonlendirmeyiniz ve mesaji gonderen kisiyi derhal uyararak bu 
mesaji siliniz. Bu mesajin iceriginde ya da eklerinde yer alan bilgilerin 
dogrulugu, butunlugu ve guncelligi Bankamiz tarafindan garanti edilmemektedir 
ve bilinen viruslere karsi kontrolleri yapilmis olarak yollanan mesajin 
sisteminizde yaratabilecegi zararlardan Bankamiz sorumlu tutulamaz.

This message and the files attached to it are under the privacy liability in 
accordance with the Banking Law and confidential to the use of the individual 
or entity to whom they are addressed. This message cannot be copied, disclosed 
or sold monetary consideration for any purpose. If you are not the intended 
recipient of this message, you should not copy, distribute, disclose or forward 
the information that exists in the content and in the attachments of this 
message; please notify the sender immediately and delete all copies of this 
message. Our Bank does not warrant the accuracy, integrity and currency of the 
information transmitted with this message. This message has been detected for 
all known computer viruses thence our Bank is not liable for the occurrence of 
any system corruption caused by this message

Other related posts: