FAST REFRESHing of Oracle Materialized Views containing Sdo_Geometry columns

After much trial and error at a couple of customer sites, I worked out how to get FAST REFRESHing of materialized views that contain Sdo_geometry columns.

The following points give you a starting guide. Yes, the Oracle documentation really is your best source of information, but sometimes being able to see how others made it work can be very useful.

1. You can FAST REFRESH a materialized view that has an Oracle object such as SDO_Geometry in its select list only if it is based on a single table (ie one entry in a FROM clause).

CREATE MATERIALIZED VIEW mv_a
AS
SELECT ID,
       GEOM
  FROM table_a;

If you do join two or more tables and include an SDO_Geometry:

CREATE MATERIALIZED VIEW mv_a_b
AS
SELECT a.ID,
       b.value,
       a.GEOM
  FROM table_a a,
       table_b b
 WHERE b.ID = a.ID;

 

You will get the following reported in MV_CAPABILITIES_TABLE:

REFRESH_FAST_AFTER_INSERT – “expression not supported for fast refresh”. (Not very helpful “expression”.)

Summary: An MV with a join (simple or otherwise) cannot have an Oracle object such as SDO_Geometry in its attribute list.

2. ENABLE QUERY REWRITE doesn’t work when the select list contains an Oracle object such as SDO_Geometry.

CREATE MATERIALIZED VIEW mv_a
ENABLE QUERY REWRITE
AS
SELECT ID,
       GEOM
       FROM table_a;

 

You will get this error: ORA-30373: object data types are not supported in this context
If you construct a materialized view without the “ENABLE QUERY REWRITE” clause, MV_CAPABILITIES_TABLE reports:

REWRITE_FULL_TEXT_MATCH N object data types are not
                           supported in this contex

4. (Not just Sdo_Geometry) You must use Oracle traditional join specification (WHERE clause) for joins if you want FAST REFRESH.

CREATE MATERIALIZED VIEW mv_a_b
AS
SELECT a.ID,
       b.value
  FROM table_a a,
       table_b b
 WHERE b.ID = a.ID;

If you use the ANSI/SQL INNER JOIN syntax:

CREATE MATERIALIZED VIEW mv_a_b
AS
SELECT a.ID,
       b.value
  FROM table_a a INNER JOIN table_b b USING (ID);

You will get this reported in the MV_CAPABILITIES table:

REFRESH_FAST_AFTER_INSERT – “inline view or subquery in FROM list not supported for this type MV”

5. Even if you have PRIMARY KEYS on all base tables and MVs you MUST have ROWID in all materialized view logs if you “nest” materialized views.

CREATE MATERIALIZED VIEW LOG ON TABLE_A
  WITH PRIMARY KEY, ROWID
  INCLUDING NEW VALUES;

6. And, the ROWIDs of the base mvs/tables must appear in the select list of an MV based on a join for it to be FAST REFRESHED.

CREATE MATERIALIZED VIEW mv_a_b
AS
SELECT a.ID,
       b.value,
       a.rowid as a_rowid,
       b.rowid as b_rowid
  FROM table_a a,
       table_b b
 WHERE b.ID = a.ID;

7. To support all DML (INSERT, UPDATE and DELETE) for FAST REFRESH you must include SEQUENCE and “INCLUDING NEW VALUES” in the MV log.

 CREATE MATERIALIZED VIEW LOG ON TABLE_A
   WITH SEQUENCE, PRIMARY KEY, ROWID
   INCLUDING NEW VALUES;

