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.

Extracting geometry type string values from geometry/geography objects in SQL Server 2008 Spatial

Monday September 28 2009 at 23:56

Ever needed to extract a textual description of all geometry types in a single geometry/geography in SQL Server 2008?

Recently I had cause to do so and created the following function that implements this need.

/*********************************************************************************
** @function    : Geometry_Type
** @precis      : Returns geometry type of passed in geometry as string.
** @description : Returns list of geometry types (from OGC STGeometryType function)
**                that describe the contents of the passed in geometry.
**                Any GeometryCollection is "exploded" to examine the geometry types
**                within it.
**                Geography objects can be processed by converting to geometry using
**                dbo.toGeometry() function.
** @example     : select dbo.geometry_type(geometry::STGeomFromText('POINT(0 1 2)',0));
** @param       : p_geom : the geometry object to be processed.
** @param_type  : p_geom : geometry
** @history     : Simon Greener, The Spatial DB Advisor, September 2009
** @copyright   : Licensed under a Creative Commons Attribution-Share Alike 2.5 Australia License. 
**                (http://creativecommons.org/licenses/by-sa/2.5/au/)
**/

USE [GISDB]  -- Change this to your database
GO

SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

Create function [dbo].[geometry_type]( @p_geom geometry )
  Returns varchar(MAX)
As
Begin
  Declare
    @v_geomn        Int,
    @v_geometryType varchar(100),
    @v_return       varchar(MAX);
  Begin
    If ( @p_geom is NULL ) 
      return NULL;

    SET @v_GeometryType = @p_geom.STGeometryType();

    IF ( @v_geometryType <> 'GeometryCollection' )
      SET @v_return = @v_GeometryType
    ELSE
    BEGIN
	  SET @v_geomn  = 1;
	  SET @v_return = 'GeometryCollection';
	  WHILE ( @v_geomn <= @p_geom.STNumGeometries() )
	  BEGIN
	    SET @v_GeometryType = @p_geom.STGeometryN(@v_geomn).STGeometryType();
	    IF ( CHARINDEX(':' + @v_GeometryType,==@==v_return) = 0 )
		  SET @v_return = @v_return + ':' + @v_GeometryType;
		SET @v_geomn = @v_geomn + 1;
	  END
    END;
    RETURN @v_return;
   END;
End
GO

Now let’s test it against a selection of all possible geometry types

