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.

How to extract elements from the result of an sdo_intersection of two polygons.

Wednesday December 17 2008 at 07:04

This article is about how three things:

1. The fact that the intersection between two polygon (area) can be a combination of points, lines and polygons (a Collection sdo_geometry object).
2. Shows you how to extract a particular object type, in this case a polygon, from a mixed collection that results from an geospatial intersection.
3. Shows how to extract the sub-elements of a geometry object in SQL.

1. Intersecting Two Polygons

Firstly, here are two polygons that we will intersect using Oracle’s sdo_geom.sdo_intersection function:

Intersection of Two Polygons can be of mixed type

Here is how to execute an intersection between our two polygons.

SQL> SELECT SDO_GEOM.SDO_INTERSECTION(
  2  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(100,0,400,0,400,300,100,300,100,0)),
  3  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(-175,0,100,0,0,75,100,75,100,200,200,325,200,525,-175,525,-175,0)),
  4  0.05) AS GEOM
  5  FROM DUAL;

GEOM
------------------------------------------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2004, NULL, NULL, SDO_ELEM_INFO_ARRAY(1, 2, 1, 5, 1, 1, 7, 1003, 1), SDO_ORDINATE_ARRAY(100, 75, 100, 200, 100, 0, 180, 300, 100, 300, 100, 200, 180, 300))

1 rows selected

Note, the the result is a compound (or collection) object, composed of a line (1,2,1), a point (5,1,1) and a polygon with a single outer shell (7,1003,1)

2. Extracting individual objects from Collection

Often, we would like the result of the intersection to be three separate geometries so that we can extract one or more and use them in other processes.

This can be achieved, if you have 10g, as follows:

SQL> SELECT level as enum,mdsys.sdo_util.Extract(i.geom,level,0) AS GEOMETRY
  2    FROM (SELECT SDO_GEOM.SDO_INTERSECTION(
  3                          SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(100,0,400,0,400,300,100,300,100,0)),
  4                          SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(-175,0,100,0,0,75,100,75,100,200,200,325,200,525,-175,525,-175,0)),
  5                          0.05) as geom
  6            FROM DUAL) i
  7    CONNECT BY LEVEL <= mdsys.sdo_util.GetNumElem(i.geom);

ENUM                   GEOMETRY
---------------------- --------------------------------------------------------------------------------------------------------------------------------
1                      MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1),MDSYS.SDO_ORDINATE_ARRAY(100,75,100,200))
2                      MDSYS.SDO_GEOMETRY(2001,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1,1),MDSYS.SDO_ORDINATE_ARRAY(100,0))
3                      MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,1),MDSYS.SDO_ORDINATE_ARRAY(180,300,100,300,100,200,180,300))

3 rows selected

However, if you only have 9i or earlier, you have to write a custom PL/SQL function such as the “Explode” function in my free GEOM package:

  Function ExplodeGeometry(p_geometry in MDSYS.SDO_Geometry)
    Return codesys.GeometrySetType pipelined;

Which you would use as follows:

SQL> SELECT a.geometry
  2    FROM TABLE(codesys.geom.ExplodeGeometry(SDO_GEOM.SDO_INTERSECTION(
  3  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(100,0,400,0,400,300,100,300,100,0)),
  4  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(-175,0,100,0,0,75,100,75,100,200,200,325,200,525,-175,525,-175,0)),
  5  0.05))) a;

GEOMETRY
-----------------------------------------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2002, NULL, NULL, SDO_ELEM_INFO_ARRAY(1, 2, 1), SDO_ORDINATE_ARRAY(100, 75, 100, 200))
SDO_GEOMETRY(2001, NULL, NULL, SDO_ELEM_INFO_ARRAY(1, 1, 1), SDO_ORDINATE_ARRAY(100, 0))
SDO_GEOMETRY(2003, NULL, NULL, SDO_ELEM_INFO_ARRAY(1, 1003, 1), SDO_ORDINATE_ARRAY(180, 300, 100, 300, 100, 200, 180, 300))

3 rows selected

Now, what if we only wanted the polygon geometry from the result? Using 10g only this could be done as follows:

SQL> SELECT a.enum,a.geometry
  2    FROM  (SELECT level as enum,mdsys.sdo_util.Extract(i.geom,level,0) AS GEOMETRY
  3             FROM (SELECT SDO_GEOM.SDO_INTERSECTION(
  4                              SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(100,0,400,0,400,300,100,300,100,0)),
  5                              SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(-175,0,100,0,0,75,100,75,100,200,200,325,200,525,-175,525,-175,0)),
  6                              0.05) as geom 
  7                     FROM DUAL) i
  8           CONNECT BY LEVEL <= sdo_util.getnumelem(i.geom)
  9          ) a
 10  WHERE a.geometry.sdo_gtype = 2003;

ENUM                   GEOMETRY
---------------------- --------------------------------------------------------------------------------------------------------------------------------
3                      MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1003,1),MDSYS.SDO_ORDINATE_ARRAY(180,300,100,300,100,200,180,300))

