Skip to Main Content

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, ayush.

Asked: November 11, 2012 - 3:17 am UTC

Last updated: November 19, 2012 - 9:05 am UTC

Version: 10.2.4

Viewed 10K+ times! This question is

You Asked

Hi Tom, How are you doing.

I have a generic question. During which DML operation ( Insert,update and delete)
is the most undo and redo generated and why.

Regards
Ayush

and Tom said...

it depends :)

all you have to do however is think about what happens during each operation under different conditions - then you can sort of guestimate what will happen.

during an insert - we have to generate undo equivalent to "delete+rowid"

during an update - we have to generate undo equivalent to "update this rowid to have these before image values" (undo = rowid + column before images)

during a delete - we have to generate undo equivalent to "insert at this rowid these values"

so, considering an unindexed table - IN GENERAL, a delete and update will generate the most and an insert the least. IN GENERAL this is true (but not always).


if you add indexes - everything can change. the insert might generate gobs of undo for the index maintenance - the update might not update any indexed columns and hence only generate undo for the table - and the delete might have to maintain all of the indexes generating tons of undo again.

so, it depends on the nature of the data, what you are inserting/updating/deleting..

same for redo. It depends on what is modified...

Rating

  (2 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Ayush Agarwal, November 12, 2012 - 10:37 pm UTC


Excellent

Ayush Agarwal, November 15, 2012 - 12:41 am UTC

Hi Tom,

If it's possible, can you please provide example for the above issue. So that we can understand better.
Tom Kyte
November 19, 2012 - 9:05 am UTC

just perform a few operations and measure things....

here is an example with indexes...

ops$tkyte%ORA11GR2> create table t
  2  as
  3  select a.*
  4    from all_objects a
  5   where 1=0
  6  /

Table created.

ops$tkyte%ORA11GR2> create index t_idx1 on t(object_name);

Index created.

ops$tkyte%ORA11GR2> create index t_idx2 on t(object_type);

Index created.

ops$tkyte%ORA11GR2> create index t_idx3 on t(timestamp);

Index created.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> connect /
Connected.
ops$tkyte%ORA11GR2> set autotrace on statistics
ops$tkyte%ORA11GR2> insert into t select a.* from all_objects a
  2  /

72911 rows created.


Statistics
----------------------------------------------------------
       1514  recursive calls
     224491  db block gets
      57503  consistent gets
        888  physical reads
   62639584  redo size
        902  bytes sent via SQL*Net to client
       1011  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
       1501  sorts (memory)
          0  sorts (disk)
      72911  rows processed

ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> @mystat "undo change"
ops$tkyte%ORA11GR2> set echo off

NAME                         VALUE
----------------------- ----------
undo change vector size   24025452

ops$tkyte%ORA11GR2> commit;

Commit complete.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> connect /
Connected.
ops$tkyte%ORA11GR2> set autotrace on statistics
ops$tkyte%ORA11GR2> update t set object_id = object_id+1;

72911 rows updated.


Statistics
----------------------------------------------------------
         79  recursive calls
      78595  db block gets
       1324  consistent gets
        112  physical reads
   34121652  redo size
        902  bytes sent via SQL*Net to client
       1004  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      72911  rows processed

ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> @mystat "undo change"
ops$tkyte%ORA11GR2> set echo off

NAME                         VALUE
----------------------- ----------
undo change vector size   22234080

ops$tkyte%ORA11GR2> commit;

Commit complete.

ops$tkyte%ORA11GR2> 
ops$tkyte%ORA11GR2> connect /
Connected.
ops$tkyte%ORA11GR2> set autotrace on statistics
ops$tkyte%ORA11GR2> delete from t;

72911 rows deleted.


Statistics
----------------------------------------------------------
        423  recursive calls
     599516  db block gets
       2751  consistent gets
        722  physical reads
   78043120  redo size
        902  bytes sent via SQL*Net to client
        981  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
      72911  rows processed

ops$tkyte%ORA11GR2> set autotrace off
ops$tkyte%ORA11GR2> @mystat "undo change"
ops$tkyte%ORA11GR2> set echo off

NAME                         VALUE
----------------------- ----------
undo change vector size   40230900

ops$tkyte%ORA11GR2> commit;

Commit complete.