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.

Funky Fix Ordinates By Formula

Thursday February 12 2009 at 10:34

There was a posting over on the Oracle Spatial forum on Oracle Technet recently where a poster wanted to know how to fix the ordinates of an existing SDO_GEOMETRY object because the values that had been entered were incorrect (multiplied by 100000). This is the orginal post:

I was given a spatial network table, I have a problem though, when they built the original spatial table the lat longs were in whole numbers with precision of 5 ie(4787580, -9409401 which really should have been 47.87580, -94.09401), so my question for you all is… is there a way to loop through the table and perhaps alter each rows SDO_ORDINATE_ARRAY and say divide all the values for each row by 100000?

Siva Ravada (one of the Oracle Spatial development team) answered his question with the following bespoke function.

create or replace function fix_ordinates(geometry sdo_geometry)
  return SDO_GEOMETRY deterministic 
as
  idx number;
  result sdo_geometry;
begin
  result := geometry;
  FOR idx in 1 .. result.sdo_ordinates.count LOOP
    result.sdo_ordinates(idx) := result.sdo_ordinates(idx)/100000;
  END LOOP;
  return result;
end;

This function got me wondering what a more generic function might look like that could provide a greater range of potential corrections that could be applied to the ordinates in an SDO_GEOMETRY. Immediately this got me thinking about allowing a user to provide a formula for each of the elements of a coordinate ie X, Y, Z and W (ie M).

Here is my coding of the function (which has been added to my GEOM package).

  Function fix_ordinates(p_geometry  in sdo_geometry,
                         p_x_formula in varchar2,
                         p_y_formula in varchar2,
                         p_z_formula in varchar2 := null,
                         p_w_formula in varchar2 := null)
    Return SDO_GEOMETRY 
  Is
     v_measure_posn PLS_INTEGER; /* Ordinate position of the Measure value in an LRS geometry */
     v_dims         PLS_INTEGER;
     v_gtype        PLS_INTEGER;
     v_sdo_point    mdsys.sdo_point_type;
     v_ordinates    MDSYS.SDO_Ordinate_Array := new MDSYS.SDO_Ordinate_Array();
     v_vertex       mdsys.vertex_type;
     v_sql          varchar2(4000);
     NULL_GEOMETRY  EXCEPTION;
  Begin
    If ( p_geometry is NULL ) Then
      raise NULL_GEOMETRY;
    End If;
    v_dims  := TRUNC(p_geometry.sdo_gtype/1000,0);
    v_gtype := Mod(p_geometry.sdo_gtype,10);
    -- If sdo_geometry is a single point coded in sdo_point, then update it
    v_sdo_point := p_geometry.sdo_point;
    If ( v_gtype = 1 And p_geometry.sdo_point is not null ) Then
      v_sql := 'SELECT mdsys.sdo_point_type(' || p_x_formula || ',' || 
                                                 p_y_formula || ',' || 
                                                 case when p_z_formula is null 
                                                      then 'NULL' 
                                                      else p_z_formula
                                                  end || ') 
                FROM (SELECT :X as X,:Y as Y,:Z as Z FROM DUAL )';
       EXECUTE IMMEDIATE v_sql
                    INTO v_sdo_point 
                   USING v_sdo_point.x, 
                         v_sdo_point.y, 
                         v_sdo_point.z;
    End If;
    If ( p_geometry.sdo_ordinates is not null ) Then
      v_measure_posn := MOD(trunc(p_geometry.sdo_gtype/100),10);
      /* Need to UNPIVOT x,y,z,w records from "b" query into ordinate list to collect into v_ordinates */
      v_sql := '