1 rows selected

But, for 9i and below, this could be done in this way:

SQL> SELECT a.geometry
  2    FROM TABLE(CODESYS.GEOM.ExplodeGeometry(SDO_GEOM.SDO_INTERSECTION(
  3  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(100,0,400,0,400,300,100,300,100,0)),
  4  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(-175,0,100,0,0,75,100,75,100,200,200,325,200,525,-175,525,-175,0)),
  5  0.05))) a
  6   WHERE a.geometry.sdo_gtype = 2003;

GEOMETRY
------------------------------------------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2003, NULL, NULL, SDO_ELEM_INFO_ARRAY(1, 1003, 1), SDO_ORDINATE_ARRAY(180, 300, 100, 300, 100, 200, 180, 300))

1 rows selected

There is a fair bit of detail in these two different approaches to extracting a polygon. The detail can be wrapped up inside a PL/SQL function as in the ExtractPolygon function in my free PL/SQL packages:

  Function ExtractPolygon(p_geometry in MDSYS.SDO_Geometry)
    Return codesys.GeometrySetType Pipelined;

Now, why would we want to extract only the polygon from the intersection of two polygons? All these things depend on the business problem the SQL is being developed to solve. But we could use the extracted polygon to generate a centroid of the intersecting area as in the following example (that uses the mentioned ExtractPolygon function):

SQL> SELECT codesys.geom.Sdo_Centroid(
  2  codesys.geom.ExtractPolygon(
  3  SDO_GEOM.SDO_INTERSECTION(
  4  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(100,0,400,0,400,300,100,300,100,0)),
  5  SDO_GEOMETRY(2003,NULL,NULL,SDO_ELEM_INFO_ARRAY(1,1003,1),SDO_ORDINATE_ARRAY(-175,0,100,0,0,75,100,75,100,200,200,325,200,525,-175,525,-175,0)),
  6  0.05)
  7  )
  8  , 0.0000001) as geometry
  9   FROM DUAL;

GEOMETRY
-----------------------------------------------------------------------------------------------------------------------------------------------------
SDO_GEOMETRY(2001, NULL, SDO_POINT_TYPE(140, 275, NULL), NULL, NULL)

1 rows selected

3. Extracting Sub-Elements from a single SDO_Geometry object

I have mentioned the SDO_UTIL.EXTRACT function already in this article. We saw how we can use it to extract individual polygon objects from a collection. But what if we wanted to extract the internal elements within an SDO_Geometry object, how can we do this?

The SDO_UTIL.EXTRACT function, and the documented description of the element and ring parameters, is as follows:

SDO_UTIL.EXTRACT(
     geometry IN SDO_GEOMETRY,
     element IN NUMBER
     [, ring IN NUMBER]
     ) RETURN SDO_GEOMETRY;

element
Number of the element in the geometry: 1 for the first element, 2 for the second element, and so on. Geometries with SDO_GTYPE values (explained in Section 2.2.1) ending in 1, 2, or 3 have one element; geometries with SDO_GTYPE values ending in 4, 5, 6, or 7 can have more than one element. For example, a multipolygon with an SDO_GTYPE of 2007 might contain three elements (polygons).

ring
Number of the subelement (ring) within element: 1 for the first subelement, 2 for the second subelement, and so on. This parameter is valid only for specifying a subelement of a polygon with one or more holes or of a point cluster:

For a polygon with holes, its first subelement is its exterior ring, its second subelement is its first interior ring, its third subelement is its second interior ring, and so on. For example, in the polygon with a hole shown in Figure 2-3 in Section 2.5.2, the exterior ring is subelement 1 and the interior ring (the hole) is subelement 2.

For a point cluster, its first subelement is the first point in the point cluster, its second subelement is the second point in the point cluster, and so on.

The default is 0, which causes the entire element to be extracted.

So, note that the definition of element does not count the hole (inner ring). Holes need to be extracted via the ring parameter. The following SQL will show you this in reality:

with s_geom as (
select SDO_GEOMETRY(
     2007,  -- two-dimensional multi-part polygon with hole 
     NULL,
     NULL,
     SDO_ELEM_INFO_ARRAY(1,1005,2, 1,2,1, 5,2,2,
                        11,2005,2, 11,2,1, 15,2,2,
                        21,1005,2, 21,2,1, 25,2,2),
     SDO_ORDINATE_ARRAY(  6,10, 10,1, 14,10, 10,14,  6,10,
                         13,10, 10,2,  7,10, 10,13, 13,10,
                       106,110, 110,101, 114,110, 110,114,106,110)) as geom from dual)
select ExtractParms,sdo_geom.sdo_area(egeom,0.005) as area,egeom
  from (select '1,0' as ExtractParms, sdo_util.Extract(a.geom,1,0) as egeom from s_geom a
        union all
        select '1,1' as ExtractParms, sdo_util.Extract(a.geom,1,1) as egeom from s_geom a
        union all
        select '1,2' as ExtractParms, sdo_util.Extract(a.geom,1,2) as egeom from s_geom a
        union all
        select '2,1' as ExtractParms, sdo_util.Extract(a.geom,2,1) as egeom from s_geom a
       );

