jump to navigation

11g Virtual Columns and Fast Refreshable Materialized Views (What In The World) November 24, 2010

Posted by Richard Foote in 11g, 11g New features, Function Based Indexes, Oracle Bugs, Virtual Columns.
trackback

Previous to Oracle 11g Rel 2, two very common and useful features previously worked well together, they being fast refreshable materialized views and the introduction of virtual columns due to the creation of function-based indexes.
 
To illustrate, we create and populate a little demo table: 

 
SQL> create table bowie (a number, b number, c number);
 
Table created.
 
SQL> insert into bowie select rownum, mod(rownum,10), mod(rownum,100) from dual connect by level <= 100000;
 
100000 rows created.
 
SQL> commit;
 
Commit complete.
 
SQL> alter table bowie add primary key (a);
 
Table altered.

 
We now create a simple little function-based index:
 

 
SQL> create index bowie_func_i on bowie(b+c);
 
Index created.

 
 
If we look at the columns in the table via DBA_TAB_COLS:
 

 
SQL> select column_name, data_default, virtual_column, hidden_column from dba_tab_cols where table_name = 'BOWIE';
 
COLUMN_NAME  DATA_DEFAULT VIR HID
------------ ------------ --- ---
SYS_NC00004$ "B"+"C"      YES YES
C                         NO  NO
B                         NO  NO
A                         NO  NO

 

We notice Oracle has introduced a new, hidden virtual column (SYS_NC00004$), required to store statistics for use by the Cost Based Optimizer.
 
Next we create a materialized view log on this table and a fast refreshable materialized view:
 

 
SQL> create materialized view log on bowie WITH PRIMARY KEY,SEQUENCE, ROWID (b,c) INCLUDING NEW VALUES;
 
Materialized view log created.
 
SQL> create materialized view bowie_mv
  2  build immediate
  3  refresh fast
  4  with primary key
  5  enable query rewrite
  6  as
  7  select b, count(*) from bowie group by b;
 
Materialized view created.

 
 
Collect a few statistics and we note the Materialized View does indeed get used during a query rewrite scenario:
 

 
SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE', estimate_percent=>null, cascade=> true, method_opt=> 'FOR ALL COLUMNS SIZE 1')
 
PL/SQL procedure successfully completed.
 
SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE_MV', estimate_percent=>null, cascade=> true, method_opt=> 'FOR ALL COLUMNS SIZE 1')
 
PL/SQL procedure successfully completed. 

SQL> select b, count(*) from bowie having b > 3 group by b;
 
         B   COUNT(*)
---------- ----------
         6      10000
         4      10000
         5      10000
         8      10000
         7      10000
         9      10000
 
6 rows selected.
 

Execution Plan
----------------------------------------------------------
Plan hash value: 593592962
 
-----------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |     7 |    42 |     2   (0)| 00:00:01 |
|*  1 |  MAT_VIEW REWRITE ACCESS FULL| BOWIE_MV |     7 |    42 |     2   (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
 

Predicate Information (identified by operation id):
---------------------------------------------------
 
   1 - filter("BOWIE_MV"."B">3)
 

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
        538  bytes sent via SQL*Net to client
        395  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          6  rows processed

 
 

And indeed the materialized view is fast refreshable:
 

 
SQL> insert into bowie values (100001, 5, 42);
 
1 row created.
 
SQL> commit;
 
Commit complete.
 
SQL> exec dbms_mview.refresh('BOWIE_MV', 'F');
 
PL/SQL procedure successfully completed.
 
 
SQL> select b, count(*) from bowie having b > 3 group by b;
 
         B   COUNT(*)
---------- ----------
         6      10000
         4      10000
         5      10001
         8      10000
         7      10000
         9      10000
 
6 rows selected.
 

Execution Plan
----------------------------------------------------------
Plan hash value: 593592962
 
-----------------------------------------------------------------------------------------
| Id  | Operation                    | Name     | Rows  | Bytes | Cost (%CPU)| Time     |
-----------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT             |          |     7 |    42 |     2   (0)| 00:00:01 |
|*  1 |  MAT_VIEW REWRITE ACCESS FULL| BOWIE_MV |     7 |    42 |     2   (0)| 00:00:01 |
-----------------------------------------------------------------------------------------
 

Predicate Information (identified by operation id):
---------------------------------------------------
 
   1 - filter("BOWIE_MV"."B">3)
 

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
          4  consistent gets
          0  physical reads
          0  redo size
        546  bytes sent via SQL*Net to client
        395  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          6  rows processed

 
Notice how the materialized view does indeed displayed the correct updated information via the query rewrite operation . So the materialized view behaved and worked as expected even though the underlining master table has a virtual column due to the creation of the function-based index (note that QUERY_REWRITE_INTEGRITY is set to STALE_TOLERATED)
 
Unfortunately, things go off the rails somewhat since Oracle 11g Rel 2 when a virtual column is introduced due to one of the 11g new features. For example, I now collect some Extended Statistics on this table:
 

 
SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>'BOWIE', method_opt=> 'FOR COLUMNS (A,B,C) SIZE 254');
 
