Search Oracle Blogs

List of Blogs maintained by Paweł Barut.


Sunday, September 17, 2006

ORA_ROWSCN behavior: bug or feature?

ORA_ROWSCN is pseudo column that gives SCN (System Change Number) for transaction that was modifying record. Lets take a closer look. First create table:
 CREATE TABLE A_TABLE
   (ID NUMBER, TEXT CHAR(2000));
Then feed table with some data:
SQL> declare
  2    procedure auto_commit
  3    is pragma autonomous_transaction;
  4    begin commit; end;
  5  begin
  6    for i in 1..10 loop
  7      insert into a_table select rownum, rownum 
from dual connect by level <=10;
  8      auto_commit;
  9    end loop;
 10  end;
 11  /
Procedure auto_commit is used to force change of SCN. Take a look what we have in table:
SQL> select ora_rowscn, count(*) from a_table
  2  group by ora_rowscn;

ORA_ROWSCN   COUNT(*)                                                           
---------- ----------                                                           
   4589308         24                                                           
   4589313         16                                                           
   4589293         15                                                           
   4589297         24                                                           
   4589302         21                                                           
We ran INSERT statement 10 times and we get 5 different SCN’s in table. None of them has exactly 10 rows. This is because table was created with default setting: NOROWDEPENDENCIES, and SCN is kept on block level. Every and each row in block has the same SCN. Lets commit this transaction:
SQL> commit;

Commit complete.

SQL> select ora_rowscn, count(*) from a_table
  2  group by ora_rowscn;

ORA_ROWSCN   COUNT(*)                                                           
---------- ----------                                                           
   4589363        100                                                           
Now all rows haveexactly the same SCN.
Now lets take a look what will happen for table with ROWDEPENDENCIES on.
 CREATE TABLE A_TABLE_ROW
   (ID NUMBER, TEXT CHAR(2000)) ROWDEPENDENCIES;
Insert some data:
SQL> declare
  2    procedure auto_commit
  3    is pragma autonomous_transaction;
  4    begin commit; end;
  5  begin
  6    for i in 1..10 loop
  7      insert into A_TABLE_ROW select rownum, rownum 
from dual connect by level <=10;
  8      auto_commit;
  9    end loop;
 10  end;
 11  /
Query table:
SQL> select ora_rowscn, count(*) from A_TABLE_ROW
  2  group by ora_rowscn;

ORA_ROWSCN   COUNT(*)                                                           
---------- ----------                                                           
                  100                                                           
Now ORA_ROWSCN is NULL for uncommitted transaction. This is very interesting.
SQL> commit;

Commit complete.

SQL> select ora_rowscn, count(*) from A_TABLE_ROW
  2  group by ora_rowscn;

ORA_ROWSCN   COUNT(*)                                                           
---------- ----------                                                           
   4590773        100                                                           
What will happen when updating:
SQL> update A_TABLE_ROW set id = id where rownum <20;

19 rows updated.

SQL> select ora_rowscn, count(*) from A_TABLE_ROW
  2  group by ora_rowscn;

ORA_ROWSCN   COUNT(*)
---------- ----------
                   19
   4590773         81
We can conclude that data in active transaction have NULL ORA_ROWSCN for tables with ROWDEPENDENCY.
What about Index Organized Tables:
 CREATE TABLE A_TABLE_IOT
   (ID NUMBER primary key, TEXT CHAR(2000)) organization index;
Generate data:
 SQL> declare
  2    procedure auto_commit
  3    is pragma autonomous_transaction;
  4    begin commit; end;
  5  begin
  6    for i in 1..10 loop
  7      insert into A_TABLE_IOT select i*10+rownum, rownum 
from dual connect by level <=10;
  8      auto_commit;
  9    end loop;
 10  end;
 11  /

PL/SQL procedure successfully completed.

SQL> select ora_rowscn, count(*) from A_TABLE_IOT
  2  group by ora_rowscn;

ORA_ROWSCN   COUNT(*)
---------- ----------
                  100
For IOT with NOROWDEPENDENCIES we still get NULLs for ORA_ROWSCN.

Questions:

1. Why we have such differences in implementation of ORA_ROWSCN?
2. We can see that SCN is assigned at commit. Does commit tackles all blocks modified by transaction? For short transaction it is not a problem, as blocks probably are still in buffer. But large transactions that generate lot of redo, and there are few check points during transaction time should not change this blocks. That means that block should have only transaction id, and oracle translates this transaction id to SCN.

Cheers, Paweł

3 comments:

Anonymous said...

Hi this is really nice post.


Gurpreet S. Gill

Anonymous said...

Your auto_commit procedure does a pragma autonomous_transcation. Per the PL/SQL Oracle 10g docs: "Once started, an autonomous transaction is fully independent. It shares no locks, resources, or commit-dependencies with the main transaction. You can log events, increment retry counters, and so on, even if the main transaction rolls back." The commit you did in auto_commit procedure did not commit the work in your main transaction. Therefore the null value of ora_rowscn is as expected.

Paweł Barut said...

Hi Anonymous.

The problem is with difference between Heap table and IOT table.
Same procedure gives different results when run on Heap table it fills ORA_ROWSCN, and for IOT it does not (both tables with NOROWDEPENDENCIES).
Also 2 Heap tables behave different depending on NOROWDEPENDENCIES or ROWDEPENDENCIES set.

Regards,
Paweł

 

Copyright © Paweł Barut
Printing from DOS to USB Printer