Go to content Go to navigation and search

Home

Current Oracle Spatial Blog Articles

    GeoRaptor 4.x Update 2 (Project has Stalled)
    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
    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.

Update Triggers and SDO_GEOMETRY Equality

Monday November 12 2012 at 03:08

KeywordsSDO_GEOM.RELATE SDO_GEOMETRY equals trigger before update oracle
Summary

This article shows how to test for changes in an Sdo_Geometry column value via a Before Update trigger. A Spatial function Sdo_Geom.Relate is used and alternatives suggested for Locator users.

It is not uncommon to want to construct BEFORE INSERT row level triggers that detect and process changes to SDO_GEOMETRY columns and assign other column values. However, the rules that govern the comparison of objects such as numbers, dates, strings etc do not apply to complex objects such as SDO_GEOMETRY. As such, to correctly detect changes to such objects one must have recourse to different techniques.

This blog articles offers a few examples of what can be done and needs to be done.

This article is based on the problem outlined in this Oracle Spatial forum thread to which I responded.

The problem that we need to solve is set the GEOM_MOD_DATE column with a value only when a change to the GEOM SDO_GEOMETRY column is detected by the trigger. The processing is to be done via a trigger so that we get a single, consistent, approach to detecting changed data from multiple client (vendor) software processing.

The table we shall process is the following:

  1. DROP TABLE oper_zone_valve;
  2. --
  3. CREATE TABLE oper_valve
  4. (
  5.   oper_valve_id     NUMBER (38),
  6.   valve_number      VARCHAR2 (8 BYTE),
  7.   valve_size        VARCHAR2 (4 BYTE),
  8.   geom_mod_date     DATE,
  9.   geom              MDSYS.sdo_geometry
  10. );

Comparing SDO_GEOMETRY objects

The SDO_GEOMETRY object does not have a ORDER MEMBER method that compares two SDO_GEOMETRY objects. However, if you have a Spatial license, you do have recourse to the SDO_GEOM.RELATE function. Using this we can construct a BEFORE UPDATE function as follows:

  1. CREATE OR REPLACE TRIGGER oper_valve_geom_but
  2. BEFORE UPDATE OF geom
  3. ON oper_valve
  4. REFERENCING NEW AS NEW OLD AS OLD
  5. FOR EACH ROW
  6. BEGIN
  7.    -- If not updates have been detected against the GEOM column, short-circuit the test
  8.    IF ( NOT UPDATING('GEOM') ) THEN
  9.     RETURN;
  10.   END IF;
  11.   -- Only need to compare actual geom data if both are not null.
  12.   IF ( :OLD.geom IS NOT NULL AND :NEW.geom IS NOT NULL ) THEN
  13.     -- Check if geometry has changed internally
  14.      IF ( sdo_geom.relate(:OLD.geom,'DETERMINE',:NEW.geom,0.005) != 'EQUAL' ) THEN
  15.        :NEW.geom_mod_date := SYSDATE;
  16.      END IF;
  17.   ELSIF ( ( :OLD.geom IS NULL AND :NEW.geom IS NOT NULL ) OR
  18.        ( :OLD.geom IS NOT NULL AND :NEW.geom IS NULL ) ) THEN
  19.      :NEW.geom_mod_date := SYSDATE;
  20.   ELSE
  21.     -- NULL obviously does not equal NOT NULL!
  22.     :NEW.geom_mod_date := NULL;
  23.   END IF;
  24. END;
  25. /
  26. SHOW ERRORS