SELECT CASE A.rin
            WHEN 1 THEN b.x
            WHEN 2 THEN b.y
            WHEN 3 THEN CASE ' || v_measure_posn || '
                             WHEN 0 THEN b.z 
                             WHEN 3 THEN b.w
                         END
            WHEN 4 THEN b.w
        END as ord
  FROM (SELECT LEVEL as rin 
          FROM DUAL 
        CONNECT BY LEVEL <= ' || v_dims || ') a,
       (SELECT rownum as cin, ' || 
               case when p_x_formula is null
                    then 'x'
                    else p_x_formula 
                end || ' as x,' || 
               case when p_y_formula is null
                    then 'y'
                    else p_y_formula 
                end || ' as y,' || 
               case when p_z_formula is null
                    then 'z'
                    else p_z_formula 
                end || ' as z,' || 
               case when p_w_formula is null
                    then 'w'
                    else p_w_formula 
                end || ' as w
          FROM (SELECT v.x,
                       v.y, ' ||
                       CASE WHEN v_measure_posn <> 3 /* If measured geometry and measure position is not 3 then Z is coded in this position */
                            THEN 'v.z'
                            ELSE 'NULL'
                        END || ' as z, ' ||
                       CASE WHEN v_measure_posn = 3 /* If measured geometry and measure position is 3 then Z has been coded with W so move it */
                            THEN 'v.z'
                            ELSE 'v.w'
                        END || ' as w
                  FROM TABLE(mdsys.sdo_util.GetVertices(:1)) v
               )
        ) b
 ORDER BY B.cin,A.rin';
      EXECUTE IMMEDIATE v_sql
      BULK COLLECT INTO v_ordinates
                  USING p_geometry;
    End If;
    Return sdo_geometry(p_geometry.sdo_gtype,
                        p_geometry.sdo_srid,
                        v_sdo_point,
                        p_geometry.sdo_elem_info,
                        v_ordinates);
    EXCEPTION
      WHEN NULL_GEOMETRY Then
        raise_application_error(CODESYS.CONSTANTS.c_i_null_geometry,
                                CODESYS.CONSTANTS.c_s_null_geometry,TRUE);
        RETURN p_geometry;
      WHEN OTHERS THEN
        dbms_output.put_line('Error ('|| SQLCODE ||') of ' || SQLERRM(SQLCODE) );
        RETURN p_geometry;
  End fix_ordinates;

Note that the function expects 4 formulae that are applied to the X,Y,Z and W ordinates depending on the dimensionality of the SDO_Geometry. Note that if a 2D geometry has been coded with a measure in the Z position (eg 3302) then the function will move the measure to the W position and then move it back: measure formula should be provided in this more “naturalistic” interpretation of a geometry’s ordinates.

The formula may reference the ordinates of the geometry via the columns X, Y, Z and W (the Vertex_Type fields produced by SDO_Util.GetVertices function) keywords. These keywords can be referred to multiple times in a formula (see ‘ROUND ( z / ( z * dbms_random.value(1,10) ), 3 )’ in the example that processes a 3D linestring below). Since the formula are applied via SQL even Oracle intrinsic columns like ROWNUM can be used (see ‘(rownum * w)’ below). One can also use any Oracle function, eg RANDOM: this includes functions in packages such as DBMS_RANDOM eg ‘ROUND ( Y * dbms_random.value ( 1,1000) ,3 )’) as well.

Here are some tests on point and linestring geometries.

-- Test a single 2D point
select geom.fix_ordinates(mdsys.SDO_Geometry('POINT(1.25 2.44)'),
                          'ROUND(:X * 3.141592653,3)',
                          'ROUND(:Y * dbms_random.value(1,1000),3)',
                          NULL).Get_WKT() as point2d
  from dual;
POINT2D
---------------------
POINT (3.927 707.838)

1 rows selected
-- Test single 3D point
select geom.fix_ordinates(mdsys.SDO_Geometry(3001,null,sdo_point_type(1.25,2.44,3.09),null,null),
                          'ROUND(:X * 3.141592653,3)',
                          'ROUND(:Y * dbms_random.value(1,1000),3)',
                          'ROUND(:Z / 1000,3)') as point3d
  from dual;

POINT3D
-----------------------------------------------------------------------------
MDSYS.SDO_GEOMETRY(3001,null,MDSYS.SDO_POINT_TYPE(3.927,814.987,0.003),null))

1 rows selected
-- Test a 2d linestring
select geom.fix_ordinates(mdsys.SDO_Geometry('LINESTRING(1.12345 1.3445,2.43534 2.03998398)'),
                          'ROUND(:X * 3.141592653,3)',
                          'ROUND(:Y * dbms_random.value(1,1000),3)').Get_WKT() as LINE2D
  from dual;

LINE2D
------------------------------------------
LINESTRING (3.529 805.689, 7.651 1418.316)

1 rows selected

-- Modify the Z ordinate of the following 3D multilinestring object
select geom.fix_ordinates(SDO_Geometry(3006,null,null,sdo_elem_info_array(1,2,1,10,2,1),
                               sdo_ordinate_array(1.12345,1.3445,9,2.43534,2.03998398,9,3.43513,3.451245,9,10,10,9,10,20,9)),
                               NULL,
                               NULL,
                               'ROUND(z / (z * dbms_random.value(1,10)),3)',
                               NULL) as fixed_mutlilinestring3D
  from dual;

FIXED_MUTLILINESTRING3D
------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
MDSYS.SDO_GEOMETRY(3006,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1,10,2,1),MDSYS.SDO_ORDINATE_ARRAY(1.12345,1.3445,0.26,2.43534,2.03998398,0.323,3.43513,3.451245,0.116,10,10,0.312,10,20,0.132))

1 rows selected

Finally,

