Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    Convert Single Geometry to Multi-part Geometry in Oracle Spatial
    Optimized Rectangle to 5 Point Polygon
    Centroid Package now supports Y ordinate seeding
    Convert GeoJSON document to Sdo_Geometry objects
    Implementation Of Travelling Salesman Problem
    Create Polygon From Bearings And Distances
    Function That Returns a Compass Point From a Whole Circle Bearing
    Playing around with Centroids by using different seed values
    GeoRaptor 4.x Update 2
    Simple Oracle C Sprintf or Java String.format
    Some Oriented Point Functions
    Extracting Inner Rings Changed Ordinate Ordering: A Trap For Players Who Don't Read Documentation!
    PLS-00306: wrong number or types of arguments in call to 'SDO_GEOMETRY'
    Converting Google Earth Formatted Longitude/Latitude points to decimal degrees
    Oracle Business Intelligence Warehousing and Analytics - Spatial Summit
    How far inside, is inside? Measuring actual distance.
    Noding and building a polygon from single, overlapping linestrings
    Analyzing Spatial Query Performance Improvements in Oracle Spatial and Graph 12c Through Cross-Vendor Comparison
    ST_VertexN / ST_PointN - Extracting a specific point from any geometry
    Convert Single Point stored in SDO_ORDINATES to SDO_POINT_TYPE
    Aggregate APPEND Islands and XOR polygons
    Circular Arcs in Geodetic Polygons
    Some SDO_GEOMETRY/DIMINFO handling functions
    Applying And Extending Oracle Spatial - Book Released
    Changing all DIMINFO sdo_tolerance values for all metadata records in one go.
    Building Polygons from Incomplete Linestrings using ST_PolygonBuilder
    Computing Cardinal Directions to nearby geometries
    Intersecting two aggregated polygon layers with SC4O
    Spatial and Oracle 12c
    Update Triggers and SDO_GEOMETRY Equality
    Duplicate Geometry data and Data Models
    CENTROID package update
    How to calculate cumulative length of a linestring
    Useful Package of Wrapper Functions for Sdo_Util.AffineTransforms
    Compute Location from known Lat/Long point using delta easting and northing in miles
    SDO_AGGR_SET_UNION
    Sorting SDO_GEOMETRY data using the ORDER BY clause of a SELECT statement
    Creating linestrings from points
    Rounding Coordinates or Ordinates in SDO_GEOMETRY
    Effects of Sdo_Geometry Ordinate Precision on Performance
    Effects of Sdo_Geometry Ordinate Precision on Storage
    The Spatial filtering of geometries: The effect of tolerances on relationships
    Application of Delaunay Triangulation and Inverse Distance Weighting (IDW) in Oracle for Soils Interpolation
    Selecting all SDO_GTYPE values for all tables/sdo_geometry columns in a schema
    CENTROID package - Tips for Use
    Announcing the Spatial Companion For Oracle (SC4O)
    Filtering Rings (Oracle Spatial)
    Splitting a polygon using one or more linestrings
    isValid, isSimple, Dimension and CoordDim methods for SDO_Geometry
    Line Merging or Collecting lines together: ST_LineMerger
    ST_DeleteVertex for Oracle SDO_Geometry based on Jaspa/JTS
    3D/4D and SRID aware Conversion functions for SDO_Geometry: WKT and EWKT
    Topological vs Non-Topological Simplification/Generalization of Aggregated Area Geometies in Oracle
    Filtering very short linestrings via bitmap function index
    CENTROID For Oracle
    Gridding a sdo_geometry line/polygon object (Oracle)
    Finding centre and radius of a circular geometry
    Constraining geometry type for sdo_geometry column in a table.
    CASE Statements and SDO_GEOMETRY
    The Power of Constraints and Indexes for Spatial Constraints: stopping duplicate points
    Replacement for SDO_GEOM.RELATE - ST_Relate based on JTS
    Changing Oracle Spatial Index Parameters on existing index
    Writing Excel Spreadsheets files from within the Oracle database using Java and PL/SQL
    Writing xSV (eg csv) files from within the Oracle database using Java and PL/SQL
    A simple spike finder for Spatial/Locator
    JTS Java class compilation for 11g and above
    Random Spatial Search Procedure
    Geometry Snapping using JTS in Oracle
    Exposing JTS's MinimumBoundingCircle functionality
    Exposing JTS's Densifier functionality
    Using JTS's Comparison Functions - HausdorffSimilarityMeasure & AreaSimilarityMeasure with SDO_GEOMETRY
    Free JTS-based Area/Length Functions
    Handy way of systematically fixing polygon geometries with 13349 and other errors
    Standalone CENTROID package now available for download
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 4 Processing Geodetic data
    Configurable Buffer: JTS and Oracle
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 3
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 2
    Free Union, Intersection, Xor and Difference Functions for Oracle Locator - Part 1
    Building Lines into Polygons in Oracle Locator / Spatial
    Finding Intersection Points between Line and Polygon
    SDO2GeoJSON
    Free version of sdo_length
    Alternative to my SQL based GetNumRings function
    External Tables and SDO_Geometry data.
    layer_gtype keyword issue when indexing linear data on 11g
    String Tokenizer for Oracle
    Free Aggregate Method for Concatenating 2D Lines in Oracle Locator 10g
    Reducing 5 Vertex Polygon to Optimized Rectangle
    Square Buffer
    Converting decimal seconds to string
    SDO_GEOM.VALIDATE_GEOMETRY_WITH_CONTEXT - 13356 Issues
    Valid conversion unit values for Oracle sdo_geom.sdo_length()
    Removing Steps in Gridded Vector Data - SmoothGrid for Oracle
    Oracle Spatial DISJOINT search/filtering
    Creating SDO_Geometry from geometric data recorded in the columns of a table
    Concave Hull Geometries in Oracle 11gR2
    Projecting SDO_GEOM_METADATA DIMINFO XY ordinates
    Instantiating MDSYS.VERTEX_TYPE
    New PL/SQL Packages - Rotate oriented point
    GeoRaptor Development Team
    Fast Refreshing Materialized View Containing SDO_GEOMETRY and SDO_GEOM.SDO_AREA function
    Performance of PL/SQL Functions using SQL vs Pure Code
    Implementing the BEST VicGrid Projection in Oracle 10gR2
    Making Sdo Geometry Metadata Update Generic Code
    ORA-13011 errors when using SDO_GEOM.VALIDATE_LAYER_WITH_CONTEXT()
    Extract Polygons from Compound Polygon
    Detecting sdo_geometries with compound (3-point Arcs) segments
    GEOMETRY_COLUMNS for Oracle Spatial
    Convert GML to SDO_Geometry in Oracle 10gR2
    Spatial Sorting of Data via Morton Key
    Swapping Ordinates in an SDO_GEOMETRY object
    New To_3D Function
    Extend (Reduce/Contract/Skrink) Function for Oracle
    Loading and Processing GPX 1.1 files using Oracle XMLDB
    Loading Spatial Data from an external CSV file in Oracle
    Calling the Oracle Spatial shapefile loader from within the Oracle database itself
    Implementing SDO_VertexUpdate/ST_VertexUpdate for Oracle
    Implementing SDO_RemovePoint/ST_RemovePoint for Oracle
    Implementing SDO_AddPoint/ST_AddPoint for Oracle
    ESRI ArcSDE Exverted and Inverted Polygons and Oracle Spatial
    Funky Fix Ordinates By Formula
    Implementing a SetPoint/ST_SetPoint function in Oracle
    Implementing an ST_SnapToGrid (PostGIS) function for Oracle Spatial
    Generating random point data
    Implementing an Affine/ST_Affine function for Oracle Spatial
    Implementing a Scale/ST_Scale function for Oracle Spatial
    Implementing a Parallel/ST_Parallel function for linestring data for Oracle Spatial
    Implementing a Rotate/ST_Rotate function for Oracle Spatial
    Limiting table list returned when connecting to Oracle Database using ODBC
    ST_Azimuth for Oracle: AKA Cogo.Bearing
    Implementing a Translate/ST_Translate/Move function for Oracle Spatial
    Elem_Info_Array Processing: An alternative to SDO_UTIL.GetNumRings and querying SDO_ELEM_INFO itself
    Minumum Bounding Rectangle (MBR) Object Type for Oracle
    How to extract elements from the result of an sdo_intersection of two polygons.
    How to restart a database after failed parameter change
    Fixing failed spatial indexes after import using data pump
    generate_series: an Oracle implementation in light of SQL Design Patterns
    Multi-Centroid Shootout
    Oracle Spatial Centroid Shootout
    On the use of ROLLUP in Oracle SELECT statements
    Surrounding Parcels
    Spatial Pipelining
    Using Oracle's SDO_NN Operator - Some examples
    Converting distances and units of measure in Oracle Locator
    Split Sdo_Geometry Linestring at a known point
    Forcing an Sdo_Geometry object to contain only points, lines or areas
    Unpacking USER_SDO_GEOM_METADATA's DIMINFO structure using SQL
    Generating multi-points from single point records in Oracle Spatial
    Object Tables of Sdo_Geometry
    Oracle Locator vs Oracle Spatial: A Reflection on Oracle Licensing of the SDO_GEOM Package
    FAST REFRESHing of Oracle Materialized Views containing Sdo_Geometry columns
    Australian MGA/AMG Zone Calculation from geographic (longitude/latitude) data
    Loading Shapefiles (SHP) into Oracle Spatial
    Oracle Spatial Mapping and Map Rendering Performance Tips
    The significance of sdo_lb/sdo_ub in USER_SDO_GEOM_METDATA: Do I need it?
    Oracle Spatial Forum - Melbourne April 2007
    Layer_GTypes for spatial indexes
    Oracle's SQL/MM Compliant Types
    Tips and Tricks

