Go to content Go to navigation and search

Home

Current SQL Server Blog Articles

    SQL Server Spatial: STFlipVectors
    SQL Server Spatial: Extract LineStrings in GeometryCollection to create LineString
    SQL Server Spatial: Converting a LineString to COGO XML
    SQL Server Spatial: Creating (Multi)LineStrings geometries from COGO XML instructions
    New Version of Package of TSQL Spatial Functions
    Vectorize/Segmentize SQL Server 2012
    Coordinate Editing Functions for SQL Server Spatial
    Function to Scale a geometry object for SQL Server Spatial
    TSQL String Tokenizer Function for SQL Server
    geography/geometry to MBR helper functions
    generate_series for SQL Server 2008
    Extract Polygons from result of STIntersection in SQL Server Spatial
    Function to round ordinates of a SQL Server Spatial geometry object
    Extract elements of SQL Server Spatial geometry object
    Counting number of polygon rings SQL Server Spatial
    Filtering Polygon Rings in SQL Server Spatial
    Function to Move a geometry object in SQL Server Spatial
    Alternate Centroid Functions for SQL Server Spatial
    Function to Rotate geometry objects in SQL Server Spatial
    A GetVertices wrapper for DumpPoints in SQL Server 2008 Spatial
    Creating a Morton number Space Key generator for SQL Server
    Gridding a geometry or geography object (SQL Server Denali)
    On hinting spatial indexes
    Random Search Procedure (SQL Server 2008 Spatial)
    COGO: Converting (Google Earth) Formatted Longitude/Latitude points to decimal degrees (SQL Server)
    COGO: Convert Degrees, Minutes and Seconds values to Decimal Degrees
    COGO: DD2DMS Formatting a latitude/longitude decimal degree value
    COGO: Create point from bearing and distance
    COGO: Compute number of vertices required to stroke circle or circular arc
    COGO: Calculating the bearing between two points (SQL Server 2008 Spatial)
    COGO: Compute arc length subtended by angle centre of circle
    COGO: Compute chord length of segment of a circle (arc)
    COGO: Computing Arc To Chord (Arc2Chord) Separation
    COGO: Creating a stroked polygon from a circle's centre x,y and radius
    COGO: Finding centre and radius of a curve defined by three points: FindCircle function
    Identifying Tight Radius Curves sections within LineString geometry data
    Generating random point data for SQL Server 2008 Spatial
    New Presentation on Active (Searchable) Spatial Metadata for SQL Server 2008 Spatial and FreeText
    Checking is a column in a table or a view is of type geometry or geography
    Extracting geometry type string values from geometry/geography objects in SQL Server 2008 Spatial
    Vectorising geometry objects in SQL Server 2008
    MBR to geography/geometry helper functions
    Extracting geometry types from geometry/geography objects in SQL Server 2008
    Getting the number of coordinate dimensions of a geometry/geography object in SQL Server 2008
    A Dump Points Function for SQL Server 2008 Spatial
    toGeography and toGeography Conversion Functions for SQL Server 2008 Spatial
    Write text file with spatial data from SQL Server 2008
    Loading Shapefiles into Geography type column in SQL Server 2008
    Tip #6: Correcting invalid geometries
    Tip #5: Where or where has my little column gone
    Tip #4: What Coordinate System is that?
    Tip #3: What object is that?
    Tip #2: Spatial Indexing and Primary Keys
    Tip #1: SQL Server 2008 "Katmai" - Setting SRIDs

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.

Extract Polygons from result of STIntersection in SQL Server Spatial

Tuesday January 03 2012 at 06:15

KeywordsExtractPolygon Polygon Extract SQL Server Spatial STIntersection GeometryCollection
Summary

A function is presented that allows a user to extract only the polygon geometries in a GeometryCollection that might result from an StIntersection between two geometry polygons.

Oracle customers have asked me for help in the past dealing with compound objects or collections that result from thinning or geoprocessing (intersection etc) of geometry data.

Normally this is the need to extract only polygons from the result of an intersection operation.

This problem applies to SQL Server Spatial users are the following example will show.

The solution to the problem is to process the result of an operation and extract out only those geometric elements that are required.

In a previous blog I created a function called STExtract that allows a user to extract the parts of elements of a multi or single geometry depending on what is required.

