Mview Complete Refresh – Is it slow? High redo generation? — Oracle 10g

From past few weeks, this was one the very common question i was being asked from my friends and even on OTN forum.

After migrating to 10g, mview refresh is taking time and even the redo log generation has increased for that period.Why?

I had read about it long back, almost a year back here http://askdba.org/weblog/2009/07/mview-complete-refresh-and-atomic_refresh-parameter/

Thanks to Amit 🙂

Demo time on 10.2.0.4 —

ANAND’s session – referred as Session 1
SCOTT’s session – referred as Session 2

Session 1
=========

12:46:15 ANAND at matrix >select object_name,status from user_objects where object_type='MATERIALIZED VIEW';

no rows selected
Session 2
==========
12:45:33 SCOTT at matrix >show user
USER is "SCOTT"
12:45:37 SCOTT at matrix >select * from emp;


     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500          0         30
      7876 ADAMS      CLERK           7788 23-MAY-87       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10
      8000 JOHN       ANALYST         7566 03-DEC-84       3000                    20
      8200 JIMMY      ANALYST         7566 03-DEC-84       3000                    20

16 rows selected.

Elapsed: 00:00:00.00
12:45:41 SCOTT at matrix >
12:47:02 SCOTT at matrix >
12:47:02 SCOTT at matrix >grant select on emp to anand;

Grant succeeded.

Elapsed: 00:00:00.01
12:47:09 SCOTT at matrix >
Session 1
=========
12:57:07 ANAND at matrix >create materialized view emp_mv_complete
12:57:17   2  build immediate
12:57:22   3  refresh complete
12:57:29   4  as
12:57:33   5  select * from scott.emp;

Materialized view created.

Elapsed: 00:00:00.29

Session 2
=========
12:58:43 SCOTT at matrix >delete from emp where EMPNO in (8000,8200);

2 rows deleted.

Elapsed: 00:00:00.07
12:59:05 SCOTT at matrix >commit;

Commit complete.

Elapsed: 00:00:00.01
12:59:07 SCOTT at matrix >

Now the Scott's emp table have total of 14 rows 
Session 1  -- Lets refresh the mview
========
12:59:12 ANAND at matrix >exec dbms_mview.refresh('EMP_MV_COMPLETE');

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.53
12:59:43 ANAND at matrix >

Before the refresh i had enabled 10046 trace for ANAND’s session.The trace shows –

=====================
PARSING IN CURSOR #40 len=38 dep=1 uid=64 oct=7 lid=64 tim=60423526544 hv=1342554646 ad='1bdbdaec'
 delete from "ANAND"."EMP_MV_COMPLETE"
END OF STMT
PARSE #40:c=0,e=4399,p=0,cr=6,cu=0,mis=1,r=0,dep=1,og=1,tim=60423526537
BINDS #40:
EXEC #40:c=0,e=774,p=0,cr=1,cu=49,mis=0,r=16,dep=1,og=1,tim=60423527477
=====================

All the rows are deleted first and then inserted.DELETE is what makes the refresh slower and generates a lot of redo in Oracle 10g.In Oracle 9i, instead of delete it was truncate.So, what has changed from 9i to 10g?

As Amit, had mentioned in his blog, its the “ATOMIC_REFRESH” parameter behavior.In both the versions of Oracle the default value is TRUE, but the behavior has changed.

In 9i — Default is TRUE and TRUNCATE is used.
In 10g — Default is TRUE and DELETE is used.

Lets see what happens when “ATOMIC_REFRESH” parameter is set to FALSE in Oracle 10g.

Session 2
========
13:11:33 SCOTT at matrix >insert into emp values (8000,'JOHN','ANALYST',7566,'03-DEC-84',3000,'',20);

1 row created.

Elapsed: 00:00:00.01
13:11:34 SCOTT at matrix >insert into emp values (8200,'JIMMY','ANALYST',7566,'03-DEC-84',3000,'',20);

1 row created.

Elapsed: 00:00:00.01
13:11:34 SCOTT at matrix >commit;

Commit complete.

Elapsed: 00:00:00.03
13:11:35 SCOTT at matrix >

Now the Scott's emp table has 16 rows
Session 1
=========
13:11:01 ANAND at matrix >select * from EMP_MV_COMPLETE;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500          0         30
      7876 ADAMS      CLERK           7788 23-MAY-87       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

14 rows selected.

Elapsed: 00:00:00.07
13:11:14 ANAND at matrix >
13:11:50 ANAND at matrix >
13:11:50 ANAND at matrix >exec dbms_mview.refresh('EMP_MV_COMPLETE',atomic_refresh => false);

PL/SQL procedure successfully completed.

Elapsed: 00:00:02.57
13:12:06 ANAND at matrix >select * from EMP_MV_COMPLETE;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500          0         30
      7876 ADAMS      CLERK           7788 23-MAY-87       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10
      8000 JOHN       ANALYST         7566 03-DEC-84       3000                    20
      8200 JIMMY      ANALYST         7566 03-DEC-84       3000                    20

16 rows selected.

Elapsed: 00:00:00.15
13:12:17 ANAND at matrix >

What has the 10046 trace to show?