PL/SQL procedure successfully completed.
 
SQL> select column_name, data_default, virtual_column, hidden_column from dba_tab_cols where table_name = 'BOWIE';
 
COLUMN_NAME                    DATA_DEFAULT                      VIR HID
------------------------------ --------------------------------- --- ---
SYS_STUM4KJU$CCICS9C1UJ6UWC4YP SYS_OP_COMBINED_HASH("A","B","C") YES YES
SYS_NC00004$                   "B"+"C"                           YES YES
C                                                                NO  NO
B                                                                NO  NO
A                                                                NO  NO

 
 
Notice how extended statistics has resulted in another hidden virtual column (SYS_STUM4KJU$CCICS9C1UJ6UWC4YP) being created to store the resultant statistics.
 
However, if now attempt to perform a fast refresh on the Materialized View:

 
SQL> insert into bowie values (100002, 5, 42);
 
1 row created.
 
SQL> commit;
 
Commit complete.
 
SQL> exec dbms_mview.refresh('BOWIE_MV', 'F');
BEGIN dbms_mview.refresh('BOWIE_MV', 'F'); END;
 
*
ERROR at line 1:
ORA-12008: error in materialized view refresh path
ORA-00904: "MAS$"."SYS_STUM4KJU$CCICS9C1UJ6UWC4YP": invalid identifier
ORA-06512: at "SYS.DBMS_SNAPSHOT", line 2558
ORA-06512: at "SYS.DBMS_SNAPSHOT", line 2771
ORA-06512: at "SYS.DBMS_SNAPSHOT", line 2740
ORA-06512: at line 1

 

We get an error, complaining about the existence of this new virtual column.
 
If we attempted to drop and re-create the materialized view:

 
SQL> drop materialized view bowie_mv;
 
Materialized view dropped.
 
SQL> create materialized view bowie_mv
  2  build immediate
  3  refresh fast
  4  with primary key
  5  enable query rewrite
  6  as
  7  select b, count(*) from bowie group by b;
select b, count(*) from bowie group by b
                        *
ERROR at line 7:
ORA-12033: cannot use filter columns from materialized view log on "BOWIE"."BOWIE"

 

It fails, complaining that the materialized view log is somehow missing a filter column (which it isn’t).  We get exactly the same set of issues if we add a visible virtual column via this new 11g capability: 
 
 

 
SQL> create table bowie2 (a number, b number, c number, d as (a+b+c));
 
Table created.
 
SQL> select column_name, data_default, virtual_column, hidden_column from dba_tab_cols where table_name = 'BOWIE2';
 
COLUMN_NAME  DATA_DEFAULT VIR HID
------------ ------------ --- ---
D            "A"+"B"+"C"  YES NO
C                         NO  NO
B                         NO  NO
A                         NO  NO
 
SQL> insert into bowie2 (a,b,c) select rownum, mod(rownum,10), mod(rownum,100) from dual connect by level <= 100000;
 
100000 rows created.
 
SQL> commit;
 
Commit complete.
 
SQL> alter table bowie2 add primary key (a);
 
Table altered.
 