This function is the basis for a new function called STExtractPolygon that can be used to extract only the polygon elements of a GeometryCollection that could result from an STIntersection between two polygon geometries.

  1. USE [GISDB] -- Change this to your database
  2. GO
  3. -- Drop if exists
  4. --
  5. DROP   FUNCTION dbo.STExtractPolygon;
  6. -- Now create
  7. --
  8. CREATE FUNCTION dbo.STExtractPolygon(@p_geometry geometry)
  9. RETURNS geometry
  10. AS
  11. BEGIN
  12.   DECLARE
  13.      @v_geom geometry;
  14.   BEGIN
  15.     IF ( @p_geometry IS NULL )
  16.       RETURN NULL;
  17.     IF ( @p_geometry.STGeometryType() NOT IN ('CurvePolygon','Polygon','MultiPolygon','GeometryCollection') )
  18.     RETURN NULL;
  19.   IF ( @p_geometry.STGeometryType() IN ('CurvePolygon','Polygon','MultiPolygon') )
  20.     RETURN @p_geometry;
  21.   IF ( @p_geometry.STGeometryType() IN ('GeometryCollection') )
  22.   BEGIN
  23.     -- Need to extract and append any polygons that may be in the GeometryCollection
  24.     --
  25.       SELECT @v_geom = geometry::CollectionAggregate(e.[geom])
  26.         FROM dbo.STExtract(@p_geometry,0) AS e
  27.      WHERE e.[geom].STGeometryType() IN ('CurvePolygon','Polygon');
  28.     IF ( @v_geom IS NOT NULL AND @v_geom.STNumGeometries() > 0 )
  29.     BEGIN
  30.       IF ( @v_geom.STNumGeometries() = 1 )
  31.       BEGIN
  32.       -- Get rid of GeometryCollection WKT token wrapper
  33.       --
  34.           SET @v_geom = geometry::STGeomFromText(REPLACE(REPLACE(@v_geom.STAsText(),'GEOMETRYCOLLECTION (','')+'$',')$',''),@v_geom.STSrid);
  35.       END
  36.     ELSE
  37.       BEGIN
  38.       IF ( CHARINDEX('CURVEPOLYGON',@v_geom.STAsText()) = 0 )
  39.       BEGIN
  40.              -- Replace all internal POLYGON WKT tokens with nothing
  41.          -- Then replace starting GeometryCollection token with MultiPolygon
  42.          --
  43.            SET @v_geom = geometry::STGeomFromText(REPLACE(REPLACE(UPPER(@v_geom.STAsText()),'POLYGON',''),'GEOMETRYCOLLECTION','MULTIPOLYGON'),@v_geom.STSrid);
  44.       END;
  45.       END;
  46.     END;
  47.   END;
  48.   RETURN @v_geom;
  49.   END;
  50. END
  51. GO

Now some testing…

  1. -- All these return null as they should
  2. --
  3. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('POINT(0 0)',0)).STAsText() AS ePoly UNION ALL
  4. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('MULTIPOINT((0 0),(20 0))',0)).STAsText() AS ePoly UNION ALL
  5. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('LINESTRING(0 0,20 0,20 20,0 20,0 0)',0)).STAsText() AS ePoly UNION ALL
  6. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('MULTILINESTRING((0 0,20 0,20 20,0 20,0 0),(10 10,10 11,11 11,11 10,10 10),(5 5,5 7,7 7,7 5,5 5))',0)).STAsText() AS ePoly;

As they do….

ePoly
NULL
NULL
NULL
NULL
  1. -- These should return themselves
  2. --
  3. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('POLYGON((0 0,20 0,20 20,0 20,0 0),(10 10,10 11,11 11,11 10,10 10),(5 5,5 7,7 7,7 5,5 5))',0)).STAsText() AS ePoly UNION ALL
  4. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('MULTIPOLYGON (((80 80, 100 80, 100 100, 80 100, 80 80)), ((110 110, 150 110, 150 150, 110 150, 110 110)))',0)).STAsText() AS ePoly UNION ALL
  5. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('MULTIPOLYGON (((0 0,20 0,20 20,0 20,0 0),(10 10,10 11,11 11,11 10,10 10),(5 5,5 7,7 7,7 5,5 5)), ((80 80, 100 80, 100 100, 80 100, 80 80)), ((110 110, 150 110, 150 150, 110 150, 110 110)))',0)).STAsText() AS ePoly UNION ALL
  6. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('CURVEPOLYGON(COMPOUNDCURVE((0 -23.43778, 0 23.43778),CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),(-90 23.43778, -90 -23.43778),CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778)))',0)).STAsText() AS ePoly;

As they do….