SELECT geom.fix_ordinates(
         SDO_Geometry( 3302,  -- line string, 3 dimensions: X,Y,M
                      NULL,
                      NULL,
                      SDO_ELEM_INFO_ARRAY(1,2,1), -- one line string, straight segments
                      SDO_ORDINATE_ARRAY(
                        2,2,0,   -- Start point - Exit1; 0 is measure from start.
                        2,4,2,   -- Exit2; 2 is measure from start. 
                        8,4,8,   -- Exit3; 8 is measure from start. 
                        12,4,12,  -- Exit4; 12 is measure from start. 
                        12,10,NULL,  -- Not an exit; measure automatically calculated and filled.
                        8,10,22,  -- Exit5; 22 is measure from start.  
                        5,14,27)  -- End point (Exit6); 27 is measure from start.
                    ),
                    NULL,
                    NULL,
                    NULL,
                    '(rownum * w)') 
         as measured_geom
  FROM dual;

MEASURED_GEOM
-----------------------------------------------------------------------------------------------------------------------------------------------------
MDSYS.SDO_GEOMETRY(3302,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1),MDSYS.SDO_ORDINATE_ARRAY(2,2,0,2,4,4,8,4,24,12,4,48,12,10,null,8,10,132,5,14,189))

1 rows selected

I think this is a pretty flexible, nay “funky” function. I hope you find it useful. If you want it improved or find any problems, please let me know.

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

Simon,
This looks pretty neat. There are still a lot of things you are doing which I don’t follow, mostly because I don’t know much about Oracle.

For example
p_geometry.sdo_point —> does an sdo_geometry only return something in this case if it is a point? Do they have like .sbo_polygon and so forth constructs.

This construct is kind of new to me

EXECUTE IMMEDIATE v_sql BULK COLLECT INTO v_ordinates USING p_geometry;