Now, we can test this.

  1. SET NULL NULL
  2. SET serveroutput ON SIZE unlimited
  3. --.
  4. INSERT INTO oper_valve (oper_valve_id,geom) VALUES (1, MDSYS.sdo_geometry(2001,NULL,SDO_POINT_TYPE(0,0,0), NULL,NULL));
  5. --.
  6. 1 ROWS inserted.
  7. --.
  8. COMMIT;
  9. --.
  10. commited.
  11. --.
  12. SELECT oper_valve_id, to_char(geom_mod_date,'YYYY-MM-DD HH24:MI:SS') AS geom_mod_date, geom
  13.   FROM oper_valve;
  14. OPER_VALVE_ID GEOM_MOD_DATE       GEOM
  15. ------------- ------------------- --------------------------------------------------------------------
  16.             1 NULL                MDSYS.SDO_GEOMETRY(2001,NULL,MDSYS.SDO_POINT_TYPE(0,0,0),NULL,NULL)
  17. --.
  18. UPDATE oper_valve
  19.    SET geom = sdo_geometry(2001, NULL,SDO_POINT_TYPE(0,0,0),NULL,NULL) WHERE oper_valve_id = 1;
  20. --.
  21. 1 ROWS updated.
  22. --.
  23. COMMIT;
  24. --.
  25. commited.
  26. --.
  27. SELECT oper_valve_id, to_char(geom_mod_date,'YYYY-MM-DD HH24:MI:SS') AS geom_mod_date, geom
  28.   FROM oper_valve;
  29. --.
  30. OPER_VALVE_ID GEOM_MOD_DATE       GEOM
  31. ------------- ------------------- --------------------------------------------------------------------
  32.             1 NULL                MDSYS.SDO_GEOMETRY(2001,NULL,MDSYS.SDO_POINT_TYPE(0,0,0),NULL,NULL)
  33. --.
  34. UPDATE oper_valve
  35.    SET geom = sdo_geometry(2001, NULL,SDO_POINT_TYPE(10,0,0),NULL,NULL)
  36.  WHERE oper_valve_id = 1;
  37. --.
  38. 1 ROWS updated.
  39. --.
  40. COMMIT;
  41. --.
  42. commited.
  43. --.
  44. SELECT oper_valve_id,  to_char(geom_mod_date,'YYYY-MM-DD HH24:MI:SS') AS geom_mod_date, geom
  45.   FROM oper_valve;
  46. --.
  47. OPER_VALVE_ID GEOM_MOD_DATE       GEOM
  48. ------------- ------------------- --------------------------------------------------------------------
  49.             1 2012-11-12 09:49:16 MDSYS.SDO_GEOMETRY(2001,NULL,MDSYS.SDO_POINT_TYPE(10,0,0),NULL,NULL)
  50. --.
  51. EXECUTE dbms_lock.sleep(5);
  52. --.
  53. anonymous block completed
  54. --.
  55. UPDATE oper_valve
  56.    SET geom = NULL
  57.  WHERE oper_valve_id = 1;
  58. --.
  59. 1 ROWS updated.
  60. --.
  61. COMMIT;
  62. --.
  63. commited.
  64. --.
  65. SELECT oper_valve_id,  to_char(geom_mod_date,'YYYY-MM-DD HH24:MI:SS') AS geom_mod_date, geom
  66.   FROM oper_valve;
  67. --.
  68. OPER_VALVE_ID GEOM_MOD_DATE       GEOM
  69. ------------- ------------------- --------------------------------------------------------------------
  70.             1 2012-11-12 09:49:21 NULL

As you can see, the processing is correct.

WHEN clause

The UPDATE TRIGGER syntax includes the possibility of including a WHEN clause in the trigger header that allows for a more declarative style for controlling processing.

  1. CREATE OR REPLACE TRIGGER valve_geom_but
  2. BEFORE UPDATE OF geom
  3. ON oper_valve
  4. REFERENCING NEW AS NEW OLD AS OLD
  5. FOR EACH ROW
  6. WHEN ( ( OLD.geom IS NOT NULL
  7.      AND NEW.geom IS NOT NULL
  8.      AND sdo_geom.relate(OLD.geom,'DETERMINE',NEW.geom,0.005)<>'EQUAL' )
  9.   OR ( ( OLD.geom IS NULL     AND NEW.geom IS NOT NULL ) OR
  10.        ( OLD.geom IS NOT NULL AND NEW.geom IS NULL )
  11.      ) )
  12. BEGIN
  13.   :NEW.geom_mod_date := SYSDATE;
  14. END;
  15. /
  16. SHOW ERRORS

As you can see this looks really “clean”.

Sadly, though, it doesn’t work:

  1. -- Results
  2. --
  3. Error report:
  4. ORA-04076: invalid NEW OR OLD specification
  5. 04076. 00000 -  "invalid NEW or OLD specification"
  6. *Cause:    An invalid NEW OR OLD specification was given FOR a COLUMN.
  7. *Action:   Re-specify the COLUMN USING the correct NEW OR OLD specification.

Actually, this error is not about the NEW/OLD specification clause but about the WHEN clause as can be seen in the following:

  1. CREATE OR REPLACE TRIGGER valve_geom_but
  2. BEFORE UPDATE OF geom
  3. ON oper_valve
  4. REFERENCING NEW AS NEW OLD AS OLD
  5. FOR EACH ROW
  6. WHEN ( NOT ( OLD.geom IS NULL AND NEW.geom IS NULL ) )
  7. BEGIN
  8.   IF ( :OLD.geom IS NOT NULL AND :NEW.geom IS NOT NULL ) THEN
  9.     IF ( sdo_geom.relate(:OLD.geom,'DETERMINE',:NEW.geom,0.005)!='EQUAL' ) THEN
  10.        :NEW.geom_mod_date := SYSDATE;
  11.     END IF;
  12.   ELSE
  13.      :NEW.geom_mod_date := SYSDATE;
  14.   END IF;
  15. END;
  16. /
  17. SHOW ERRORS
  18. -- Result
  19. --
  20. TRIGGER VALVE_GEOM_BUT compiled
  21. No Errors.

