Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    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.

Handy way of systematically fixing polygon geometries with 13349 and other errors

Thursday September 01 2011 at 09:28

One often processes sdo_geometry data looking for errors with SQL we get errors in the SQL that stop us seeing what the result is.

select count(*)
  from oracle_test_geometries a
where a.geometry is not null;
 
COUNT(*)
------------
70
 
select substr(sdo_geom.validate_geometry(a.geometry,0.005),1,10) as errCode
  from oracle_test_geometries a
  where a.geometry is not null
 group by substr(sdo_geom.validate_geometry(A.geometry,0.005),1,10);
 
Error starting at line 1 in command:
select substr(sdo_geom.validate_geometry(a.geometry,0.005),1,10) as errCode
  from oracle_test_geometries a
 group by substr(sdo_geom.validate_geometry(A.geometry,0.005),1,10)
Error report:
SQL Error: ORA-06502: PL/SQL: numeric or value error
ORA-06512: at "MDSYS.SDO_GEOM", line 125
ORA-06512: at "MDSYS.SDO_GEOM", line 460
06502. 00000 -  "PL/SQL: numeric or value error%s"
*Cause:    
*Action:

So, how do we find out what is in error? The following bit of anonymous PL/SQL is helpful in this situation.

set serveroutput on size unlimited
DECLARE
   v_err varchar2(10);
BEGIN
   FOR rec IN (SELECT id, geometry FROM ORACLE_TEST_GEOMETRIES) loop
   BEGIN
      v_err := substr(SDO_GEOM.VALIDATE_GEOMETRY(rec.geometry,0.5),1,10); 
      If ( v_err <> 'TRUE' ) Then
        dbms_output.put_line('Geometry with ID - ' || rec.id || ' - validate result is ' || v_err );
      End If;
      EXCEPTION 
         WHEN OTHERS THEN
            dbms_output.put_line('Geometry with ID - ' || rec.id || ' - failed to validate with ' || SQLCODE );
   END;
   END LOOP;
END;
/
 
anonymous block completed
Geometry with ID - 204 - validate result is 13350
Geometry with ID - 205 - validate result is 13356
Geometry with ID - 28 - validate result is 13366
Geometry with ID - 141 - validate result is 13356
Geometry with ID - 25 - validate result is 13351
Geometry with ID - 29 - validate result is 13349
Geometry with ID - 30 - validate result is 13349
Geometry with ID - 37 - validate result is 13341
Geometry with ID - 45 - validate result is NULL
Geometry with ID - 46 - validate result is 13028
Geometry with ID - 47 - validate result is 13356
Geometry with ID - 48 - validate result is 13356
Geometry with ID - 49 - validate result is 13356
Geometry with ID - 50 - validate result is 13351
Geometry with ID - 51 - validate result is 13351
Geometry with ID - 52 - validate result is 13351
Geometry with ID - 53 - failed to validate with -6502
Geometry with ID - 54 - validate result is 13028
Geometry with ID - 55 - validate result is 13028
Geometry with ID - 56 - validate result is 13031
Geometry with ID - 57 - validate result is 13032
Geometry with ID - 58 - validate result is 13033
Geometry with ID - 59 - validate result is 13034
Geometry with ID - 61 - validate result is 13371
Geometry with ID - 62 - validate result is 13354
Geometry with ID - 63 - validate result is 13341
Geometry with ID - 64 - validate result is 13342
Geometry with ID - 65 - validate result is 13343
Geometry with ID - 66 - validate result is 13348
Geometry with ID - 67 - validate result is 13346
Geometry with ID - 201 - validate result is 13356
Geometry with ID - 202 - validate result is 13348
Geometry with ID - 203 - validate result is 13366

Note the line:

Geometry with ID – 53 – failed to validate with -6502

The geometry associated with it is:

select geometry
  from oracle_test_geometries a
where a.id = 53;
 
GEOMETRY 
-------------
MDSYS.SDO_GEOMETRY(NULL,NULL,NULL,NULL,NULL)

Which, patently, blows up validate_geometry(), though it shouldn’t. Because this geometry stopped the original SQL SELECT statement, we must exclude it if our non-PL/SQL SELECT statements are to succeed. One can do so by nominating the id as above:

where a.id = 53

Or one could do this:

where a.geometry is not null
  and a.geometry.sdo_gtype is not null;

Now, what if we tried to fix all the geometries in one non PL/SQL based UPDATE statement:

update oracle_test_geometries a
   set a.geometry = sdo_util.rectify_geometry(a.geometry,0.005)
where a.geometry is not null
  and a.geometry.sdo_gtype is not null;
 
Error starting at line 1 in command:
update oracle_test_geometries a
   set a.geometry = sdo_util.rectify_geometry(a.geometry,0.005)
where a.geometry is not null
  and a.geometry.sdo_gtype is not null
Error report:
SQL Error: ORA-13199: the given geometry cannot be rectified
ORA-06512: at "MDSYS.MD", line 1723
ORA-06512: at "MDSYS.MDERR", line 17
ORA-06512: at "MDSYS.SDO_UTIL", line 716
13199. 00000 -  "%s"
*Cause:    This is an internal error.
*Action:   Contact Oracle Support Services.

