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)
STGeometryTypes: Extracting all geometry type string values from complex geometry
Ever needed to extract a textual description of all geometry types in a single geometry/geography in SQL Server 2008 inluding all sub-elements?
Recently I had cause to do so and created the following function that implements this need.
USE [GISDB] -- Change this to your database GO -- -- Extracts all geometry type keywords from a geometry (and its sub-elements) CREATE FUNCTION [$(owner)].[STGeometryTypes]( @p_geometry geometry ) RETURNS VARCHAR(MAX) AS BEGIN DECLARE @v_return VARCHAR(MAX); BEGIN IF ( @p_geometry IS NULL ) RETURN NULL; SELECT @v_return = SUBSTRING(a.token,2,LEN(a.token)) FROM (SELECT (STUFF((SELECT ',' + a.token FROM (SELECT t.token FROM [$(owner)].[Tokenizer](@p_geometry.AsTextZM(),' ,)(') AS t ) AS a WHERE a.token IS NOT NULL AND a.token NOT LIKE '%[0-9]%' FOR XML PATH(''), TYPE, ROOT ).VALUE('root[1]','nvarchar(max)'),1,1,'''') ) AS token ) AS a; RETURN @v_return; END; END GO
Now let’s test it against a selection of all possible geometry types
-- Simple geometry SELECT dbo.[STGeometryTypes](geometry::STGeomFromText('POINT(0 1 2)',0)) AS gtypes ; GO gtypes POINT -- Single CurvePolygon with one interior ring SELECT [$(owner)].[STGeometryTypes](geometry::STGeomFromText('CURVEPOLYGON(CIRCULARSTRING(0 5, 5 0, 0 -5, -5 0, 0 5), (-2 2, 2 2, 2 -2, -2 -2, -2 2))',0)) AS gtypes; GO gtypes CURVEPOLYGON,CIRCULARSTRING -- GeometryCollection SELECT [$(owner)].[STGeometryTypes]( geometry::STGeomFromText( 'GEOMETRYCOLLECTION( LINESTRING(0 0,20 0,20 20,0 20,0 0), 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))), COMPOUNDCURVE( CIRCULARSTRING(-90 -23.43778, -45 -23.43778, 0 -23.43778), (0 -23.43778, 0 23.43778)))',0)) AS gTypes; GO gTypes GEOMETRYCOLLECTION,LINESTRING,CURVEPOLYGON,COMPOUNDCURVE,CIRCULARSTRING,CIRCULARSTRING,COMPOUNDCURVE,CIRCULARSTRING
I hope this function 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