Go to content Go to navigation and search

Home

Current SQL Server Blog Articles


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.

Filtering Polygon Rings in SQL Server Spatial

Monday January 02 2012 at 01:35

Keywordsfunction remove outer inner ring polygon multipolygon geometry area STFilterRings
Summary

A function is presented that allows a user to remove (outer and inner) rings from polygon or multipolygon geometry objects based on area.

A function that have found use in Oracle and PostGIS is one that allows a user to filter out the rings of a polygon or multipolygon based on area.

Here is presented a function to do this in SQL Server Spatial. This function requires Denali (2012) as it uses unionAggregate. In addition, the function requires my Extract function.

  1. USE [GISDB]  -- Change to your database
  2. GO
  3. -- Drop STFilterRings
  4. --
  5. DROP   FUNCTION STFilterRings;
  6. -- Create STFilterRings
  7. --
  8. CREATE FUNCTION STFilterRings(@p_geometry geometry,
  9.                               @p_area     FLOAT)
  10. RETURNS geometry
  11. AS
  12. BEGIN
  13.   DECLARE
  14.      @v_filtered_geom geometry;
  15.   BEGIN
  16.     IF ( @p_geometry IS NULL )
  17.       RETURN NULL;
  18.     IF ( @p_geometry.STGeometryType() NOT IN ('CurvePolygon','Polygon','MultiPolygon') )
  19.     RETURN @p_geometry;
  20.     SELECT @v_filtered_geom = a.outer_rings.STDifference(f.inner_rings)
  21.       FROM (SELECT geometry::UnionAggregate(e.geom) AS outer_rings
  22.               FROM dbo.EXTRACT(@p_geometry,1) AS e
  23.        WHERE e.sid = 1
  24.          AND e.geom.STArea() > @p_area
  25.           ) AS a,
  26.            (SELECT geometry::UnionAggregate(d.geom) AS inner_rings
  27.               FROM (SELECT e.geom
  28.                       FROM dbo.EXTRACT(@p_geometry,1) AS e
  29.                  WHERE e.sid <> 1
  30.                        AND e.geom.STArea() > @p_area
  31.                    ) AS d
  32.            ) f;
  33.     RETURN @v_filtered_geom;
  34.   END;
  35. END
  36. GO

Some tests.

Polygon

  1. -- Original
  2. --
  3. SELECT 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) AS geom;

Visually this looks like this.:

  1. -- Rings <= 2sq M removed
  2. --
  3. SELECT dbo.STFilterRings(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),2) AS geom

Visually, this looks like this:

MultiPolygon

  1. -- Original
  2. --
  3. SELECT a.geom.STArea() AS area, a.geom
  4.   FROM (SELECT 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)), ((30 30, 50 30, 50 50, 30 50, 30 30)), ((0 30, 20 30, 20 50, 0 50, 0 30)), ((30 0,31 0,31 1,30 1,30 0)))',0) AS geom) AS a;

This looks like this.

area geom
1196 0×0000000001041E0000…..

Visually….

  1. -- Rings <= 2sq M removed
  2. --
  3. SELECT e.geom.STArea() AS area, e.geom
  4.   FROM dbo.EXTRACT(dbo.STFilterRings(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)), ((30 30, 50 30, 50 50, 30 50, 30 30)), ((0 30, 20 30, 20 50, 0 50, 0 30)), ((30 0,31 0,31 1,30 1,30 0)))',0),2.5),1) AS e

This looks like this:

area geom
400 0×0000000001040500…
400 0×0000000001040500…
400 0×0000000001040500…
4 0×0000000001040500…

Visually….

I hope this is useful 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