select dbo.geometry_type(geometry::STGeomFromText('
POINT(0 1 2)',0)) as gtype 
union all select dbo.geometry_type(geometry::STGeomFromText('
MULTIPOINT((0 0 0), 
(1 1 1), 
(2 2 2), 
(3 3 3))',0)) as gtype 
union all select dbo.geometry_type(geometry::STGeomFromText('
LINESTRING(0 0, 1 1)',0)) as gtype 
union all select dbo.geometry_type(geometry::STGeomFromText('
MULTILINESTRING(
(0 0,1 1,1 2),
(2 3,3 2,5 4))',0)) as gtype 
union all select dbo.geometry_type(geometry::STGeomFromText('
POLYGON(
(326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
(326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0))',0)) as gtype 
union all SELECT dbo.geometry_type(geometry::STGeomFromText('
MULTIPOLYGON(
((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
	(326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0)),
((321000.0 5450000.0,322000.0 5450000.0,321500.0 5451000.0,321000.0 5450000.0)))',0)) as gtype 
union all select dbo.geometry_type(geometry::STGeomFromText('
GEOMETRYCOLLECTION(
POINT(2 3 4),
LINESTRING(2 3 4,3 4 5),
POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0)),
POINT(4 5))',0));

gtype
Point
MultiPoint
LineString
MultiLineString
Polygon
MultiPolygon
GeometryCollection:Point:LineString:Polygon

But what if I want to create a single string that describes all the geometries in a particular table?

Here is one way to do this via XML aggregation.

WITH geometry_Types AS 
(
SELECT distinct dbo.geometry_type(a.geom) as gtype
  FROM (select           geometry::STGeomFromText('
POINT(0 1 2)',0) as geom
		union all select geometry::STGeomFromText('
MULTIPOINT((0 0 0), 
(1 1 1), 
(2 2 2), 
(3 3 3))',0) as geom
		union all select geometry::STGeomFromText('
LINESTRING(0 0, 1 1)',0) as geom
		union all select geometry::STGeomFromText('
MULTILINESTRING(
(0 0,1 1,1 2),
(2 3,3 2,5 4))',0) as geom
		union all select geometry::STGeomFromText('
POLYGON(
(326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
(326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0))',0) as geom
		union all SELECT geometry::STGeomFromText('
MULTIPOLYGON(
((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
 (326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0)),
((321000.0 5450000.0,322000.0 5450000.0,321500.0 5451000.0,321000.0 5450000.0)))',0) as geom
		union all select geometry::STGeomFromText('
GEOMETRYCOLLECTION(
POINT(2 3 4),
LINESTRING(2 3 4,3 4 5),
POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0)),
POINT(4 5))',0) as geom
	   ) a
)
SELECT (STUFF((SELECT DISTINCT ':' + a.gtype
                 FROM geometry_types a
                ORDER BY ':' + a.gtype
                FOR XML PATH(''), TYPE, ROOT).value('root[1]','nvarchar(max)'),1,1,'')
        ) as GeometryTypes;

GeometryTypes
GeometryCollection:Point:LineString:Polygon:LineString:MultiLineString:MultiPoint:MultiPolygon:Point:Polygon



Notice how the list is not unique. Here is one method of making it unique.

WITH geometries AS 
(
select           geometry::STGeomFromText('
POINT(0 1 2)',0) as geom
union all select geometry::STGeomFromText('
MULTIPOINT((0 0 0), 
(1 1 1), 
(2 2 2), 
(3 3 3))',0) as geom
union all select geometry::STGeomFromText('
LINESTRING(0 0, 1 1)',0) as geom
union all select geometry::STGeomFromText('
MULTILINESTRING(
(0 0,1 1,1 2),
(2 3,3 2,5 4))',0) as geom
union all select geometry::STGeomFromText('
POLYGON(
(326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
(326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0))',0) as geom
union all SELECT geometry::STGeomFromText('
MULTIPOLYGON(
((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0),
 (326500.0 5455500.0,326550.0 5455200.0,326450.0 5455200.0,326500.0 5455500.0)),
((321000.0 5450000.0,322000.0 5450000.0,321500.0 5451000.0,321000.0 5450000.0)))',0) as geom
union all select geometry::STGeomFromText('
GEOMETRYCOLLECTION(
POINT(2 3 4),
LINESTRING(2 3 4,3 4 5),
POLYGON((326000.0 5455000.0,327000.0 5455000.0,326500.0 5456000.0,326000.0 5455000.0)),
POINT(4 5))',0) as geom
)
SELECT (STUFF((SELECT DISTINCT ':' + a.gtype
                 FROM ( select distinct t.token as gtype
                          from geometries a
                               cross apply 
                               dbo.Tokenizer(dbo.geometry_type(a.geom),':') as t 
                       ) a
                 ORDER BY ':' + a.gtype
              FOR XML PATH(''), TYPE, ROOT).value('root[1]','nvarchar(max)'),1,1,'')
            ) as GeometryTypes;

GeometryTypes
GeometryCollection:LineString:MultiLineString:MultiPoint:MultiPolygon:Point:Polygon



Finally, show how we can use the function with geography type data.

select dbo.Geometry_Type(
           dbo.MBR2GEOMETRY(147,-44,148,-43,4326).STDifference(
               dbo.MBR2GEOMETRY(147.4,-43.6,147.6,-43.2,4326) ).STUnion(
                   dbo.MBR2GEOMETRY(150,-44,151,-43,4326) ) ) as geogtypes;

geogtypes
MultiPolygon



I hope this function 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