Oracle SQL
  • LICENSE

Tag Archives: redo

Triggers and Redo: changes on 12.2

Posted on November 19, 2017 by Sayan Malakshinov Posted in 12c, oracle, trace 1 Comment

In one of the previous posts I showed How even empty trigger increases redo generation, but running the test from that post, I have found that this behaviour a bit changed on 12.2:
In my old test case, values of column A were equal to values of B, and on previous oracle versions including 12.1.0.2 we can see that even though “update … set B=A” doesn’t change really “B”, even empty trigger greatly increases redo generation.
But on 12.2.0.1 in case of equal values, the trigger doesn’t increase redo, so we can see small optimization here, though in case of different values, the trigger still increases reado generation greatly.

same_dumpredo.sql
set feed on;
drop table xt_curr1 purge;
drop table xt_curr2 purge;
-- simple table:
create table xt_curr1 as select '2' a, '2' b from dual connect by level<=1000;
-- same table but with empty trigger:
create table xt_curr2 as select '2' a, '2' b from dual connect by level<=1000;
create or replace trigger tr_xt_curr2 before update on xt_curr2 for each row
begin
  null;
end;
/
-- objectID and SCN:
col obj1 new_val obj1;
col obj2 new_val obj2;
col scn  new_val scn;
select 
  (select o.OBJECT_ID from user_objects o where o.object_name='XT_CURR1') obj1
 ,(select o.OBJECT_ID from user_objects o where o.object_name='XT_CURR2') obj2
 ,d.CURRENT_SCN scn
from v$database d
/
-- logfile1:
alter system switch logfile;
col member new_val logfile;
SELECT member
FROM v$logfile
WHERE 
     is_recovery_dest_file='NO'
 and group#=(SELECT group# FROM v$log WHERE status = 'CURRENT')
 and rownum=1;
-- update1:
set autot trace stat;
update xt_curr1 set b=a;
set autot off;
commit;
-- dump logfile1:
alter session set tracefile_identifier='log1_same';
ALTER SYSTEM DUMP LOGFILE '&logfile' SCN MIN &scn OBJNO &obj1;

-- logfile2:
alter system switch logfile;
col member new_val logfile;
SELECT member
FROM v$logfile
WHERE 
     is_recovery_dest_file='NO'
 and group#=(SELECT group# FROM v$log WHERE status = 'CURRENT')
 and rownum=1;
-- update2:
set autot trace stat;
update xt_curr2 set b=a;
set autot off;
commit;
-- dump logfile2:
alter session set tracefile_identifier='log2_same';
ALTER SYSTEM DUMP LOGFILE '&logfile' OBJNO &obj2;
alter session set tracefile_identifier='off';
disc;

[collapse]

diff_dumpredo.sql

set feed on;
drop table xt_curr1 purge;
drop table xt_curr2 purge;
-- simple table:
create table xt_curr1 as select '1' a, '2' b from dual connect by level<=1000;
-- same table but with empty trigger:
create table xt_curr2 as select '1' a, '2' b from dual connect by level<=1000;
create or replace trigger tr_xt_curr2 before update on xt_curr2 for each row
begin
  null;
end;
/
-- objectID and SCN:
col obj1 new_val obj1;
col obj2 new_val obj2;
col scn  new_val scn;
select 
  (select o.OBJECT_ID from user_objects o where o.object_name='XT_CURR1') obj1
 ,(select o.OBJECT_ID from user_objects o where o.object_name='XT_CURR2') obj2
 ,d.CURRENT_SCN scn
from v$database d
/
-- logfile1:
alter system switch logfile;
col member new_val logfile;
SELECT member
FROM v$logfile
WHERE 
     is_recovery_dest_file='NO'
 and group#=(SELECT group# FROM v$log WHERE status = 'CURRENT')
 and rownum=1;
-- update1:
set autot trace stat;
update xt_curr1 set b=a;
set autot off;
commit;
-- dump logfile1:
alter session set tracefile_identifier='log1_diff';
ALTER SYSTEM DUMP LOGFILE '&logfile' SCN MIN &scn OBJNO &obj1;

-- logfile2:
alter system switch logfile;
col member new_val logfile;
SELECT member
FROM v$logfile
WHERE 
     is_recovery_dest_file='NO'
 and group#=(SELECT group# FROM v$log WHERE status = 'CURRENT')
 and rownum=1;
-- update2:
set autot trace stat;
update xt_curr2 set b=a;
set autot off;
commit;
-- dump logfile2:
alter session set tracefile_identifier='log2_diff';
ALTER SYSTEM DUMP LOGFILE '&logfile' OBJNO &obj2;
alter session set tracefile_identifier='off';
disc;

[collapse]

Equal values:
12.1.0.2:

12.2.0.1:

Different values:
12.1.0.2:

12.2.0.1:

We can easily find that trigger disables batched “Array update”:

redo triggers
photo Sayan Malakshinov

Oracle ACE Pro Oracle ACE Pro

DEVVYOracle Database Developer Choice Award winner

Oracle performance tuning expert

UK / Cambridge

LinkedIn   Twitter
sayan@orasql.org

Recent Posts

  • CBO and Partial indexing
  • Slow index access “COL=:N” where :N is NULL
  • Where does the commit or rollback happen in PL/SQL code?
  • :1 and SP2-0553: Illegal variable name “1”.
  • ORA exceptions that can’t be caught by exception handler

Recent Comments

  • Oracle SGA 값을 증가 시킬 때 발생 장애 원인 – DBA의 정석 on Example of controlling “direct path reads” decision through SQL profile hints (index_stats/table_stats)
  • Oracle SQL | Oracle diagnostic events — Cheat sheet on Where does the commit or rollback happen in PL/SQL code?
  • Functions & Subqueries | Oracle Scratchpad on Deterministic function vs scalar subquery caching. Part 3
  • Materialized views state turns into compilation_error after refresh - kranar.top - Answering users questions... on Friday prank: select from join join join
  • Exadata Catalogue | Oracle Scratchpad on When bloggers get it wrong – part 1
  • Exadata Catalogue | Oracle Scratchpad on Serial Scans failing to offload
  • lateral join – decorrelation gone wrong – svenweller on Lateral view decorrelation(VW_DCL) causes wrong results with rownum
  • 255 column catalogue | Oracle Scratchpad on Intra-block row chaining optimization in 12.2
  • 255 column catalogue | Oracle Scratchpad on row pieces, 255 columns, intra-block row chaining in details
  • opt_estimate catalogue | Oracle Scratchpad on Correct syntax for the table_stats hint

Blogroll

  • Alex Fatkulin
  • Alexander Anokhin
  • Andrey Nikolaev
  • Charles Hooper
  • Christian Antognini
  • Coskan Gundogar
  • David Fitzjarrell
  • Igor Usoltsev
  • Jonathan Lewis
  • Karl Arao
  • Mark Bobak
  • Martin Bach
  • Martin Berger
  • Neil Chandler
  • Randolf Geist
  • Richard Foote
  • Riyaj Shamsudeen
  • Tanel Poder
  • Timur Akhmadeev
  • Valentin Nikotin

Meta

  • Log in
  • Entries feed
  • Comments feed
  • WordPress.org
©Sayan Malakshinov. Oracle SQL