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.

toGeography and toGeography Conversion Functions for SQL Server 2008 Spatial

Monday September 28 2009 at 05:13

I have been doing some SQL Server 2008 programming lately and have come across the fact that TSQL does not allowing a programmer to create overloaded functions.

This is an issue, when programming SQL Server 2008 Spatial, because of use of its implementation of two different data types for geodetic and projected data: geography and geometry.

Thus, if I want to create a function like “DumpPoints”: I have to implement it twice (as is done with the CLR functions in SQL Spatial Tools ) eg:

Create Function DumpPointsGeom( @p_geom geometry ) 
etc

Create Function DumpPointsGeog( @p_geom geography ) 
etc

Or I can implement it once – DumpPoints( @p_geom geometry) – and call it using the following conversion functions.

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

SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

Create Function [dbo].[toGeography](@p_geom geometry,
                                    @p_srid Int = null)
 Returns geography
As
Begin
  Return geography::STGeomFromText(@p_geom.AsTextZM(),
         case when @p_srid is null 
              then @p_geom.STSrid
              else @p_srid
          end );
End
GO

Create Function [dbo].[toGeometry](@p_geog geography,
                                   @p_srid Int = null)
 Returns geometry
As
Begin
  Return geometry::STGeomFromText(@p_geog.AsTextZM(),
         case when @p_srid is null 
              then @p_geog.STSrid
              else @p_srid
          end );
End
GO

Testing its we get:

-- Test
-- 
SELECT dbo.ToGeography(
           dbo.ToGeometry(
               geography::STGeomFromText('LINESTRING(147.234 -43.2345, 148.234 -43.2345)',4326),
               0),
           4326).STAsText() 
       as geog;

geog
LINESTRING (147.234 -43.2345, 148.234 -43.2345)

Not all that clever, but I find them useful. I hope you might too.

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