Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    Tip: Drop that Spatial Index!
    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.

CASE Statements and SDO_GEOMETRY

Friday December 16 2011 at 05:10

Keywordscase statement sdo_geometry comparison

Over the past week I have been having a conversation with a customer around problems with using CASE WHEN THEN ELSE END constructs in SQL for turning WKT into SDO_GEOMETRY objects on INSERT.

Now the customer was doing this sort of comparison for correctly processing WKT data values in an external file into SDO_GEOMETRY and was getting a wrong result forcing him to change the way he inserted the data.

The error he was generating was trying to construct a geometry with a NULL WKT value as follows:

  1. SELECT sdo_util.from_wktgeometry(CAST(NULL AS VARCHAR2(100))) AS geom
  2.   FROM dual;
  3. Error starting at line 260 IN command:
  4. SELECT sdo_util.from_wktgeometry(CAST(NULL AS VARCHAR2(100))) AS geom FROM dual
  5. Error report:
  6. SQL Error: ORA-29532: Java CALL TERMINATED BY uncaught Java exception: java.SQL.SQLException
  7. ORA-06512: at "MDSYS.SDO_UTIL", line 187
  8. 29532. 00000 -  "Java call terminated by uncaught Java exception: %s"
  9. *Cause:    A Java exception OR error was signaled AND could NOT be
  10.            resolved BY the Java code.
  11. *Action:   MODIFY Java code, IF this behavior IS NOT intended.

Now, he thought that he could catch this by doing this:

  1. DECLARE
  2.   v_wkt  VARCHAR2(100) := NULL;
  3.   v_geom sdo_geometry;
  4. BEGIN
  5.   SELECT CASE v_wkt WHEN NULL THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt) END INTO v_geom FROM dual;
  6. END;
  7. /
  8. Error starting at line 253 IN command:
  9. DECLARE
  10.   v_wkt  VARCHAR2(100) := NULL;
  11.   v_geom sdo_geometry;
  12. BEGIN
  13.   SELECT CASE v_wkt WHEN NULL THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt) END INTO v_geom FROM dual;
  14. END;
  15. Error report:
  16. ORA-29532: Java CALL TERMINATED BY uncaught Java exception: java.SQL.SQLException
  17. ORA-06512: at "MDSYS.SDO_UTIL", line 187
  18. ORA-06512: at line 5
  19. 29532. 00000 -  "Java call terminated by uncaught Java exception: %s"
  20. *Cause:    A Java exception OR error was signaled AND could NOT be
  21.            resolved BY the Java code.
  22. *Action:   MODIFY Java code, IF this behavior IS NOT intended.

That is, he thought the case statement would catch the null WKT error but it doesn’t: the same error is being generated. Why is this?

The reason is the way the CASE statement does the comparison when it hits a null value for the variable.

  1. SELECT CASE NULL WHEN NULL THEN 'NULL' ELSE 'NOT NULL' END AS RESULT  FROM DUAL;
  2. RESULT
  3. --------
  4. NOT NULL
  5. -- The above fails because the CASE NULL WHEN NULL is executing a comparison on two NULLs as in the following "null = null" predicate.
  6. SELECT 1 FROM dual AS RESULT WHERE NULL = NULL
  7. UNION ALL
  8. SELECT 2 FROM dual AS RESULT WHERE NULL IS NULL;
  9. RESULT
  10. ------
  11. 2

In other words, you simply can’t compare nulls using an equality operator. The CASE WHEN form actually executes a equals (*) and not an *IS NULL.

