Top 5 Recent Articles
ARTICLES CATEGORIES
- Algorithms (22)
- All (399)
- Biography (1)
- Blog (44)
- Business Requirements (1)
- Commentary (1)
- Conversion (2)
- Customers (2)
- Data Models (1)
- Education (2)
- GeoRaptor (13)
- GPS (1)
- Image Processing (2)
- Import Export (8)
- Licensing (2)
- LiDAR (1)
- Linear Referencing (4)
- Manifold GIS (3)
- Mapping (1)
- MySQL Spatial (7)
- Networking and Routing (including Optimization) (5)
- Open Source (18)
- Oracle Spatial and Locator (194)
- Partitioning (1)
- PostGIS (36)
- Projections (1)
- Published Articles (1)
- qGIS (1)
- Recommendations (1)
- Services (1)
- Software Change Log (1)
- Source Code (37)
- Space Curves (9)
- Spatial Database Functions (109)
- Spatial DB comparison (1)
- Spatial XML Processing (11)
- SQL Server Spatial (92)
- Standards (3)
- Stored Procedure (17)
- Tessellation or Gridding (10)
- Tools (2)
- Topological Relationships (1)
- Training (2)
- Triangulation (2)
Handy way of systematically fixing polygon geometries with 13349 and other errors
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?
Documentation
- MySQL Spatial General Functions
- Oracle LRS Objects
- Oracle Spatial Exporter (Java + pl/SQL)
- Oracle Spatial Object Functions
- Oracle Spatial Object Functions (Multi Page)
- PostGIS pl/pgSQL Functions
- SC4O Oracle Java Topology Suite (Java + pl/SQL)
- SQL Server Spatial General TSQL Functions
- SQL Server Spatial LRS TSQL Functions