Again, the tests are correct.

Note: we cannot use a function from an external package in our WHEN clause.

No Spatial?

OK, so I hear you saying: “We only have Locator: we are not licensed for Spatial. What can we do?”

There are things that can be done.

JTS Relate

You could consider installing my Spatial Companion For Oracle (SC4O) package which contains the Java Topology Suite open source implementation of RELATE. That function can be seen here on my web site, with full package documentation here.

I leave it to you, dear reader, to replace the lines containing SDO_GEOM.RELATE with SC4O.ST_RELATE (there is a slight difference in what is returned so the comparison in the IF statement needs changing).

PL/SQL Function

We have a very simple SDO_GEOMETRY test: Is one SDO_GEOMETRY equal to another? As such this test can be coded reasonably simply via a PL/SQL function as follows.

  1. -- Because this code uses the ability of Oracle to compare two nested tables we need a nested table into which to CAST the VARRAYs that make up the SDO_GEOMETRY SDO_ELEM_INFO_ARRAY and SDO_ORDINATE_ARRAY
  2. --
  3. CREATE OR REPLACE TYPE T_Numbers AS TABLE OF NUMBER;
  4. /
  5. SHOW errors
  6. TYPE compiled
  7. -- Now create function
  8. --
  9. CREATE OR REPLACE
  10. FUNCTION ST_Equal(p_geom1 IN sdo_geometry,
  11.                   p_geom2 IN sdo_geometry)
  12. RETURN varchar2
  13. AUTHID CURRENT_USER
  14. AS
  15.    v_ok varchar2(10);
  16.    v_vertex1 mdsys.vertex_type;
  17.    v_vertex2 mdsys.vertex_type;
  18. BEGIN
  19.   IF (    p_geom1.get_gtype() != p_geom2.get_gtype() ) THEN
  20.      -- Is:
  21.      -- Point != Multipoint with same point?
  22.      -- Line  != MultiLine  with exactly same points?
  23.      -- Poly  != MultiPoly  with exactly same points?
  24.      -- For simplicity we say yes.
  25.      -- If not, change this to suite your processing.
  26.      RETURN 'FALSE';
  27.   ElsIf (    p_geom1.sdo_elem_info IS NOT NULL
  28.          AND p_geom2.sdo_elem_info IS NOT NULL
  29.          AND p_geom1.sdo_ordinates IS NOT NULL
  30.          AND p_geom2.sdo_ordinates IS NOT NULL) THEN
  31.      SELECT CASE WHEN ( CAST(p_geom1.sdo_elem_info AS codesys.t_numbers) =
  32.                         CAST(p_geom2.sdo_elem_info AS codesys.t_numbers)
  33.                         AND
  34.                         CAST(p_geom1.sdo_ordinates AS codesys.t_numbers) =
  35.                         CAST(p_geom2.sdo_ordinates AS codesys.t_numbers) )
  36.                  THEN 'TRUE'
  37.                  ELSE 'FALSE'
  38.              END AS equals
  39.        INTO v_ok
  40.        FROM dual;
  41.     RETURN v_ok;
  42.   ElsIf ( p_geom1.get_gtype() = 1 AND p_geom2.get_gtype() = 1 ) THEN
  43.      -- Both points may be coded in sdo_point or one in sdo_ordinates etc
  44.      v_vertex1 := sdo_util.getVertices(p_geom1)(1);
  45.      v_vertex2 := sdo_util.getVertices(p_geom2)(1);
  46.      IF ( v_vertex1.x = v_vertex2.x AND
  47.           v_vertex1.y = v_vertex2.y AND
  48.           NVL(v_vertex1.z,-999999999999999999) = NVL(v_vertex2.z,-999999999999999999) ) THEN
  49.         RETURN 'TRUE';
  50.      ELSE
  51.        RETURN 'FALSE';
  52.      END IF;
  53.   ELSE
  54.      RETURN 'FALSE';
  55.   END IF;
  56.   EXCEPTION
  57.      WHEN NO_DATA_FOUND THEN
  58.          RETURN 'TRUE';
  59. END ST_Equal;
  60. /
  61. SHOW ERRORS
  62. -- Results
  63. --
  64. FUNCTION ST_EQUAL compiled
  65. No Errors.

