如何用SQL SERVER數(shù)據(jù)庫(kù)計(jì)算距離并像MapInfo一樣圈選數(shù)據(jù)
在MapInfo因?yàn)榘鏅?quán)的問(wèn)題不讓使用和存在大量的經(jīng)緯度數(shù)據(jù)計(jì)算的背景下,本人提供3種方法進(jìn)行經(jīng)緯度的計(jì)算和Buffer數(shù)據(jù)圈選。(要求你有一點(diǎn)數(shù)據(jù)庫(kù)的基礎(chǔ))
準(zhǔn)備工作
準(zhǔn)備一張基礎(chǔ)數(shù)據(jù)表,表數(shù)據(jù)和表頭如下,表名:T1
在該表數(shù)據(jù)基礎(chǔ)上面增加空間字段(這一步很重要),表名:T1_Point
SELECT [Site_Name_Chinese]
,[Site_Name_English]
,[CGI]
,[gNBId]
,[經(jīng)度]
,[緯度]
,geography::STGeomFromText('POINT('+convert(varchar(50),[經(jīng)度])+ ' '+convert(varchar(50),[緯度])+')', 4326) [經(jīng)緯度點(diǎn)]
into [T1_POINT]
FROM [dbo].[T1]
新表數(shù)據(jù)展示
新表空間數(shù)據(jù)點(diǎn)展示
方法一(利用自定義函數(shù)計(jì)算距離)
方法1需要在sql server進(jìn)行自定義計(jì)算經(jīng)緯度函數(shù),具體函數(shù)如下:
CREATE FUNCTION [dbo].[fnGetDistance](@lon1 REAL, @lat1 REAL, @lon2 REAL, @lat2 REAL) RETURNS FLOAT
AS
BEGIN
--距離單位(米)
DECLARE @a_2d REAL,@e_2d REAL,@h_2d Integer,@DEG_2_RAD REAL,@RAD_2_DEG REAL
DECLARE @x_rads REAL,@y_rads REAL,@n_2ds REAL,@x_2d REAL,@y_2d REAL,@z_2d REAL,@x_radm REAl,@y_radm REAL,@n_2dm REAL,@x_2d_mark REAL,@y_2d_mark REAL,@z_2d_mark REAL
DECLARE @curdistance REAL
SET @a_2d = 6378137
SET @e_2d = 0.00669438
SET @h_2d = 15
SET @DEG_2_RAD = 0.01745329252
SET @RAD_2_DEG = 57.2957795129
SET @x_rads = Abs(@lon1) * @DEG_2_RAD
SET @y_rads = Abs(@lat1) * @DEG_2_RAD
SET @n_2ds = @a_2d / Sqrt(1 - @e_2d * Sin(@y_rads) * Sin(@y_rads))
SET @x_2d = (@n_2ds + @h_2d) * Cos(@y_rads) * Cos(@x_rads)
SET @y_2d = (@n_2ds + @h_2d) * Cos(@y_rads) * Sin(@x_rads)
SET @z_2d = (@n_2ds * (1 - @e_2d) + @h_2d) * Sin(@y_rads)
SET @x_radm = Abs(@lon2) * @DEG_2_RAD
SET @y_radm = Abs(@lat2) * @DEG_2_RAD
SET @n_2dm = @a_2d / Sqrt(1 - @e_2d * Sin(@y_radm) * Sin(@y_radm))
SET @x_2d_mark = (@n_2dm + @h_2d) * Cos(@y_radm) * Cos(@x_radm)
SET @y_2d_mark = (@n_2dm + @h_2d) * Cos(@y_radm) * Sin(@x_radm)
SET @z_2d_mark = (@n_2dm * (1 - @e_2d) + @h_2d) * Sin(@y_radm)
SET @curdistance = (@x_2d_mark - @x_2d) * (@x_2d_mark - @x_2d) + (@y_2d_mark - @y_2d) * (@y_2d_mark - @y_2d) + (@z_2d_mark - @z_2d) * (@z_2d_mark - @z_2d)
SET @curdistance = Sqrt(@curdistance)
RETURN @curdistance
END
計(jì)算方法:
SELECT * ,[dbo].[fnGetDistance] (A.[經(jīng)度],A.[緯度],B.[經(jīng)度],B.[緯度]) [DIS]
FROM [dbo].[T1] A,[dbo].[T1] B
where [dbo].[fnGetDistance] (A.[經(jīng)度],A.[緯度],B.[經(jīng)度],B.[緯度])<=500
解釋一下:
直接像調(diào)用系統(tǒng)函數(shù)如max(),avg()一樣調(diào)用該自定義函數(shù)進(jìn)行求兩個(gè)點(diǎn)的距離。
方法二(利用空間類型數(shù)據(jù)進(jìn)行計(jì)算距離)
計(jì)算方法:
SELECT * ,A.[經(jīng)緯度點(diǎn)].STDistance(B.[經(jīng)緯度點(diǎn)]) distance
FROM [dbo].[T1_Point] A,[dbo].[T1_Point] B
where A.[經(jīng)緯度點(diǎn)].STDistance(B.[經(jīng)緯度點(diǎn)])<=500
解釋一下:
將度量該實(shí)例與調(diào)用 STDistance() 的實(shí)例之間的距離。 如果 other_geography 是一個(gè)空集,則 STDistance() 返回 null。
方法三(利用空間類型數(shù)據(jù)制造Buffer對(duì)點(diǎn)數(shù)據(jù)進(jìn)行圈選)
計(jì)算方法:
SELECT *
,A.[經(jīng)緯度點(diǎn)].STDistance(B.[經(jīng)緯度點(diǎn)]) distance
FROM [dbo]. [T1_Point] A,[dbo]. [T1_Point] B
where A.[經(jīng)緯度點(diǎn)].STBuffer(500).STContains(B.[經(jīng)緯度點(diǎn)])=1
解釋一下:
STBuffer為geography的緩沖區(qū),同mapinfo的buffer類似,里面的500指的是500米范圍內(nèi)。
STContains()為調(diào)用 geography 實(shí)例在空間上包含傳遞給該方法的 geography 實(shí)例,則返回 1;否則,返回 0。 如果兩個(gè) geography 實(shí)例的 SRID 不同,則返回 null。
大白話就是以第一個(gè)點(diǎn)制作的buffer區(qū)域是否包含第二個(gè)里面的點(diǎn)
如何用SQL SERVER數(shù)據(jù)庫(kù)計(jì)算距離并像MapInfo一樣圈選數(shù)據(jù).docx
本人無(wú)不為,QQ345071917,本人愿意和大家一起共同學(xué)習(xí)。!