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.

COGO: Converting (Google Earth) Formatted Longitude/Latitude points to decimal degrees (SQL Server)

Saturday May 07 2011 at 01:57

KeywordsCOGO SQL Server 2008 and 2012 convert Google Earth DMS to decimal degrees value
Summary

This article presents a function, DmsS2DD, for Sql Server 2008 and 2012 that takes a Google Earth formatting Degrees Minutes and Seconds string and converts it to a single floating point decimal degrees value.

In an article on Oracle I described how to convert Google Earth textual representations of a longitude or latitude value to its decimal equivalent.

Here is a version that will work with SQL Server 2008/2012 Spatial.

  1. /** ----------------------------------------------------------------------------------------
  2.   * @function   : DMSS2DD
  3.   * @precis     : Function parses provided string, say extracted from Google Earth,
  4.   *               that represents DD MM SS.SS values, extracts and creates a single
  5.   *               floating point decimal degrees value.
  6.   * @version    : 1.0
  7.   * @usage      : Function DMSS2DD(@p_strDegMinSec nvarchar(100))
  8.   *                Returns Float
  9.   *               eg SELECT 3 as id, DMSS2DD('43° 0'' 50.00"S') as DD;
  10.   * @param      : p_strDegMinSec : DD MM SS.SS description eg 43° 0'' 50.00"S
  11.   * @param      : p_strDegMinSec : String
  12.   * @return     : Decimal Degree : Returns decimal degrees equivalent eg -43.0138888888889
  13.   * @returnType : Float
  14.   * @depends    : dbo.Tokenizer()
  15.   * @history    : Simon Greener - Feb 2011 - Original coding for Oracle in PL/SQL
  16.   * @history    : Simon Greener - May 2011 - Original coding for SQL Server in TSQL
  17.   * @copyright  : Licensed under a Creative Commons Attribution-Share Alike 2.5 Australia License.
  18.   *               (http://creativecommons.org/licenses/by-sa/2.5/au/)
  19. **/
  20. CREATE FUNCTION DMSS2DD(@p_strDegMinSec nvarchar(100))
  21. RETURNS FLOAT
  22. AS
  23. BEGIN
  24.    DECLARE
  25.        @i               INT = 0,
  26.        @intDmsLen       INT = -1,            --Length of original string
  27.        @strCompassPoint NVarChar(1),
  28.        @strNorm         Nvarchar(100) = N'', --Will contain normalized string
  29.        @strDegMinSecB   Nvarchar(100),
  30.        @token           Nvarchar(100),
  31.        @strChr          NVarChar(1),
  32.        @blnGotSeparator INTEGER = -1,        -- Keeps track of separator sequences
  33.        @dDeg            FLOAT   = 0,
  34.        @dMin            FLOAT   = 0,
  35.        @dSec            FLOAT   = 0,
  36.        @dReturnDecimal  FLOAT   = 0.0;
  37.     BEGIN
  38.        -- Remove leading and trailing spaces
  39.        SET @strDegMinSecB = REPLACE(@p_strDegMinSec,' ','');
  40.        -- assume no leading and trailing spaces?
  41.        SET @intDmsLen = DATALENGTH(@strDegMinSecB);
  42.        SET @blnGotSeparator = 0; -- Not in separator sequence right now
  43.        -- Loop over string, replacing anything that is not a digit or a
  44.        -- decimal separator with
  45.        -- a single blank
  46.        SET @i = 0;
  47.        WHILE ( @i <= @intDmsLen)
  48.        BEGIN
  49.           SET @i = @i + 1;
  50.           -- Get current character
  51.           SET @strChr = SUBSTRING(@strDegMinSecB, @i, 1);
  52.           -- either add character to normalized string or replace
  53.           -- separator sequence with single blank
  54.           IF (CHARINDEX(@strChr,N'0123456789,.') > 0 )
  55.           BEGIN
  56.              -- add character but replace comma with point
  57.              IF ((@strChr <> N',') )
  58.              BEGIN
  59.                 SET @strNorm = @strNorm + @strChr;
  60.              END
  61.              ELSE
  62.              BEGIN
  63.                 SET @strNorm = @strNorm + N'.';
  64.              END;
  65.              SET @blnGotSeparator = 0;
  66.           END;
  67.           ELSE
  68.           BEGIN
  69.             IF (CHARINDEX(@strChr,N'neswNESW') > 0 ) -- Extract Compass Point IF (present
  70.             BEGIN
  71.               SET @strCompassPoint = UPPER(@strChr);
  72.             END;
  73.             ELSE
  74.             BEGIN
  75.                -- ensure only one separator is replaced with a marker -
  76.                -- suppress the rest
  77.                IF (@blnGotSeparator = 0 )
  78.                BEGIN
  79.                   SET @strNorm = @strNorm + N'@';
  80.                   SET @blnGotSeparator = 0;
  81.                END;
  82.              END;
  83.           END;
  84.        END /* LOOP */
  85.        -- Split normalized string into array of max 3 components
  86.        DECLARE tokenList CURSOR FOR
  87.           SELECT a.token
  88.             FROM dbo.Tokenizer(@strNorm,N'@') a;
  89.      OPEN tokenList
  90.      FETCH NEXT FROM tokenList
  91.     INTO @token
  92.        SET @i = 1;
  93.      WHILE ( ==@@==FETCH_STATUS = 0 )
  94.      BEGIN
  95.           --convert specified components to double
  96.          IF ( @i = 1 ) SET @dDeg = CAST(@token AS FLOAT);
  97.          IF ( @i = 2 ) SET @dMin = CAST(@token AS FLOAT);
  98.          IF ( @i = 3 ) SET @dSec = CAST(@token AS FLOAT);
  99.          SET @i = @i + 1
  100.          FETCH NEXT FROM tokenList INTO @token
  101.      END;
  102.      CLOSE tokenList
  103.      DEALLOCATE tokenList
  104.        -- convert components to value
  105.        SET @dReturnDecimal = CASE WHEN UPPER(@strCompassPoint) IN (N'S',N'W')
  106.                                   THEN -1
  107.                                   ELSE 1
  108.                               END
  109.                              *
  110.                              (@dDeg + @dMin / 60 + @dSec / 3600);
  111.        RETURN @dReturnDecimal;
  112.     END;
  113. END
  114. GO

And here are a few examples.

  1. SELECT a.DD
  2.   FROM (
  3.       SELECT 1 AS id, DMSS2DD('43° 0''   50.00"S') AS DD
  4. UNION SELECT 2 AS id, DMSS2DD('43° 30''  45.50"N') AS DD
  5. UNION SELECT 3 AS id, DMSS2DD('147° 50'' 30.60"E') AS DD
  6. UNION SELECT 4 AS id, DMSS2DD('65° 10''  12.60"W') AS DD
  7. ) a
  8. ORDER BY a.id;

Result

DD
-43.0138888888889
43.5126388888889
147.841833333333
-65.1701666666667

I hope this is of use 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