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)
STFilterRings: Removing rings from Polygon 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.
USE [GISDB] -- Change to your database GO -- Drop dbo.STFilterRings -- DROP FUNCTION dbo.STFilterRings; -- Create dbo.STFilterRings -- CREATE FUNCTION dbo.STFilterRings( @p_geometry geometry, @p_area FLOAT ) RETURNS geometry AS BEGIN DECLARE @v_filtered_geom geometry; BEGIN IF ( @p_geometry IS NULL ) RETURN NULL; IF ( @p_geometry.STGeometryType() NOT IN ('CurvePolygon','Polygon','MultiPolygon') ) RETURN @p_geometry; SELECT @v_filtered_geom = a.outer_rings.STDifference(f.inner_rings) FROM (SELECT geometry::UnionAggregate(e.geom) AS outer_rings FROM dbo.EXTRACT(@p_geometry,1) AS e WHERE e.sid = 1 AND e.geom.STArea() > @p_area ) AS a, (SELECT geometry::UnionAggregate(d.geom) AS inner_rings FROM (SELECT e.geom FROM dbo.EXTRACT(@p_geometry,1) AS e WHERE e.sid <> 1 AND e.geom.STArea() > @p_area ) AS d ) f; RETURN @v_filtered_geom; END; END GO
Some tests.
Polygon
-- Original -- 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.:
-- Rings <= 2sq M removed -- 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
-- Original -- SELECT a.geom.STArea() AS area, a.geom 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….
-- Rings <= 2sq M removed -- SELECT e.geom.STArea() AS area, e.geom 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.
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