SQL> create materialized view log on bowie2 WITH PRIMARY KEY,SEQUENCE, ROWID (b,c) INCLUDING NEW VALUES;
 
Materialized view log created.
 
SQL> create materialized view bowie2_mv
  2  build immediate
  3  refresh fast
  4  with primary key
  5  enable query rewrite
  6  as
  7  select b, count(*) from bowie2 group by b;
select b, count(*) from bowie2 group by b
                        *
ERROR at line 7:
ORA-12033: cannot use filter columns from materialized view log on "BOWIE"."BOWIE2"

 
Extended statistics and visible virtual columns are both potentially extremely useful new features introduced in 11g but unfortunately both can not be implemented on any table that needs to be fast refreshable within a complex materialized view.

I raised this issue with Oracle Support who have raised bug 10281402 as a result as it occurs in both 11.2.0.1 and 11.2.0.2 on various platforms I’ve tested.

Comments»

1. Gianluca Sartori - February 24, 2011

Hi Richard,
I’m running into the same problem here.
Did support give you a fix for this issue? I find it very annoying, especially because in many cases the optimizer cannot estimate correctly the cardinality without extended statistics (eg. corraleted columns). However, MVs introduce a great performance benefit in many scenarios and I cannot drop them. MVs + extended statistics would be the best of both worlds.
Thanks,
Gianluca

Like

Richard Foote - February 24, 2011

Hi Giabluca

No, this is still being worked on by Oracle Support. I’ll post details of a fix once they come to hand.

Like

2. andrea - March 17, 2011

Hi Richard,

We created a new SR specific for visible virtual columns: “SR 3-3208078560: FAST REFRESH ON MVIEW IS FAILING WITH VIRTUAL COLUMNS”.

The following is an example:
SQL>CREATE TABLE master_tab (A NUMBER(1), vir NUMBER GENERATED ALWAYS AS ( ROUND ( A ) ) VIRTUAL);

Table created.

SQL>CREATE INDEX master_tab_idx ON master_tab (vir) ;

Index created.

SQL>CREATE MATERIALIZED VIEW LOG ON master_tab WITH ROWID, SEQUENCE (“A”) INCLUDING NEW VALUES;

Materialized view log created.

SQL>CREATE MATERIALIZED VIEW mview AS SELECT ml.vir, COUNT(1) FROM MASTER_TAB ml GROUP BY ml.vir;

Materialized view created.
SQL>EXEC DBMS_SNAPSHOT.REFRESH(LIST => ‘MVIEW’, METHOD => ‘F’);

PL/SQL procedure successfully completed.

SQL>INSERT INTO MASTER_TAB (A) VALUES (1);

1 row created.

SQL>COMMIT;

Commit complete.

SQL>EXEC DBMS_SNAPSHOT.REFRESH(LIST => ‘MVIEW’, METHOD => ‘F’);
BEGIN DBMS_SNAPSHOT.REFRESH(LIST => ‘MVIEW’, METHOD => ‘F’); END;

*
ERROR at line 1:
ORA-12008: error in materialized view refresh path
ORA-00904: “DLT$0″.”VIR”: invalid identifier
ORA-06512: at “SYS.DBMS_SNAPSHOT”, line 2566
ORA-06512: at “SYS.DBMS_SNAPSHOT”, line 2779
ORA-06512: at “SYS.DBMS_SNAPSHOT”, line 2748
ORA-06512: at line 1

Elapsed: 00:00:00.25
SQL>

Thanks
Andrea

Like

Richard Foote - April 20, 2011

Hi Andrea

Yes, same issue as we hit. Still to be addressed.

Like

3. Virtual Columns « Oracle Scratchpad - April 18, 2011

[…] I see that Richard Foote has been uncovering some problems with virtual columns. As so often happens with new Oracle features combinations cause problems. In this case it’s […]

Like

4. Reiner Kuehl - July 11, 2012

Hi Richard
I would like to add another thing that is not working with the combination of ‘virtual columns’ and materialized views:
Query Rewrite!
We have function-based indexes in our application (UPPER()). In 10g the query rewrites properly without specifying explicitly the materialized view. In 11g, whenever the optimizer uses the function-based index the query will not be rewritten.
Oracle support says: “Works as designed”. I have opened an enhancement request:
Bug 12345941: ABILITY TO REWRITE QUERY WITH FUNCTION-BASED INDEX
br
Reiner

