Skip to content

Commit 07b75f3

Browse files
authored
Create GetOpenLocationCode.sql
1 parent f29b25a commit 07b75f3

File tree

1 file changed

+99
-0
lines changed

1 file changed

+99
-0
lines changed

GetOpenLocationCode.sql

Lines changed: 99 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,99 @@
1+
/****** Object: StoredProcedure [dbo].[GetOpenLocationCode] Script Date: 11/23/2018 4:18:59 PM ******/
2+
SET ANSI_NULLS ON
3+
GO
4+
SET QUOTED_IDENTIFIER ON
5+
GO
6+
-- =============================================
7+
-- Author: Victor-Vartan Pambuccian
8+
-- Create date: 2018-11-22
9+
-- Description: The MSSQL implementation of converting latitude and longitude to Open Location Code
10+
-- =============================================
11+
CREATE FUNCTION [dbo].[GetOpenLocationCode]
12+
(
13+
@latitude DECIMAL(9,6),
14+
@longitude DECIMAL(9,6),
15+
@codeLength INT = 10
16+
)
17+
RETURNS VARCHAR(MAX)
18+
AS
19+
BEGIN
20+
DECLARE @code VARCHAR(MAX) = '';
21+
DECLARE @CodePrecisionNormal INT = 10; -- Provides a normal precision code, approximately 14x14 meters.
22+
DECLARE @CodePrecisionExtra INT = 11; -- Provides an extra precision code, approximately 2x3 meters.
23+
DECLARE @Separator CHAR(1) = '+'; -- A separator used to break the code into two parts to aid memorability.
24+
DECLARE @SeparatorPosition INT = 8; -- The number of characters to place before the separator.
25+
DECLARE @PaddingCharacter CHAR(1) = '0'; -- The character used to pad codes.
26+
DECLARE @CodeAlphabet CHAR(20) = '23456789CFGHJMPQRVWX'; -- The character set used to encode the values.
27+
DECLARE @EncodingBase INT = LEN(@CodeAlphabet); -- The base to use to convert numbers to/from.
28+
DECLARE @EncodingBaseSquared INT = @EncodingBase * @EncodingBase;
29+
DECLARE @LatitudeMax INT = 90; -- The maximum value for latitude in degrees.
30+
DECLARE @LongitudeMax INT = 180; -- The maximum value for longitude in degrees.
31+
DECLARE @PairCodeLength INT = 10; -- Maxiumum code length using just lat/lng pair encoding.
32+
DECLARE @GridColumns INT = 4; -- Number of columns in the grid refinement method.
33+
DECLARE @GridRows INT = 5; -- Number of rows in the grid refinement method.
34+
35+
-- Check that the code length requested is valid.
36+
IF (@codeLength < 4 OR (@codeLength < @PairCodeLength AND @codeLength % 2 = 1)) RETURN N'Illegal code length ' + CAST(@codeLength as NVARCHAR);
37+
38+
-- Ensure that latitude and longitude are valid.
39+
SET @latitude = (SELECT MIN(x) FROM (VALUES ((SELECT MAX(x) FROM (VALUES (@latitude), (-@LatitudeMax)) AS value(x))), (@LatitudeMax)) AS value(x));
40+
WHILE (@longitude < -@LongitudeMax) SET @longitude = @longitude + @LongitudeMax * 2;
41+
WHILE (@longitude >= @LongitudeMax) SET @longitude = @longitude - @LongitudeMax * 2;
42+
43+
-- Latitude 90 needs to be adjusted to be just less, so the returned code can also be decoded.
44+
IF (@latitude = @LatitudeMax)
45+
BEGIN
46+
DECLARE @latitudePrecission DECIMAL(9,6);
47+
IF (@codeLength <= @CodePrecisionNormal) SET @latitudePrecission = POWER(@EncodingBase, @codeLength / -2 + 2);
48+
ELSE SET @latitudePrecission = POWER(@EncodingBase, -3) / POWER(@GridRows, @codeLength - @PairCodeLength);
49+
SET @latitude = @latitude - 0.9 * @latitudePrecission;
50+
END
51+
52+
-- Adjust latitude and longitude to be in positive number ranges.
53+
DECLARE @remainingLatitude DECIMAL(9,6) = @latitude + @LatitudeMax;
54+
DECLARE @remainingLongitude DECIMAL(9,6) = @longitude + @LongitudeMax;
55+
56+
-- Count how many digits have been created.
57+
DECLARE @generatedDigits INT = 0;
58+
59+
-- The precisions are initially set to ENCODING_BASE^2 because they will be immediately divided.
60+
DECLARE @latPrecision DECIMAL(9,6) = @EncodingBaseSquared;
61+
DECLARE @lngPrecision DECIMAL(9,6) = @EncodingBaseSquared;
62+
63+
WHILE (@generatedDigits < @codeLength)
64+
BEGIN
65+
IF (@generatedDigits < @PairCodeLength)
66+
BEGIN
67+
-- Use the normal algorithm for the first set of digits.
68+
SET @latPrecision = @latPrecision / @EncodingBase;
69+
SET @lngPrecision = @lngPrecision / @EncodingBase;
70+
DECLARE @latDigit INT = FLOOR(@remainingLatitude / @latPrecision);
71+
DECLARE @lngDigit INT = FLOOR(@remainingLongitude / @lngPrecision);
72+
SET @remainingLatitude = @remainingLatitude - @latPrecision * @latDigit;
73+
SET @remainingLongitude = @remainingLongitude - @lngPrecision * @lngDigit;
74+
SET @code = @code + SUBSTRING(@CodeAlphabet, @latDigit + 1, 1);
75+
SET @code = @code + SUBSTRING(@CodeAlphabet, @lngDigit + 1, 1);
76+
SET @generatedDigits = @generatedDigits + 2;
77+
END
78+
ELSE
79+
BEGIN
80+
-- Use the 4x5 grid for remaining digits.
81+
SET @latPrecision = @latPrecision / @GridRows;
82+
SET @lngPrecision = @lngPrecision / @GridColumns;
83+
DECLARE @row INT = FLOOR(@remainingLatitude / @latPrecision);
84+
DECLARE @col INT = FLOOR(@remainingLongitude / @lngPrecision);
85+
SET @remainingLatitude = @remainingLatitude - @latPrecision * @row;
86+
SET @remainingLongitude = @remainingLongitude - @lngPrecision * @col;
87+
SET @code = @code + SUBSTRING(@CodeAlphabet, @row * @GridColumns + @col + 1, 1);
88+
SET @generatedDigits = @generatedDigits + 1;
89+
END;
90+
91+
-- If we are at the separator position, add the separator.
92+
IF (@generatedDigits = @SeparatorPosition) SET @code = @code + @Separator;
93+
END;
94+
95+
-- If the generated code is shorter than the separator position, pad the code and add the separator.
96+
IF (@generatedDigits < @SeparatorPosition) SET @code = @code + REPLICATE(@PaddingCharacter, @SeparatorPosition - @generatedDigits) + @Separator;
97+
98+
RETURN @code;
99+
END;

0 commit comments

Comments
 (0)