=====================
PARSING IN CURSOR #22 len=60 dep=1 uid=64 oct=85 lid=64 tim=61164324021 hv=3988442541 ad='1825ddc4'
 truncate table "ANAND"."EMP_MV_COMPLETE" purge snapshot log
END OF STMT
PARSE #22:c=0,e=90773,p=0,cr=0,cu=1,mis=1,r=0,dep=1,og=1,tim=61164324016
BINDS #22:
=========================

So if you are using mviews on 10g and doing a complete refresh, don’t forget to set “ATOMIC_REFRESH” to “FALSE” during refresh. 🙂

What i need to find out now is why “purge snapshot log” ?? 😉

UPDATE (9th-Nov-2010) –
=========================

This post was written to show the change in the default behavior of atomic refresh and to answer why the complete refresh takes time.But the last statement of the blog where i do mention ” So if you are using mviews on 10g and doing a complete refresh, don’t forget to set “ATOMIC_REFRESH” to “FALSE” during refresh.” is incorrect to say.

The default value “TRUE” for ATOMIC_REFRESH is set to maintain the read consistency in case some session is querying the data from materialized view during the refresh period.From Oracle doc

Materialized View Refresh
=====================
In Oracle Database 10g Release 2, a complete refresh of a single materialized view using dbms_mview.refresh performs a delete of the materialized view base table instead of a truncate (prior to Oracle Database 10g Release 2, Materialized view used truncate). This may require more time to perform the complete refresh and generate more redo.

This change was made to prevent wrong results. Refreshing a single MV is not atomic even if ATOMIC_REFRESH = true (the default). Previously, the refresh could lead to wrong results in sessions querying the materialized view, as the row count can suddenly change to 0 (as the refresh truncates the MV). An atomic refresh should not affect read consistency in this way.

So, before changing the value for the ATOMIC_REFRESH parameter permanently, know how application is using the mview’s data and what is the refresh time, how frequently the refresh happens, what could be the consequences of the change, if done.

Do not blindly change the value to “false”.

Thanks to Santosh Kumar for the inputs.

6 thoughts on “Mview Complete Refresh – Is it slow? High redo generation? — Oracle 10g

  1. Nice posting once again, Anand.

    I was just thinking of one old issue which was associated with “ATOMIC_REFRESH”. The truncate is always going to be faster and produce almost no archive(so no IO). But think of an application which badly relies on rownum. The truncate will reset the value of rownum to ‘0’ and may cause wrong resultset. Whereas delete will maintain the rownum.

    So I feel one should understand the application requirement and only then play with the parameter.

    Awaiting your opinion.

    1. Hi Santosh,

      Can you provide an example for it.With my little Oracle knowledge,as far as i can understand is, when we do a complete refresh the rowids will definitely change and the sql queries using rownum will generate different resultset every time complete refresh is done, regardless of atomic_refresh being “true” or “false”.

      I might be missing somewhere, but would definitely like to learn from you.

      Regards,
      Anand

      1. Hi Anand,

        The feature ‘atomic_refresh=true’ has definately a meaning behind it. Unable to create an example at the moment, but copying and pasting the excerpt from 10g Upgrade Companion:


        Materialized View Refresh
        In Oracle Database 10g Release 2, a complete refresh of a single materialized view using dbms_mview.refresh performs a delete of the materialized view base table instead of a truncate (prior to Oracle Database 10g Release 2, Materialized view used truncate). This may require more time to perform the complete refresh and generate more redo.

        This change was made to prevent wrong results. Refreshing a single MV is not atomic even if ATOMIC_REFRESH = true (the default). Previously, the refresh could lead to wrong results in sessions querying the materialized view, as the row count can suddenly change to 0 (as the refresh truncates the MV). An atomic refresh should not affect read consistency in this way.

        Reference:
        Metalink Note Id: 466181.1

        With Best Regards,
        Santosh

      2. Hi Santosh,

        This change was made to prevent wrong results. Refreshing a single MV is not atomic even if ATOMIC_REFRESH = true (the default). Previously, the refresh could lead to wrong results in sessions querying the materialized view, as the row count can suddenly change to 0 (as the refresh truncates the MV). An atomic refresh should not affect read consistency in this way.

        An atomic refresh should not affect read consistency in this way” is the most important factor for changing the default behavior from 10g.As far as the word “rownum” was concerned in your previous comment, it made me think little out of the way.

        The last line in my post “So if you are using mviews on 10g and doing a complete refresh, don’t forget to set “ATOMIC_REFRESH” to “FALSE” during refresh.” is incorrect to say.Definitely, understanding the application requirement it must before changing the default settings.

        I will update it.Thanks for your valuable input.

        Regards,
        Anand

  2. Keep posting your experience. These are really valuable stuffs. I still have to come out of theoretical part as far as materialized views are concerned i.e. I have not worked a lot on materialized view.( 😉 At the moment, concentrating on fighter planes, so no rigourous study of oracle).

  3. i am doing the group refresh using Dbms_Refresh.Refresh in 10g,then where to specify the ATOMIC REFRESH parameter and what is the default value for the ATOMIC REFRESH parameter ?

    Please guide me !

    Thanks
    Yassin Khan

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s