Is it really that bad (ie contact Oracle Support Services)? Maybe. But before you do you need to know which of the many geometries in the table caused:

SQL Error: ORA-13199: the given geometry cannot be rectified

OK, we can fix many of the errors by constructing PL/SQL targeted at fixing specific errors. What follows can be used to fix 13349 (bow-tie in outer boundary of polygon) and 13356 (duplicate vertices):

set serveroutput on size unlimited
DECLARE
  v_id oracle_test_geometries.id%type;
  CURSOR c_geometries_to_fix Is
    select id
      from oracle_test_geometries a
     where a.geometry is not null
       and a.geometry.sdo_gtype is not null
       and SDO_GEOM.VALIDATE_GEOMETRY(a.geometry,0.5) IN ('13349','13356')
     for update of geometry;
BEGIN
   OPEN c_geometries_to_fix;
   LOOP
      FETCH c_geometries_to_fix INTO v_id;
      EXIT WHEN c_geometries_to_fix%NOTFOUND;
      BEGIN
         UPDATE oracle_test_geometries a
            SET a.geometry = sdo_util.rectify_geometry(a.geometry,0.005)
          WHERE CURRENT OF c_geometries_to_fix;
         dbms_output.put_line('RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id ' || v_id);
         EXCEPTION
           WHEN OTHERS THEN
              BEGIN
                  UPDATE oracle_test_geometries a
                     SET a.geometry = sdo_geom.sdo_union(a.geometry,a.geometry,0.005)
                   WHERE CURRENT OF c_geometries_to_fix;
                  dbms_output.put_line('SDO_UNION was successful for oracle_test_geometries geometry with id ' || v_id);
                  EXCEPTION
                    WHEN OTHERS THEN
                         dbms_output.put_line('Could not rectify oracle_test_geometries geometry with id ' || v_id);
              END;
      END;
   END LOOP;
   CLOSE c_geometries_to_fix;
   COMMIT;
END;
/
show errors
 
anonymous block completed
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 29
SDO_UNION was successful for oracle_test_geometries geometry with id 30
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 47
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 48
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 49
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 141
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 201
RECTIFY_GEOMETRY was successful for oracle_test_geometries geometry with id 205

NOTE: You have to have Spatial to execute the SDO_UNION unless you use the one in my GEOPROCESS package.

Of course, what is needed are a set of functions/techniques for fixing other errors,

My TOOLS package includes procedures that can be used to check daily updates and attempt to fix them:

   /*** function    GeometryCheck
   **   description Procedure that processes the supplied object looking
   **                for errors and correcting where possible.
   **                Writes activity to FEATURE_ERRORS table.
   **   param       p_schema      The owner of the table/geometry column data.
   **   param       p_tableName   The table holding the geometry data to be checked.
   **   param       p_ColumnName  The sdo_geometry column in the table to be checked.
   **   param       p_whereClause A predicate to limit the activity to specific rows.
   **/
   Procedure GeometryCheck( p_schema        IN VarChar2,
                            p_tableName     IN VarChar2,
                            p_ColumnName    IN VarChar2,
                            p_whereClause   IN VarChar2);

I hope this is helpful to someone.

Comments?

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 [5]

I’ve never understood why rectify_geometry doesnt do ‘what it says on the tin’ for all spatial errors.

I’ve been fixing the various errors i’ve come across by running sdo_union inside rectify_geometry – not sure whether this is smart or stupid.

— Thomas · 1 September 2011, 11:23 · #

Thomas,

I concur about rectify_geometry given the documentation does say:

This function checks for the following problems that can make a geometry invalid, and fixes the problems in the returned geometry:

  • Duplicate vertices
  • Polygon boundary intersecting itself (which is why SDO_UNION should not be needed)
  • Incorrect orientation of exterior or interior rings (or both) of a polygon

If the input geometry has any other problem that makes it invalid, the function raises an exception.

The only problem of putting one function inside the other is that if the inside one fails then the whole collection fails.

So, one should not put rectify_geometry inside sdo_union because it just may fail as shown above.

Also, for those out there who are non-Spatial users, my GEOPROCESS.GeoUnion function could be substituted for sdo_union.

regards
Simon

Simon Greener · 1 September 2011, 23:33 · #

How to know the bad geometries in a POLYGON Spatial feature table of count 5000000

— venu · 20 December 2011, 06:09 · #

You could do this:

select mdsys.sdo_geom.validate_geometry(a.<your sdo_geometry colummn name>,0.005) as valid_code,
count(*)
from <Your Table> a
group by mdsys.sdo_geom.validate_geometry(a.<your sdo_geometry colummn name>,0.005);

regards
Simon

Simon Greener · 20 December 2011, 06:50 · #

Simon,

A useful addition to your GeometryCheck procedure would be to include a parameter for a size delta. In other words, if the area or length is within 0.5% of the original, make the change. Otherwise, leave it alone for a carbon based unit to review.

Bryan

— Bryan Hall · 11 January 2013, 19:06 · #