Friday, June 10, 2005

ORA_ROWSCN.... New 10g pseudo Column

If you have written code for the web that involves select for update, no doubt you have run into problems where the web session somehow disappeared, and the database didn't realize it. The result is that the record remained locked until you killed the session. I've been involved with several clients now where this is a common problem, so common that they have an automated routine to "clean up" these zombie sessions.

So what do you do if you are writing code, and you don't want to use that pesky FOR UPDATE syntax? Oracle Database 10g offers ORA_ROWSCN!! ORA_ROWSCN provides an answer to consistency, without needing to lock a row. ORA_ROWSCN is a new pseudo column available in Oracle Database 10g. It provides the SCN associated with each individual row in a table when it was read. One thing to note, by default Oracle will not track SCN's at the row level in a table, so you need to enable row level dependency tracking by using the ROWDEPENDENCIES keyword in the CREATE TABLE command. We have noticed no additional performance issues with this feature enabled. Still, it's always a good idea to test things before you just start using them in production! :-)

Here is an example. In an HTMLDB application (but this technique can be used in any kind of 10g application), we want to read in a record from the database and offer the potential to edit the record. We don't want to lock it at this point for a number of reasons (for example, our user might just leave the record up on his/her web browser for an hour). So, we use something like this PL/SQL code when we load our page for the first time:

begin
select b.name, a.adr_id, a.address, a.ora_rowscn,
b.ora_rowscn
into :P4710_EDIT_NAME,
:P4710_ADR_IDENTIFIER,
:P4710_EDIT_ADDR,
:P4710_EDT_NAME_ORA_ROWSCN,
:P4710_EDT_ADDR_RWSCN
from addresses a, place b
where b.place_id=v('P4710_PLACE')
and a.adr_identifier=b.adr_identifier
and a.adr_sequence=b.adr_sequence;
end;

Note in this code that we load in the ORA_ROWSCN values for both the tables/rows we are reading. Now, we make changes to this data, and we get ready to update it. How do we know, though, that someone else has not changed the data?

We could requery the record just before we write it and make sure the data is still the same, but then we really need to use the FOR UPDATE clause again, and we want to avoid that. If we don't use the FOR UPDATE clause, someone could still change the data between the query and the update.

The solution is to use ORA_ROWSCN in your update clause to ensure that the row has not changed since the last time you read it. Here is an example (again, a PL/SQL code block from HTMLDB):

declare
-- Declare the exception
htmldb_record_changed EXCEPTION;
begin
-- Update the HSD-unit_codes table
update addresses
set address=v(':P4710_EDIT_ADDR')
where adr_identifier=v('P4710_ADR_IDENTIFIER')
and v('P4710_EDT_ADDR_ROWSCN')=ORA_ROWSCN;
:P4710_SUCCESSFUL_ADD:='TRUE';

-- See above where we compare the ROWSCN list value to the
-- current ORA_ROWSCN of the table?

-- Note that SQL%ROWCOUNT=0 if we didn’t update a row.
-- This means that the update failed.

if SQL%ROWCOUNT<=0
then
-- We clear the cache of the page.
htmldb_util.clear_page_cache(4710);
-- This raises the error to the user that the record was already
-- changed.
raise_application_error(-20000, 'Record has already been changed by another user.');
else
-- I set this to allow a display message to be printed on
-- the refresh.
:P4710_SUCCESSFUL_ADD=’TRUE’
end if;
end;

Note in the WHERE clause that I check the recorded ORA_ROWSCN against the current value of ORA_ROWSCN for that table. If the record has changed since I read it, then ORA_ROWSCN for the row will be different than the one we stored when we did the earlier select, and then an exception will be raised.

I've found this to be much easier to use that HTMLDB's automated row processing myself. What do you think?

Robert

6/11/2005 Note: I edited this blog to fix an entry that was in error. It indicated that the ROWDEPENDENCIES keyword could be used with the alter table command. In a comment, Tom Kyte has pointed out this is not the case, so I've made that correction here.

3 comments:

Thomas Kyte said...

Robert --

ora_rowscn is cool -- but two things.

first, you cannot (unfortunately) ALTER it "on", the table must be rebuilt. The reason why the table must be rebuilt is the second thing:

second, it adds 6 bytes of "overhead" per row. A little smaller than a date/timestamp and maybe a little bigger than a number.

BUT, you can turn the ora_rowscn into a timestamp using a function to map scns to time, showing the last modification of a row (for a while, as long as the SCN can be mapped) and it is totally non-intrusive to existing applications.

That last point makes it a good choice for apps that need to do this but coexist with other "not so well built apps" that do a select * and would be really upset if a new timestamp column appears.

Also, no triggers to write to maintain timestamps and such.

HTML DB does a md5 checksum of all of the columns read out and that can be a bit of a CPU user (the md5 algorithm) so if you actually find this easier (using the wizard and letting it do it for me was pretty easy), you might find this also to consume slightly less CPU as you are not computing that md5 checksum twice.

Robert Freeman said...

Great thoughts Tom!! Thanks for coming!

Anonymous said...

This feature certainly does look interesting when I do get around to and having time for experimenting with html db I will try to remember this part. Maybe I have been lazy on the html db side (not really just too busy) but 2 things on my "waiting for list" include 10g release 2 and the tusc html db book. Thanks for noting this.

 
Subscribe in a reader