SQL Server Forums
Profile | Register | Active Topics | Members | Search | Forum FAQ
 
Register Now and get your question answered!
Username:
Password:
Save Password
Forgot your Password?

 All Forums
 SQL Server 2000 Forums
 SQL Server Development (2000)
 Finding all post/zip codes within a certain radius
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

JamesTT
Starting Member

2 Posts

Posted - 03/13/2007 :  18:41:27  Show Profile  Reply with Quote

I have a database that holds a postcode/zipcode the town and then the longitude and latitude, what I wanted to know is it possible to write a query to say If I wanted to get a list of postcodes that were in a radius of 4 miles or kilometers from say Postcode 4612 or the town of Abbeywood. Some thing tells me I will need to get my old trigonometry maths books out but if any one could give me some pointers that would be great.


4612	Abbeywood    	151.61991	-25.9974
2176	Abbotsbury    	150.86645	-33.87245
2046	Abbotsford    	151.12888	-33.84981

jezemine
Flowing Fount of Yak Knowledge

USA
2886 Posts

Posted - 03/13/2007 :  19:44:40  Show Profile  Visit jezemine's Homepage  Reply with Quote
if a bounding box was good enough (min/max lat/long), that would be trivial to implement in sql.

a true radius is more complicated.


www.elsasoft.org
Go to Top of Page

JamesTT
Starting Member

2 Posts

Posted - 03/13/2007 :  19:50:43  Show Profile  Reply with Quote
Hi jezemine thank you for the reply I will go back and find out if a bounding box would be good enough but if not would I have to create a another table holding holding a list of all the post codes and there distrances between one another as I can see that would create a massive table.
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30282 Posts

Posted - 03/14/2007 :  01:54:41  Show Profile  Visit SwePeso's Homepage  Reply with Quote
If not correcting for Earth spherical (which only makes a difference of 0.5-1-5 % anyway) , use pythagoras theorem

SQRT(POWER(Lat1 - Lat2, 2) + Power(Long1 - Long2, 2)) -- This the distance in coordinates. Just multiply with some constant to get real distance in either mile or km.

gives the "real" distance to the other coordinates. But since you almost certainly want the nearest, get rid of the SQRT part (saves a lot a calculations) and use only

POWER(Lat1 - Lat2, 2) + Power(Long1 - Long2, 2)

to get the shortest "pseudo-distance".


Peter Larsson
Helsingborg, Sweden
Go to Top of Page

Kristen
Test

United Kingdom
22431 Posts

Posted - 03/14/2007 :  04:58:59  Show Profile  Reply with Quote
here's what we do:

1) Find the Min/Max Lat/Long of a bounding box. Select rows "within" that first. Use an index for Lat/Long. That will be quick!

2) For rows that are within the bounding box then use a Great Circle algorithm, or similar, to filter the bounding "Box" to a "Circle".

Assuming you are looking for proximity of Miles, rather than fractions of an inch!, sacrifice trigonometric accuracy for speed.

See also:

http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=40295 - Great Circle Formula
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=57242 - Accuracy v. Speed

Kristen
Go to Top of Page

Michael Valentine Jones
Yak DBA Kernel (pronounced Colonel)

USA
7020 Posts

Posted - 03/14/2007 :  07:26:16  Show Profile  Reply with Quote
This function computes the great circle distance in Kilometers using the Haversine formula distance calculation.

If you want it in miles, change the average radius of Earth to miles in the function.


create function dbo.F_GREAT_CIRCLE_DISTANCE
	(
	@Latitude1 float,
	@Logitude1 float,
	@Latitude2 float,
	@Logitude2 float
	)
returns float
as
/*
fUNCTION: F_GREAT_CIRCLE_DISTANCE

	Computes the Great Circle distance in kilometers
	between two points on the Earth using the
	Haversine formula distance calculation.

Input Parameters:
	@Logitude1 - Logitude in degrees of point 1
	@Latitude1 - Latitude in degrees of point 1
	@Logitude2 - Logitude in degrees of point 2
	@Latitude2 - Latitude in degrees of point 2

*/
begin
declare @radius float

declare @lon1  float
declare @lon2  float
declare @lat1  float
declare @lat2  float

declare @a float
declare @distance float

-- Sets average radius of Earth in Kilometers
set @radius = 6371.0E

-- Convert degrees to radians
set @lon1 = radians( @Logitude1 )
set @lon2 = radians( @Logitude2 )
set @lat1 = radians( @Latitude1 )
set @lat2 = radians( @Latitude2 )

set @a = sqrt(square(sin((@lat2-@lat1)/2.0E)) + 
	(cos(@lat1) * cos(@lat2) * square(sin((@lon2-@lon1)/2.0E))) )

set @distance =
	@radius * ( 2.0E *asin(case when 1.0E < @a then 1.0E else @a end ))

return @distance

end


CODO ERGO SUM

Edited by - Michael Valentine Jones on 03/14/2007 09:42:53
Go to Top of Page

codezilla94
Starting Member

6 Posts

Posted - 11/12/2007 :  20:09:25  Show Profile  Visit codezilla94's Homepage  Reply with Quote
(spam removed -graz)
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
30282 Posts

Posted - 11/12/2007 :  21:46:11  Show Profile  Visit SwePeso's Homepage  Reply with Quote
It cost $20 and you can get it for free here!
http://www.sqlteam.com/forums/topic.asp?TOPIC_ID=81360



E 12°55'05.25"
N 56°04'39.16"
Go to Top of Page
  Previous Topic Topic Next Topic  
 New Topic  Reply to Topic
 Printer Friendly
Jump To:
SQL Server Forums © 2000-2009 SQLTeam Publishing, LLC Go To Top Of Page
This page was generated in 0.06 seconds. Powered By: Snitz Forums 2000