There are ways of making this form of CASE statement work and that is by using the NVL function as follows:

  1. SET serveroutput ON
  2. DECLARE
  3.   v_wkt1 VARCHAR2(100) := NULL;
  4.   v_wkt2 VARCHAR2(100) := 'POINT(90 90)';
  5.   v_display SDO_GEOMETRY;
  6. BEGIN
  7.   dbms_output.put_line('select case v_wkt2 when null ... works fine because a comparison with a null never happens....');
  8.   SELECT CASE v_wkt2 WHEN NULL THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt2) END INTO v_display FROM dual;
  9.   dbms_output.put_line('RESULT: ' || SDO_UTIL.TO_WKTGEOMETRY(v_display));
  10.   dbms_output.put_line('case NVL(v_wkt1,''NULL'') when ''NULL'' .... works because, via NVL, we end up comparing two strings rather than two NULLs using incorrect NULL=NULL predicate....');
  11.   SELECT CASE NVL(v_wkt1,'NULL') WHEN 'NULL' THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt1) END INTO v_display FROM dual;
  12.   dbms_output.put_line('RESULT: ' || CASE WHEN v_wkt1 IS NULL THEN 'NULL' ELSE SDO_UTIL.TO_WKTGEOMETRY(v_display) END);  
  13.   dbms_output.put_line('case when v_wkt1 is null then null.... works because this is the proper way to compare nulls ie using NULL IS NULL predicate.');
  14.   SELECT CASE WHEN v_wkt1 IS NULL THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt1) END INTO v_display FROM dual;
  15.   dbms_output.put_line('RESULT: ' || CASE WHEN v_wkt1 IS NULL THEN 'NULL' ELSE SDO_UTIL.TO_WKTGEOMETRY(v_display) END);  
  16.   dbms_output.put_line('case v_wkt1 when null then null.... throws exception even because you can''t compare nulls this way.');
  17.   SELECT CASE v_wkt1 WHEN NULL THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt1) END INTO v_display FROM dual;
  18.   EXCEPTION
  19.      WHEN OTHERS THEN
  20.          dbms_output.put_line('Exception: ' || SQLERRM);
  21. END;
  22. /
  23. anonymous block completed
  24. SELECT CASE v_wkt2 WHEN NULL ... works fine because a comparison WITH a NULL never happens....
  25. RESULT: POINT (90.0 90.0)
  26. CASE NVL(v_wkt1,'NULL') WHEN 'NULL' .... works because, via NVL, we END up comparing two strings rather than two NULLS USING incorrect NULL=NULL predicate....
  27. RESULT: NULL
  28. CASE WHEN v_wkt1 IS NULL THEN NULL.... works because this IS the proper way TO compare NULLS ie USING NULL IS NULL predicate.
  29. RESULT: NULL
  30. CASE v_wkt1 WHEN NULL THEN NULL.... throws exception even because you can't compare nulls this way.
  31. Exception: ORA-29532: Java call terminated by uncaught Java exception: java.sql.SQLException
  32. ORA-06512: at "MDSYS.SDO_UTIL", line 187
*The CASE Statement* The CASE statement is a mix of programming constructs. The first is when you use the following form:
  1. CASE <value>
  2.      WHEN <constant> THEN <result>
  3.      WHEN <constant> THEN <result>
  4.      ...
  5.     ELSE <value>
  6.  END

Here you are using the traditional form of a switch statement as in languages like Java etc.

In this, the switching value can only be an instance of a variable’s possible range of fixed values. So, numbers, strings, booleans and enumeration types are supported.

The second of a CASE statement is in the form of a set of nested IF statements…

  1. IF ( clause ) THEN
  2.   <result>
  3. ELSIF ( clause ) THEN
  4.   <result>
  5. ELSE
  6.   <result>
  7. END IF

That is:

  1. CASE WHEN <variable> <operator> <value> THEN <result>
  2.      WHEN <variable> <operator> <value> THEN <result>
  3.      ...
  4.      ELSE <result>
  5.  END

This is used in the anonymous block above here:

  1. SELECT CASE WHEN v_wkt1 IS NULL THEN NULL ELSE sdo_util.from_wktgeometry(v_wkt1) END INTO v_display FROM dual;

This is always safe for testing if a variable/column etc is NULL.

Comparing SDO_GEOMETRY Objects

This leads to a discussion about how to use Oracle OBJECTs like SDO_GEOMETRY in CASE statements. Can it be done? Well, yes it can if the TYPE declares a comparison operation called an ORDER MEMBER FUNCTION. SDO_GEOMETRY does not declare such a comparison operator as part of its type so one must use other methods (see later).