Like

5. Robert Praetorius - March 22, 2014

Did anybody ever hear back on 12345941? I’m still seeing it lasted with the status Enhancement Request with no update at support.oracle.com since 5/13/2011

Like

Richard Foote - April 16, 2014

Hi Robert

I can provide no update other than it appears to still be with enhancements request for review.

Like

6. Robert Praetorius - March 22, 2014

(but I did see that 10281402 (aka 10259677) was addressed in the 11.2.0.3 patch set)

Like

7. Sahaj Jhingan - May 8, 2015

Hi Richard.

Gr8 article..
However i would like to update just in case starting from Oracle version 11.2.0.3 this issue seems to be taken care of .
Snapshot below:

SQL> select banner from v$version;

BANNER
——————————————————————————–
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 – 64bit Production
PL/SQL Release 11.2.0.3.0 – Production
CORE 11.2.0.3.0 Production
TNS for Linux: Version 11.2.0.3.0 – Production
NLSRTL Version 11.2.0.3.0 – Production

>>>>> Last steps with extended statistics->>>>>

SQL> exec dbms_stats.gather_table_stats(ownname=>null, tabname=>’BOWIE’, method_opt=> ‘FOR COLUMNS (A,B,C) SIZE 254’);

PL/SQL procedure successfully completed.

SQL> select column_name, data_default, virtual_column, hidden_column from dba_tab_cols where table_name = ‘BOWIE’;

COLUMN_NAME DATA_DEFAULT VIR HID
—————————— ——————————————————————————– — —
SYS_STUM4KJU$CCICS9C1UJ6UWC4YP SYS_OP_COMBINED_HASH(“A”,”B”,”C”) YES YES
SYS_NC00004$ “B”+”C” YES YES
C NO NO
B NO NO
A NO NO

SQL> insert into bowie values (100002, 5, 42);

1 row created.

SQL> commit;

Commit complete.

SQL> exec dbms_mview.refresh(‘BOWIE_MV’, ‘F’);

PL/SQL procedure successfully completed.

materialized view is getting fast refreshable.

Query using MV…

SQL> select b, count(*) from bowie having b > 3 group by b;

B COUNT(*)
———- ———-
6 10000
4 10000
5 10002
8 10000
7 10000
9 10000

6 rows selected.

Execution Plan
———————————————————-
Plan hash value: 593592962

—————————————————————————————–
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
—————————————————————————————–
| 0 | SELECT STATEMENT | | 7 | 42 | 3 (0)| 00:00:01 |
|* 1 | MAT_VIEW REWRITE ACCESS FULL| BOWIE_MV | 7 | 42 | 3 (0)| 00:00:01 |
—————————————————————————————–

Predicate Information (identified by operation id):
—————————————————

1 – filter(“BOWIE_MV”.”B”>3)

Statistics
———————————————————-
0 recursive calls
0 db block gets
3 consistent gets
0 physical reads
0 redo size
689 bytes sent via SQL*Net to client
523 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
0 sorts (memory)
0 sorts (disk)
6 rows processed

Like

8. Richard Foote - May 8, 2015

Hi Sahaj

Thanks, yes this issue was resolved as part of the 11.2.0.3 patch set. I can also confirm it works on 12.1.0.2 on windows as I just tested it 🙂

Like

9. Yahia Bani - May 6, 2016

Thank you Richard, we re getting “[Error] Execution (408: 10): ORA-12033: cannot use filter columns from materialized view log on’ on Oracle database 12C.

Like

Richard Foote - May 26, 2016

Hi Yahia

On what version of version 12c, on what platform, using what scenario ?

Like

10. Yahia - July 7, 2016

Thank you, Richard! Oracle 12.1.0.2.0 on Windows 2012.

Like

Richard Foote - August 2, 2016

Hi Yahia

I can’t replicate the problem again on Windows 7. Raise an SR would be the best bet to get things sorted.

Like


Leave a comment