Top 5 Recent Articles
ARTICLES CATEGORIES
- Algorithms (22)
- All (399)
- Biography (1)
- Blog (44)
- Business Requirements (1)
- Commentary (1)
- Conversion (2)
- Customers (2)
- Data Models (1)
- Education (2)
- GeoRaptor (13)
- GPS (1)
- Image Processing (2)
- Import Export (8)
- Licensing (2)
- LiDAR (1)
- Linear Referencing (4)
- Manifold GIS (3)
- Mapping (1)
- MySQL Spatial (7)
- Networking and Routing (including Optimization) (5)
- Open Source (18)
- Oracle Spatial and Locator (194)
- Partitioning (1)
- PostGIS (36)
- Projections (1)
- Published Articles (1)
- qGIS (1)
- Recommendations (1)
- Services (1)
- Software Change Log (1)
- Source Code (37)
- Space Curves (9)
- Spatial Database Functions (109)
- Spatial DB comparison (1)
- Spatial XML Processing (11)
- SQL Server Spatial (92)
- Standards (3)
- Stored Procedure (17)
- Tessellation or Gridding (10)
- Tools (2)
- Topological Relationships (1)
- Training (2)
- Triangulation (2)
How to extract elements from the result of an sdo_intersection of two polygons.
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:
!http://www.spatialdbadvisor.com/images/20.png (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.
Documentation
- MySQL Spatial General Functions
- Oracle LRS Objects
- Oracle Spatial Exporter (Java + pl/SQL)
- Oracle Spatial Object Functions
- Oracle Spatial Object Functions (Multi Page)
- PostGIS pl/pgSQL Functions
- SC4O Oracle Java Topology Suite (Java + pl/SQL)
- SQL Server Spatial General TSQL Functions
- SQL Server Spatial LRS TSQL Functions