But, if it did have one how would it work?

As an exercise in creating a type I created the MBR type as part of my packages many years ago. As part of the type I declared and implemented an order member function as follows

  1. CREATE OR REPLACE TYPE MBR AS OBJECT (
  2.    MinX  NUMBER,
  3.    MinY  NUMBER,
  4.    MaxX  NUMBER,
  5.    MaxY  NUMBER,
  6.    -- ================== Constructors
  7.    --
  8.    Constructor FUNCTION MBR
  9.                RETURN SELF AS RESULT,
  10.    Constructor FUNCTION MBR(            p_geometry  IN MDSYS.SDO_GEOMETRY,
  11.                                         p_tolerance IN NUMBER )
  12.                RETURN SELF AS RESULT,
  13.    Constructor FUNCTION MBR(            p_MBR IN MBR )
  14.                RETURN SELF AS RESULT,
  15. ....
  16.   ORDER Member FUNCTION Evaluate(p_other IN MBR)
  17.                RETURN PLS_Integer
  18. );
  19. -- The Order Member Function Evaluate is declared in the Type body as....
  20. --
  21. CREATE OR REPLACE TYPE BODY MBR
  22. AS
  23. .....
  24.   -- @function  : Evaluate
  25.   -- @version   : 1.0
  26.   -- @precis    : Returns value that can be used to company two MBRs in an expression of type MBR < MBR
  27.   -- @return    : Computed number.
  28.   -- @returntype: Number
  29.   -- @history   : SGG August 2006 - Original Coding
  30.   --
  31.   ORDER Member FUNCTION Evaluate(p_other IN MBR)
  32.                RETURN PLS_Integer
  33.   IS
  34.   BEGIN
  35.     IF (MinX < p_other.MinX) THEN
  36.       IF (MinY <= p_other.MinY) THEN
  37.          RETURN -1;
  38.       ElsIf (MinY = p_other.MinY) THEN
  39.          RETURN -1;
  40.       END IF;
  41.     ElsIf (MinX = p_other.MinX) THEN
  42.       IF (MinY < p_other.MinY) THEN
  43.          RETURN -1;
  44.       ElsIf (MinY = p_other.MinY) THEN
  45.          RETURN 0;
  46.       END IF;
  47.     ELSE
  48.       RETURN 1;
  49.     END IF;
  50.   END Evaluate;
  51. END MBR;
  52. /

Now you can implement any sort of processing in this method to compare the two MBRs – I have done it to return -1,0,1.

Now we can use the Evaluate method as follows:

  1. SELECT           MBR(337900, 5429000, 338900, 5430000).Evaluate(MBR(337950, 5429050, 338950, 5430500)) AS mbrvalue,
  2.        CASE WHEN MBR(337900, 5429000, 338900, 5430000).Evaluate(MBR(337950, 5429050, 338950, 5430500)) = 0
  3.             THEN 'EQUALS'
  4.             ELSE 'UNEQUAL'
  5.         END AS testMBR
  6.  FROM DUAL;
  7. MBRVALUE               TESTMBR
  8. ---------------------- -------
  9. -1                     UNEQUAL
  10. .
  11. SELECT 'TRUE' AS RESULT
  12.   FROM dual
  13.  WHERE MBR(337900, 5429000, 338900, 5430000) = MBR(337950, 5429050, 338950, 5430500);
  14. RESULT
  15. ------
  16. .
  17. SELECT           MBR(337900, 5429000, 338900, 5430000).Evaluate(MBR(337900, 5429000, 338900, 5430000)) AS mbrvalue,
  18.        CASE WHEN MBR(337900, 5429000, 338900, 5430000).Evaluate(MBR(337900, 5429000, 338900, 5430000)) = 0
  19.             THEN 'EQUALS'
  20.             ELSE 'UNEQUAL'
  21.         END AS testMBR
  22.  FROM DUAL;
  23. MBRVALUE               TESTMBR
  24. ---------------------- -------
  25. 0                      EQUALS  
  26. .
  27. -- But you can even do this!
  28. SELECT CASE MBR(337900, 5429000, 338900, 5430000)
  29.             WHEN MBR(337900, 5429000, 338900, 5430000)
  30.             THEN 'EQUALS'
  31.             ELSE 'UNEQUAL'
  32.         END AS testMBR
  33.  FROM DUAL;
  34. TESTMBR
  35. -------
  36. EQUALS  
  37. .
  38. SELECT 'TRUE' AS RESULT
  39.   FROM dual
  40.  WHERE MBR(337900, 5429000, 338900, 5430000) = MBR(337900, 5429000, 338900, 5430000);
  41. RESULT
  42. ------
  43. TRUE  