Search

    Browse

RSS / Atom

Email me

textpattern

Creative Commons License
All Blog Articles, Data Models and Free Source Code by Simon Greener, The SpatialDB Advisor is licensed under a Creative Commons Attribution-ShareAlike 3.0 Unported License.

FAST REFRESHing of Oracle Materialized Views containing Sdo_Geometry columns

Tuesday July 10 2007 at 09:39

Folks,

I will edit this over the next few weeks but I have been doing quite a bit of work on FAST REFRESHing of materialized views based on tables with SDO_Geometries.

After much trial and error I have worked out how to get FAST REFRESHing of materialized views that contain Sdo_geometry columns. I will publish actual examples but here are a bunch of points that cover off what I have learned.

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.

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:
    CREATE MATERIALIZED 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;

Keep posted...

regards
Simon

Creative Commons License

post this at del.icio.uspost this at Diggpost this at Technoratipost this at Redditpost this at Farkpost this at Yahoo! my webpost this at Windows Livepost this at Google Bookmarkspost this to Twitter

Comment [7]

Thanks very much for your explanations here. They’ve cleared up a couple of issues I had. I’m still a little stuck with creating an ON COMMIT materialized view though. If you have a moment, I’ve posted the question to the Oracle forums:
http://forums.oracle.com/forums/message.jspa?messageID=4153379#4153379.
Thanks again for this entry.