8. If you “nest” MVs by defining and MV on top of other MVs you must create a MV LOG on the base MVs.

  CREATE MATERIALIZED VIEW mv_a
  AS
  SELECT a.ID,
         a.attribute1
    FROM table_a a;

 CREATE MATERIALIZED VIEW LOG ON MV_A
   WITH SEQUENCE, PRIMARY KEY, ROWID
   INCLUDING NEW VALUES;

  CREATE MATERIALIZED VIEW mv_b
  AS
  SELECT b.ID,
         b.attribute1
         FROM table_b b;

 CREATE MATERIALIZED VIEW LOG ON MV_B
   WITH SEQUENCE, PRIMARY KEY, ROWID
   INCLUDING NEW VALUES;
   
  CREATE MATERIALIZED VIEW mv_a_b
  AS
  SELECT a.ID,
         a.attribute1,
         b.value,
         a.rowid as a_rowid,
         b.rowid as b_rowid
    FROM mv_a a,
         mv_b b
   WHERE b.ID = a.ID;

9. Sdo_Geometry constructors are not allowed for FAST REFRESH. If you try something like this:

   CREATE MATERIALIZED VIEW mv_a
   BUILD IMMEDIATE REFRESH FAST ON DEMAND
   AS
   SELECT id,
       CASE WHEN a.W_LONG IS NOT NULL
                 AND
                 a.S_LAT IS NOT NULL
                 AND
                 a.E_LONG IS NOT NULL
                 AND
                 a.N_LAT IS NOT NULL
            THEN MDSYS.SDO_GEOMETRY(2003,8311,NULL,
                          MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,3),
                          MDSYS.SDO_ORDINATE_ARRAY(a.W_LONG,a.S_LAT,a.E_LONG,a.N_LAT)) 
            ELSE NULL
        END AS GEOM_MBR
     FROM table_a;

You will get this reported in the MV_CAPABILITIES_TABLE:

“the reason why the capability is disabled has escaped analysis”

10. One can include an SDO_GEOMETRY object in a simple table:

   CREATE MATERIALIZED VIEW mv_a
   AS
   SELECT ID,
          GEOM
     FROM table_a;

BUT you cannot reference it in the where clause:

   CREATE MATERIALIZED VIEW mv_a
   AS
   SELECT a.ID,
          a.attribute1,
          a.GEOM
     FROM table_a a
    WHERE geom IS NOT NULL;

11. Union All MVs

e.g.

   CREATE MATERIALIZED VIEW mv_a_b
   BUILD IMMEDIATE REFRESH FAST ON DEMAND
   AS
   SELECT a.id,
          a.attribute1,
          a.geom
     FROM table_a a
   UNION ALL
   SELECT b.id,
          b.value,
          b.geom
     FROM table_b;

This will not work because: “Each query block in the UNION ALL query must satisfy the requirements of a fast refreshable materialized view with aggregates or a fast refreshable materialized view with joins” because of Note 2 above, the sdo_geomety object doesn’t work with joins thus inclusion of an sdo_geometry in a UNION ALL query won’t work.

The Geom attributes need to be moved to two separate materialized views.<br>

12. Include a Marker:

From Documentation: The SELECT list of each query must include a maintenance column, called a UNION ALL marker. The UNION ALL column must have a distinct constant numeric or string value in each UNION ALL branch. Further, the marker column must appear in the same ordinal position in the SELECT list of each query block.

Hence:

   CREATEMATERIALIZED VIEW mv_a_b
   BUILD IMMEDIATE REFRESH FAST ON DEMAND
   AS
   SELECT id, 
          attribute1,
          'A' AS MARKER
     FROM table_a
   UNION ALL
   SELECT id, 
          attribute2,
          'B' AS MARKER
     FROM table_b;

The MV_CAPABILITIES_TABLE is created via the utlxmv.sql script in $ORACLE_HOME/rdbms/admin

I use it like this:

set linesize 150
column capability_name format a30
column related_text format a25
column msgtxt format a55
DELETE FROM MV_CAPABILITIES_TABLE;
COMMIT;
execute dbms_mview.explain_mview('MV_A');
SELECT capability_name,
       possible,
       related_text,
       msgtxt
  FROM MV_CAPABILITIES_TABLE
 WHERE capability_name not like '%PCT%'
   AND capability_name not like 'PCT%'
   AND capability_name not like '%REWRITE%'
   AND capability_name not like 'REWRITE%'
 ORDER BY seq;

I hope this helps someone.