Now that is super cool!

However, Oracle did not implement any ORDER MEMBER function for SDO_GEOMETRY so you can’t do this:

  1. SELECT CASE sdo_geometry('POINT(90 90)', 4326)
  2.             WHEN sdo_geometry('POINT(90 90)',4326)
  3.             THEN 'EQUALS'
  4.             ELSE 'UNEQUAL'
  5.         END AS geomCompare
  6.   FROM dual;
  7. .
  8. Error starting at line 290 IN command:
  9. SELECT CASE sdo_geometry('POINT(90 90)', 4326)
  10.             WHEN sdo_geometry('POINT(90 90)',4326)
  11.             THEN 'EQUALS'
  12.             ELSE 'UNEQUAL'
  13.         END AS geomCompare
  14.   FROM dual
  15. Error at Command Line:290 COLUMN:12
  16. Error report:
  17. SQL Error: ORA-22901: cannot compare VARRAY OR LOB attributes OF an object TYPE
  18. 22901. 00000 -  "cannot compare nested table or VARRAY or LOB attributes of an object type"
  19. *Cause:    Comparison OF nested TABLE OR VARRAY OR LOB attributes OF an
  20.            object TYPE was attempted IN the absence OF a MAP OR ORDER
  21.            method.
  22. *Action:   define a MAP OR ORDER method FOR the object TYPE.
  23. .
  24. -- Nor can you do this
  25. --
  26. SELECT CASE WHEN sdo_geometry('POINT(90 90)', 4326) = sdo_geometry('POINT(90 90)',4326)
  27.             THEN 'EQUALS'
  28.             ELSE 'UNEQUAL'
  29.         END AS geomCompare
  30.   FROM dual;
  31. .
  32. Error starting at line 297 IN command:
  33. SELECT CASE WHEN sdo_geometry('POINT(90 90)', 4326) = sdo_geometry('POINT(90 90)',4326)
  34.             THEN 'EQUALS'
  35.             ELSE 'UNEQUAL'
  36.         END AS geomCompare
  37.   FROM dual
  38. Error at Command Line:297 COLUMN:17
  39. Error report:
  40. SQL Error: ORA-22901: cannot compare VARRAY OR LOB attributes OF an object TYPE
  41. 22901. 00000 -  "cannot compare nested table or VARRAY or LOB attributes of an object type"
  42. *Cause:    Comparison OF nested TABLE OR VARRAY OR LOB attributes OF an
  43.            object TYPE was attempted IN the absence OF a MAP OR ORDER
  44.            method.
  45. *Action:   define a MAP OR ORDER method FOR the object TYPE.

To compare two geometries one must convert them to WKT CLOBs or use the SDO_GEOM.RELATE function (Spatial only – or see my JTS replacement).

  1. SELECT CASE sdo_geom.relate(sdo_geometry('POINT(90 90)',4326),'EQUAL',sdo_geometry('POINT(90 90)',4326),0.05)
  2.             WHEN 'FALSE' THEN 'UNEQUAL'
  3.             WHEN 'EQUAL' THEN 'EQUAL'
  4.             ELSE sdo_geom.relate(sdo_geometry('POINT(90 90)',4326),'EQUAL',sdo_geometry('POINT(90 90)',4326),0.05)
  5.         END AS geoCompare
  6.   FROM dual;
  7. .
  8. GEOCOMPARE
  9. ----------
  10. EQUAL
I hope this is of interest to someone out there.

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