EXTRACTPARMS AREA                   EGEOM
------------ ---------------------- -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
1,0          22.9955742875643       MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1005,2,1,2,1,5,2,2,11,2005,2,11,2,1,15,2,2),MDSYS.SDO_ORDINATE_ARRAY(6,10,10,1,14,10,10,14,6,10,13,10,10,2,7,10,10,13,13,10))
1,1          61.1327412287183       MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1005,2,1,2,1,5,2,2),MDSYS.SDO_ORDINATE_ARRAY(6,10,10,1,14,10,10,14,6,10))
1,2          38.1371669411541       MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1005,2,1,2,2,5,2,1),MDSYS.SDO_ORDINATE_ARRAY(13,10,10,13,7,10,10,2,13,10))
2,1          61.1327412287184       MDSYS.SDO_GEOMETRY(2003,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,1005,2,1,2,1,5,2,2),MDSYS.SDO_ORDINATE_ARRAY(106,110,110,101,114,110,110,114,106,110))

4 rows selected

Note that there are four results: the first is all of the first element of the multipolygon including its outer shell (1005) and inner shell – hole – (2005), with the second and third being the extraction of the first element’s outer shell (1005) and inner shell (2005).

I deliberately chose this polygon to hightlight a shortcoming in the sdo_util.extract() function. That is, it is unable to extract the sub-elements that make up a higher element. Thus, above, it cannot extract the individual arc types that make up the shells of the polygon elements.

To do this we have to have recourse to some PL/SQL programming. I have done this in my free PL/SQL packages, encapsulating the result of my work in a function called ExtractElements (or ExtractElementsPiped). Here is it being used to “explode” the compound multi-polygon above into its constituent parts:

SQL> select a.geometry
  2    from table(codesys.geom.ExtractElementsPiped(
  3    SDO_GEOMETRY(
  4       2007,  -- two-dimensional multi-part polygon with hole
  5       NULL,
  6       NULL,
  7       SDO_ELEM_INFO_ARRAY(1,1005,2, 1,2,1, 5,2,2,
  8                          11,2005,2, 11,2,1, 15,2,2,
  9                          21,1005,2, 21,2,1, 25,2,2),
 10       SDO_ORDINATE_ARRAY(  6,10, 10,1, 14,10, 10,14,  6,10,
 11                           13,10, 10,2,  7,10, 10,13, 13,10,
 12                         106,110, 110,101, 114,110, 110,114,106,110)),
 13    1 /* TRUE ie extract all sub-elements */)) a;

GEOMETRY
--------------------------------------------------------------------------------------------------------------
MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1),MDSYS.SDO_ORDINATE_ARRAY(6,10,10,1,14,10))
MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,2),MDSYS.SDO_ORDINATE_ARRAY(14,10,10,14,6,10))
MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1),MDSYS.SDO_ORDINATE_ARRAY(13,10,10,2,7,10))
MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,2),MDSYS.SDO_ORDINATE_ARRAY(7,10,10,13,13,10))
MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,1),MDSYS.SDO_ORDINATE_ARRAY(6,10,10,1,14,10))
MDSYS.SDO_GEOMETRY(2002,null,null,MDSYS.SDO_ELEM_INFO_ARRAY(1,2,2),MDSYS.SDO_ORDINATE_ARRAY(14,10,10,14,6,10))

6 rows selected

I hope this is helpful to someone.

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

Recently had to generate centroids for polygon data loaded from a GIS application. Turns out that some of the records where actually a collection of either point/polygon or line/polygon geometries. This resulted in no centroid being created. After a email chat with Simon, ended up saving myself a couple of hours work in not having to write a extract polygon routine, by just using the explode function from his Oracle package, and a simple select statement.

Thanks Simon keep up the good work.

Cheers
Jamie

— Jamie Keene · 23 November 2008, 23:37 · #

Thanks Simon, this has been a godsend. Its going to make clipping data to our boundary childsplay!

— Thomas Baxter · 3 December 2008, 04:46 · #

I’m pleased that you find this posting useful. Let me know if you have any implementation or use issues.

regards
Simon

Simon Greener · 5 December 2008, 05:26 · #

Thanks for this! But is there an error in the section “Now, what if we only wanted the polygon geometry from the result? Using 10g” on line 8? (i.geometry) should be (i.geom) ???

— Mark · 30 June 2010, 18:05 · #

Quite right.
I have fixed it.
Thanks for noticing it.
Simon

Simon · 1 July 2010, 02:08 · #

Good tip on exploding geometries using: CONNECT BY LEVEL <= sdo_util.getnumelem….

That’s really useful and lets me explode my multi-line geometries into simple lines without any custom functions.

Cheers,
John

— John O'Toole · 24 June 2016, 21:03 · #