ePoly
POLYGON ((0 0, 20 0, 20 20, 0 20, 0 0), (10 10, 10 11, 11 11, 11 10, 10 10), (5 5, 5 7, 7 7, 7 5, 5 5))
MULTIPOLYGON (((80 80, 100 80, 100 100, 80 100, 80 80)), ((110 110, 150 110, 150 150, 110 150, 110 110)))
MULTIPOLYGON (((0 0, 20 0, 20 20, 0 20, 0 0), (10 10, 10 11, 11 11, 11 10, 10 10), (5 5, 5 7, 7 7, 7 5, 5 5)), ((80 80, 100 80, 100 100, 80 100, 80 80)), ((110 110, 150 110, 150 150, 110 150, 110 110)))
CURVEPOLYGON (COMPOUNDCURVE ((0 -23.43778, 0 23.43778), CIRCULARSTRING (0 23.43778, -45 23.43778, -90 23.43778), (-90 23.43778, -90 -23.43778), CIRCULARSTRING (-90 -23.43778, -45 -23.43778, 0 -23.43778)))
  1. -- These should extract only the polygons within the GeometryCollection
  2. -- (The second is wrapped as a GeometryCollection as a MultiPolygon cannot be constructed that includes a CurvePolygon
  3. --
  4. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('GEOMETRYCOLLECTION(LINESTRING(0 0,20 0,20 20,0 20,0 0),
  5.                                                                         CURVEPOLYGON(COMPOUNDCURVE((0 -23.43778, 0 23.43778),CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),(-90 23.43778, -90 -23.43778),CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778))),
  6.                                      COMPOUNDCURVE(CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778), (0 -23.43778, 0 23.43778)))',0)).STAsText() AS ePoly UNION ALL
  7. SELECT dbo.STExtractPolygon(geometry::STGeomFromText('GEOMETRYCOLLECTION(CURVEPOLYGON(COMPOUNDCURVE((0 -23.43778, 0 23.43778),CIRCULARSTRING(0 23.43778, -45 23.43778, -90 23.43778),(-90 23.43778, -90 -23.43778),CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778))), POLYGON ((100 200, 180.00 300.00, 100 300, 100 200)), LINESTRING (100 200, 100 75), POINT (100 0))',0)).STAsText() AS ePoly;

As they do…

ePoly
CURVEPOLYGON (COMPOUNDCURVE ((0 -23.43778, 0 23.43778), CIRCULARSTRING (0 23.43778, -45 23.43778, -90 23.43778), (-90 23.43778, -90 -23.43778), CIRCULARSTRING (-90 -23.43778, -45 -23.43778, 0 -23.43778)))
GEOMETRYCOLLECTION (CURVEPOLYGON (COMPOUNDCURVE ((0 -23.43778, 0 23.43778), CIRCULARSTRING (0 23.43778, -45 23.43778, -90 23.43778), (-90 23.43778, -90 -23.43778), CIRCULARSTRING (-90 -23.43778, -45 -23.43778, 0 -23.43778))), POLYGON ((100 200, 180 300, 100 300, 100 200)))

Now, test the intersection between two polygons.

  1. -- First, show the polygons
  2. --
  3. SELECT geometry::STGeomFromText('POLYGON ((100.0 0.0, 400.0 0.0, 400.0 480.0, 160.0 480.0, 160.0 400.0, 240.0 400.0,240.0 300.0, 100.0 300.0, 100.0 0.0))',0) AS geom
  4. UNION ALL
  5. SELECT geometry::STGeomFromText('POLYGON ((-175.0 0.0, 100.0 0.0, 0.0 75.0, 100.0 75.0, 100.0 200.0, 200.0 325.0, 200.0 525.0, -175.0 525.0, -175.0 0.0))',0) AS geom;

Which look like this:

  1. -- Do the intersection and show the result as WKT
  2. --
  3. SELECT a.geom.STIntersection(b.geom).STAsText() AS intersectionWKT
  4.   FROM (SELECT geometry::STGeomFromText('POLYGON ((100.0 0.0, 400.0 0.0, 400.0 480.0, 160.0 480.0, 160.0 400.0, 240.0 400.0,240.0 300.0, 100.0 300.0, 100.0 0.0))',0) AS geom) a,
  5.        (SELECT geometry::STGeomFromText('POLYGON ((-175.0 0.0, 100.0 0.0, 0.0 75.0, 100.0 75.0, 100.0 200.0, 200.0 325.0, 200.0 525.0, -175.0 525.0, -175.0 0.0))',0) AS geom) b;