I assume that :1 is p_geometry so the vSQL will explode generate an sql statement for each vertex when you do TABLE ( mdsys.sdo_util.GetVertices( :1 )

What does DECODE do?

Sorry for the somewhat inane questions.

I’m wondering if I can do a similar thing in PostGIS (perhaps when/if I or someone else gets this ST_DumpPoints going)

Regina · 13 February 2009, 19:58 · #

Regina,
Thanks for your comments.
"p_geometry.sdo_point -> does an sdo_geometry only return something in this case if it is a point? Do they have like .sbo_polygon and so forth constructs."
An Oracle SDO_Geometry is encoded as an actual Object (cf SQL3) as follows:
SQL> describe mdsys.sdo_geometry
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 SDO_GTYPE                                          NUMBER
 SDO_SRID                                           NUMBER
 SDO_POINT                                          MDSYS.SDO_POINT_TYPE
 SDO_ELEM_INFO                                      MDSYS.SDO_ELEM_INFO_ARRAY
 SDO_ORDINATES                                      MDSYS.SDO_ORDINATE_ARRAY
====
METHOD
------
 MEMBER FUNCTION GET_GTYPE RETURNS NUMBER
...
.... other methods removed for sake of brevity ...

-- SDO_POINT_TYPE is defined as:
SQL> desc mdsys.sdo_point_type
 Name                                      Null?    Type
 ----------------------------------------- -------- ------
 X                                                  NUMBER
 Y                                                  NUMBER
 Z                                                  NUMBER
====
-- The last two ARRAY types are:
SQL> desc MDSYS.SDO_ELEM_INFO_ARRAY
 MDSYS.SDO_ELEM_INFO_ARRAY VARRAY(1048576) OF NUMBER
====
SQL> desc MDSYS.SDO_ORDINATE_ARRAY
 MDSYS.SDO_ORDINATE_ARRAY VARRAY(1048576) OF NUMBER

Normally, single points are coded in the SDO_POINT structure with the SDO_ELEM_INFO and SDO_ORDINATE arrays left as NULL. However, one can code a single point in the latter two arrays and code the SDO_POINT to NULL. Multipoints are normally coded in the two arrays eg
SDO_ELEM_INFO(1/*StartPositionInOrdinateArray*/,
              1/*type of element ie 1 == point*/,
              n/*NumberOfPoints*/) 

That is, at position 1 in the SDO_ORDINATE_ARRAY are *n* points (1). Multi/Linestrings and Multi/Polygons are described by special elements in the SDO_ELEM_INFO structure and the coordinates, stored as a flat ordinate array, are stored in the SDO_ORDINATE_ARRAY. Every non-single point Oracle SDO_Geometry object can use the SDO_POINT structure to record a point: so, a linestring or polygon can have associated with it a point, perhaps the centroid of a polygon?
"This construct is kind of new to me"
EXECUTE IMMEDIATE v_sql BULK COLLECT INTO v_ordinates USING p_geometry;

Since PostgreSQL has *dynamic SQL* capability with USING and INTO variable handling I will assume the thing you don't understand is the "BULK COLLECT".
Normally, when you execute any SQL you either get a single row returned or multiple rows returned. The BULK COLLECT clause is a way of handling ALL the rows in a result set in one execute. When you do this the variable that is the target of the INTO clause must be some sort of ARRAY (or Nested Table). In this situation, the target is an SDO_ORDINATE_ARRAY object which is, of course, an array.
So, what I am doing is UNPIVOTing the X,Y,Z and M values (see discussion below) in order to _serialise_ them into a list of ordinates, then I am collecting them all up and dumping them into the SDO_ORDINATE_ARRAY object is the correct order for the SDO_Geometry object. In this was I don't have to manipulate the VARRAY in code looping around, extending the array and adding in the ordinates.
"I assume that :1 is p_geometry so the vSQL will explode generate an sql statement for each vertex when you do TABLE ( mdsys.sdo_util.GetVertices( :1 )"
The GetVertices function interrogates the SDO_Geometry object and "unserialises" the SDO_ORDINATE_ARRAY creating an ARRAY of MDSYS.VERTEX_TYPE:
SQL> desc mdsys.vertex_type
 Name                                      Null?    Type
 ----------------------------------------- -------- ------
 X                                                  NUMBER
 Y                                                  NUMBER
 Z                                                  NUMBER
 W                                                  NUMBER
 ID                                                 NUMBER

The TABLE operator in Oracle provides a mechanism for extracting the elements of a collection (eg array) for purposes of query. That is, TABLE takes the collection and makes it look like a table. This is called collection unnesting.
Each vertex in the array is returned as a single record in the SQL SELECT statment that is using the TABLE function. DECODE is an Oracle function that predates Oracle's support for the CASE statement. One reads a DECODE as follows:
    IF value of A.rin is 1 THEN return b.x
ELSEIF value of A.rin is 2 THEN return b.y
etc

So, the use of DECODE in the SQL:
SELECT DECODE(A.rin,1,b.x,
                    2,b.y,
                    3,DECODE(' || v_measure_posn || ',0,b.z,3,b.w),
                    4,b.w) as ord 

Can actually be replaced by the following:
SELECT CASE A.rin
            WHEN 1 THEN b.x
            WHEN 2 THEN b.y
            WHEN 3 THEN CASE ' || v_measure_posn || '
                             WHEN 0 THEN b.z 
                             WHEN 3 THEN b.w
                         END
            WHEN 4 THEN b.w
        END as ord

(Which I have now done.)
What I am doing with the DECODE/CASE is UNPIVOTing the four fields in a single row returned by a SELECT like this one:
SELECT v.x,v.y,v.z,.v.w
  FROM TABLE(mdsys.sdo_util.GetVertices(<>)) v;

so that each field is returned in its own row eg
Ordinate Value
-------- -----
       1   v.x
       2   v.y
       3   v.z
       4   v.w

"Sorry for the somewhat inane questions."
No question is every inane.
"I’m wondering if I can do a similar thing in PostGIS (perhaps when/if I or someone else gets this ST_DumpPoints going)."
You are dead right: it all depends on someone extending PostGIS with a custom or native ST_DumpPoints() function.
regards
Simon

Simon Greener · 14 February 2009, 05:02 · #

Simon,

Thanks for the detailed explanation. This has got me thinking some more

1) desc mdsys.vertex_type the W what is that? IS that like the M (measure position) and if so why is it called W?

2) For the GetVertices how far does it drill down. – I still haven’t gotten used to oracle’s connect by syntax for doing recursive queries so maybe I could figure this out on my own if I analyzed that more closely.

In the ST_DumpPoints approach I am envisioning (usual PostGIS dump structure – array of geometry_dumps with path,geom) , the path would be the n-dimensional array that stores the nested position of the point.

So for a POLYGON it would be something like

[0]00 — as outer ring point first point

[0]10 — as inner ring first point and so forth.

For a multipolygon it would be like
[0]000 and so forth

For Points and Multipoints it would be an empty or 1 d array.

I’m not sure how GetVertices deals with this since it looks like a one dimensional array of points (or is that where the corresponding comes into play)

Regina · 14 February 2009, 06:36 · #

Slight correction. Hmm what what was I thinking.

I guess I am so used to thinking in 0 being first index and its not an n-dimensional array. Its a 1-dimension of n numbers.

So what I meant to say was

path would be like
{0,1,1} for outer ring first point of a Polygon
{1,1,1) for 1st inner ring first point

{} for a POINT
{1} for a MULTIPOINT first point.

Anyrate argument still holds how the vertices in Oracle map back to the ordinate array when ordinate array is not a single dimension. Or is the ordinate array always a single dimension?

Regina · 14 February 2009, 06:56 · #