— Sven · 10 March 2010, 23:36 · #

Sven,

I answered your query on the OTN article as well as via a new article on my website, by created a worked example based on your particular issue.

regards
Simon

Simon · 14 March 2010, 04:33 · #

Simon,
When I added ROWID and Primary Key, my MV blew up with an ORA-12015. It indicates ROWID and Primary Keys are not supported in complex queries. Any thoughts?

— John · 5 November 2010, 22:01 · #

John,

ORA-12015 just means that Oracle has determined that the MV is complex. What that complex is I don’t know. But it is likely it will not be related to having the ROWID and primary key in the MV. Though I could be wrong.

Your best tool (besides the documentation) is to use the MV_CAPABILITIES_TABLE and let it tell you what the problem is. Then slowly modify aspects of the MV until fast refresh appears.

But note, sometimes it is not possible because of the complexity of the query esp when using aggregates.

regards
Simon

Simon Greener · 8 November 2010, 05:01 · #

I just wanted so say thank you for all your efforts. I find this to be very helpful.

— Gerald Dildine · 7 February 2014, 17:15 · #

Gerald and others,

This article formed the basis of the chapter about replication in a book Dr Siva Ravada and I published in September 2013. The book is called “Applying and Extending Oracle Spatial” and is available from PACKT publishing.

regards
SImon

— Simon Greener · 8 February 2014, 01:01 · #

Hello Simon

Bit of a long shot as this is an old post but I am trying to create an MV on a table which as an SDO_GEOMETRY type column.
This has worked fine in a basic setup but, due to the size of the live data, I have tried to use an import and create the MV on a prebuilt table.
Oracle errors with
ORA-32304: materialized views with user-defined types cannot use prebuilt table

And it remains until I ‘remove’ the SDO_GEOMETRY table from the MV SELECT clause.
Unfortunately, I am unable to find any restrictions in the Oracle Docs and wondered if you had come across this before.
I am on Oracle 11.2.0.3
Cheers for any help you can offer
Al

— Allan Bews · 4 March 2016, 22:08 · #