Note the non-polygon elements.

intersectionWKT
GEOMETRYCOLLECTION (POLYGON ((160 400, 200.00000000000088 400.00000000000045, 200.00000000000088 480.00000000000017, 160 480, 160 400)), POLYGON ((100 200, 180.00000000000119 300.0000000000008, 100 300, 100 200)), LINESTRING (100 200, 100 75), POINT (100 0))

Using STExtract we can “explode” the GeometryCollection into its components for easier viewing.

  1. SELECT d.gid, d.sid, d.geom.STAsText() AS geom
  2.   FROM (SELECT a.geom.STIntersection(b.geom) AS geom
  3.           FROM (SELECT geometry::STGeomFromText('POLYGON ((100.0 0.0, 400.0 0.0, 400.0 480.0, 160.0 480.0, 160.0 400.0, 240.0 400.0,240.0 300.0, 100.0 300.0, 100.0 0.0))',0) AS geom) a,
  4.                (SELECT geometry::STGeomFromText('POLYGON ((-175.0 0.0, 100.0 0.0, 0.0 75.0, 100.0 75.0, 100.0 200.0, 200.0 325.0, 200.0 525.0, -175.0 525.0, -175.0 0.0))',0) AS geom) b
  5.      ) c
  6.      CROSS apply
  7.      dbo.STExtract(c.geom,1) AS d;

Which looks like this:

gid sid geom
1 1 POLYGON ((160 400, 200.00000000000088 400.00000000000045, 200.00000000000088 480.00000000000017, 160 480, 160 400))
2 1 POLYGON ((100 200, 180.00000000000119 300.0000000000008, 100 300, 100 200))
3 0 LINESTRING (100 200, 100 75)
4 0 POINT (100 0)

Visually…..

Now, using our new STExtractPolygon function we can extract just the polygon intersection elements.

  1. SELECT dbo.STExtractPolygon(a.geom.STIntersection(b.geom)).STAsText() AS geom
  2.   FROM (SELECT geometry::STGeomFromText('POLYGON ((100.0 0.0, 400.0 0.0, 400.0 480.0, 160.0 480.0, 160.0 400.0, 240.0 400.0,240.0 300.0, 100.0 300.0, 100.0 0.0))',0) AS geom) a,
  3.        (SELECT geometry::STGeomFromText('POLYGON ((-175.0 0.0, 100.0 0.0, 0.0 75.0, 100.0 75.0, 100.0 200.0, 200.0 325.0, 200.0 525.0, -175.0 525.0, -175.0 0.0))',0) AS geom) b;

Which, looks like:

geom
MULTIPOLYGON (((160 400, 200.00000000000088 400.00000000000045, 200.00000000000088 480.00000000000017, 160 480, 160 400)), ((100 200, 180.00000000000119 300.0000000000008, 100 300, 100 200)))

Showing the result visually:

  1. SELECT geometry::STGeomFromText('POLYGON ((100.0 0.0, 400.0 0.0, 400.0 480.0, 160.0 480.0, 160.0 400.0, 240.0 400.0,240.0 300.0, 100.0 300.0, 100.0 0.0))',0) AS geom
  2. UNION ALL
  3. SELECT geometry::STGeomFromText('POLYGON ((-175.0 0.0, 100.0 0.0, 0.0 75.0, 100.0 75.0, 100.0 200.0, 200.0 325.0, 200.0 525.0, -175.0 525.0, -175.0 0.0))',0) AS geom
  4. UNION ALL
  5. SELECT dbo.STExtractPolygon(a.geom.STIntersection(b.geom)) AS geom
  6.   FROM (SELECT geometry::STGeomFromText('POLYGON ((100.0 0.0, 400.0 0.0, 400.0 480.0, 160.0 480.0, 160.0 400.0, 240.0 400.0,240.0 300.0, 100.0 300.0, 100.0 0.0))',0) AS geom) a,
  7.        (SELECT geometry::STGeomFromText('POLYGON ((-175.0 0.0, 100.0 0.0, 0.0 75.0, 100.0 75.0, 100.0 200.0, 200.0 325.0, 200.0 525.0, -175.0 525.0, -175.0 0.0))',0) AS geom) b;

results in….

I hope this is of use 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 [2]

This problem applies to SQL Server Spatial users are the following example will show.

— Anonymous · 29 February 2012, 20:52 · #

Thank you very much! It was very useful.

— Jordi · 3 May 2016, 21:59 · #