I will not present all the tests I used to check this function except for the following:

  1. SELECT ST_equal(SDO_GEOMETRY(2001,NULL,sdo_point_type(0,1,NULL),NULL,NULL),
  2.                 SDO_GEOMETRY(2001,NULL,sdo_point_type(0,1,NULL),NULL,NULL)) AS equal
  3.  FROM dual;
  4. --Results
  5. --
  6. EQUAL
  7. -----
  8. TRUE
  9. --
  10. SELECT ST_equal(SDO_GEOMETRY(2001,NULL,sdo_point_type(0,1,2),NULL,NULL),
  11.                 SDO_GEOMETRY(2001,NULL,sdo_point_type(0,1,NULL),NULL,NULL)) AS equal
  12.  FROM dual;
  13. --Results
  14. --
  15. EQUAL
  16. -----
  17. FALSE
  18. --
  19. SELECT ST_equal(SDO_GEOMETRY(2001,NULL,sdo_point_type(0,1,NULL),NULL,NULL),
  20.                 SDO_GEOMETRY(2001,NULL,NULL,sdo_elem_info_array(1,1,1),sdo_ordinate_array(0,1))) AS equal
  21.  FROM dual;
  22. --Results
  23. --
  24. EQUAL
  25. -----
  26. TRUE
  27. --
  28. SELECT ST_equal(SDO_GEOMETRY(2001,NULL,sdo_point_type(0,1,NULL),NULL,NULL),
  29.                 SDO_GEOMETRY(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(0,1,2,3))) AS equal
  30.  FROM dual;
  31. --Results
  32. --
  33. EQUAL
  34. -----
  35. FALSE
  36. --
  37. SELECT ST_equal(SDO_GEOMETRY(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(0,1,2,3)),
  38.                 SDO_GEOMETRY(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(0,1,2,3))) AS equal
  39.  FROM dual;
  40. --Results
  41. --
  42. EQUAL
  43. -----
  44. TRUE
  45. --
  46. SELECT ST_equal(SDO_GEOMETRY(2002,NULL,NULL,sdo_elem_info_array(1,2,1),sdo_ordinate_array(0,1,2,3)),
  47.                 SDO_GEOMETRY(2003,NULL,NULL,sdo_elem_info_array(1,1003,3),sdo_ordinate_array(0,1,2,3))) AS equal
  48.   FROM dual;
  49. --Results
  50. --
  51. EQUAL
  52. -----
  53. FALSE
  54. --
  55. SELECT ST_equal(SDO_GEOMETRY(2003,NULL,NULL,sdo_elem_info_array(1,1003,3),sdo_ordinate_array(0,1,2,3)),
  56.                 SDO_GEOMETRY(2003,NULL,NULL,sdo_elem_info_array(1,1003,3),sdo_ordinate_array(0,1,2,3))) AS equal
  57.   FROM dual;
  58. --Results
  59. --
  60. EQUAL
  61. -----
  62. TRUE

Now we can use it in our trigger as follows.

  1. CREATE OR REPLACE TRIGGER valve_geom_but
  2. BEFORE UPDATE OF geom
  3. ON oper_valve
  4. REFERENCING NEW AS NEW OLD AS OLD
  5. FOR EACH ROW
  6. WHEN ( NOT ( OLD.geom IS NULL AND NEW.geom IS NULL ) )
  7. BEGIN
  8.   IF ( :OLD.geom IS NOT NULL AND :NEW.geom IS NOT NULL ) THEN
  9.     IF ( ST_Equal(:OLD.geom,:NEW.geom)='FALSE' ) THEN
  10.        :NEW.geom_mod_date := SYSDATE;
  11.     END IF;
  12.   ELSE
  13.      :NEW.geom_mod_date := SYSDATE;
  14.   END IF;
  15. END;
  16. /
  17. SHOW ERRORS
  18. -- Result
  19. --
  20. TRIGGER VALVE_GEOM_BUT compiled
  21. No Errors.

Again, the tests are correct.

I hope this is instructive and helpful for 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 [2]

Many thanks for this great article. Tried the function ST_equal and can confirm the correct results. Would only replace:
  1. SELECT CASE WHEN (
  2.  ( CAST(multiset(SELECT v.column_value FROM TABLE(p_geom1.sdo_elem_info) v) AS t_numbers)
  3.  = CAST(multiset(SELECT v.column_value FROM TABLE(p_geom2.sdo_elem_info) v) AS t_numbers) )
  4.  AND
  5.  ( CAST(multiset(SELECT v.column_value FROM TABLE(p_geom1.sdo_ordinates) v) AS t_numbers)
  6.  = CAST(multiset(SELECT v.column_value FROM TABLE(p_geom2.sdo_ordinates) v) AS t_numbers) )
  7. )
With:
  1. SELECT CASE WHEN (
  2.  ( CAST(p_geom1.sdo_elem_info AS t_numbers) = CAST(p_geom2.sdo_elem_info AS t_numbers) )
  3.  AND
  4.  ( CAST(p_geom1.sdo_ordinates AS t_numbers) = CAST(p_geom2.sdo_ordinates AS t_numbers) )
  5.  )

— _jum · 20 November 2012, 14:34 · #

Jum,

Thanks for the comments.

You are right. One can cast and compare the varrays directly.

I have made the change to the article.

Again, my thanks to you.

regards
Simon

— Simon Greener · 20 November 2012, 22:07 · #