toGeography and toGeography Conversion Functions for SQL Server 2008 Spatial
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 STDumpPointsGeom( @p_geom geometry ) etc -- CREATE FUNCTION STDumpPointsGeog( @p_geom geography ) etc
Or I can implement it once – STDumpPoints( @p_geom geometry) – and call it using the following conversion functions.
USE [GISDB] -- Change this to your database GO -- CREATE FUNCTION [dbo].[STToGeography](@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].[STToGeometry](@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:
SELECT [dbo].[STDensify] ( [dbo].[STToGeometry] ( geography::STGeomFromText('LINESTRING(-10 0,-5 5,10 10)',4326), NULL), 2.1,3,2).AsTextZM(); GO dGeom LINESTRING (-10 0, -8.75 1.25, -7.5 2.5, -6.25 3.75, -5 5, -3.125 5.625, -1.25 6.25, 0.625 6.875, 2.5 7.5, 4.375 8.125, 6.25 8.75, 8.125 9.375, 10 10) -- SELECT dbo.STToGeography( dbo.STToGeometry( 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.