Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

ORA_ROWSCN: The pseudo Column

Oracle Tips by Burleson Consulting

ORA_ROWSCN

 

By Robert Freeman

 



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! :-)



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 APEX):


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 than APEX's automated row processing myself.


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.