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)
 Distance Application with sorting in SQL
 New Topic  Reply to Topic
 Printer Friendly
Author Previous Topic Topic Next Topic  

AskSQLTeam
Ask SQLTeam Question

USA
0 Posts

Posted - 02/01/2002 :  07:45:33  Show Profile  Visit AskSQLTeam's Homepage  Reply with Quote
Lou writes "I am trying to come up with a SQL statement that will figure the distance between one zip code and a table of another zip codes and return them sorted by distance.

The tables would be:

DISTANCE TABLE
Zip Code, Latitude, Longitude

ZIP CODE TABLE
Zip Code, Town Name

Another zip code would be provided as the starting point. Is this possible to do just in SQL?"

robvolk
Most Valuable Yak

USA
15635 Posts

Posted - 02/01/2002 :  07:59:47  Show Profile  Visit robvolk's Homepage  Reply with Quote
If you can use some basic trig functions like COS, SIN, and TAN to find the distances, then yes you can do this using on SQL. I'm not sure if the math is right, but the following example should give you an idea:

DECLARE @startzip char(5), @destzip char(5)
SELECT @startzip='11701', @destzip='30097'
SELECT Start.Latitude, Start.Longitude, Dest.Latitude, Dest.Longitude,
TAN((Start.Latitude-Dest.Latitude)/(Start.Longitude-Dest.Longitude)) AS DistanceTAN
FROM Distance Start, Distance Dest
WHERE Start.ZipCode=@startzip AND Dest.ZipCode=@destzip


You can JOIN the table of zip codes to this instead of supply a single zip code as the destination. Can you provide some more detail? If you've got a formula for calculating distance we could plug it in to give you actual distances.

Go to Top of Page

aiken
Aged Yak Warrior

USA
525 Posts

Posted - 02/02/2002 :  16:45:18  Show Profile  Send aiken an ICQ Message  Reply with Quote
I have just this application running.

For performance, I precompute the distance between every zip code (!) and then throw out the ones that are over 2500 miles. It's a 38GB database, but that's really the only way you can do it if you want to be able to sort by "closest" (otherwise you have to compute distance for every possible combination in the query itself, which can take forever).

I keep the zip code data and stored procedures in a seperate database, as it never changes and I don't want to be backing it up all the time.

Cheers
-b


Go to Top of Page

Arnold Fribble
Yak-finder General

United Kingdom
1961 Posts

Posted - 02/03/2002 :  05:28:53  Show Profile  Reply with Quote
Rob, what on earth are you doing with that tan?!
You might want to sanity check this function with some known values: I haven't tested it extensively.

CREATE FUNCTION GCdist (@lat1 float, @lon1 float, @lat2 float, @lon2 float)
RETURNS float
AS
BEGIN
-- Parameters in RADIANS, result in km
-- Haversine formula from http://www.census.gov/cgi-bin/geo/gisfaq?5.1
DECLARE @dlon float, @dlat float, @a float, @c float
SET @dlon = @lon2 - @lon1
SET @dlat = @lat2 - @lat1
SET @a = POWER(SIN(@dlat / 2.0), 2.0) +
COS(@lat1) * COS(@lat2) * POWER(SIN(@dlon / 2.0), 2.0)
SET @c = 2.0 * ATN2(SQRT(@a), SQRT(1.0 - @a))
RETURN 6367.0 * @c
END


GO


CREATE FUNCTION dms2rad (@deg int, @min int, @sec float)
RETURNS float
AS
BEGIN
RETURN RADIANS(CONVERT(float, @deg) +
CONVERT(float, @min)/60.0 + @sec/3600.0)
END



Edited by - Arnold Fribble on 02/03/2002 06:10:18
Go to Top of Page

robvolk
Most Valuable Yak

USA
15635 Posts

Posted - 02/03/2002 :  08:06:08  Show Profile  Visit robvolk's Homepage  Reply with Quote
quote:
Rob, what on earth are you doing with that tan?!


Misusing it, most likely! It's been almost 20 years since I've had to use serious trigonometry. Give me a break!

Go to Top of Page

Glockenspiel
Yak Posting Veteran

50 Posts

Posted - 10/15/2002 :  18:19:20  Show Profile  Reply with Quote
Here's a function that is derived from the original one but further simplified. I verified that it will return the same results, although this one has been further modified to return the results in STATUTE MILES rather than kilometers (if you want it in km again then just replace the constant 69.041 with 6367; if you want it in nautical miles just use 60).


CREATE FUNCTION GCdist2 (@lat1 FLOAT, @lon1 FLOAT, @lat2 FLOAT, @lon2 FLOAT)
RETURNS FLOAT
AS
BEGIN
-- Parameters in RADIANS, result in STATUTE MILES
DECLARE @c FLOAT
SET @c = ACOS(SIN(@lat1)*SIN(@lat2)+COS(@lat1)*COS(@lat2)*COS(@lon1-@lon2))
RETURN 69.041 * @c
END
GO


Go to Top of Page

Arnold Fribble
Yak-finder General

United Kingdom
1961 Posts

Posted - 10/16/2002 :  07:05:51  Show Profile  Reply with Quote
Hmm. When I posted that haversine formula, it was on the assumption that the argument in the referenced GIS faq was correct -- that the cosine formula gives inaccurate results for small distances.
What I'd failed to take into account is the difference it makes in going from single precision to double precision. The inaccuracy is still there, it's just that you need points a few inches apart to notice!

quote:

[...] return the results in STATUTE MILES rather than kilometers (if you want it in km again then just replace the constant 69.041 with 6367; if you want it in nautical miles just use 60).



By definition there are exactly 1.609344 km in a statute mile, and 1.852 km in a nautical mile. So the constants should be 3956 (rather than 69.041) and 3438 (rather than 60).


Edited by - Arnold Fribble on 10/16/2002 07:15:08
Go to Top of Page

liana
Starting Member

1 Posts

Posted - 09/06/2006 :  00:12:37  Show Profile  Reply with Quote
hi
can anyone help me how to sort many pointer for example

1.1.1
1.1.2
1.1.3 and so on

have any idea?
Go to Top of Page

SwePeso
Patron Saint of Lost Yaks

Sweden
29908 Posts

Posted - 09/06/2006 :  02:50:38  Show Profile  Visit SwePeso's Homepage  Reply with Quote
This should be a separate topic!

If there are no more than three values in the string, use this
declare @test table (version varchar(100))

insert	@test
select	'1.1.2' union all
select	'1.1.3' union all
select	'1.1.15' union all
select	'1.1.1'

select		version
from		@test
order by	CAST(parsename(version, 3) AS INT),
		CAST(parsename(version, 2) AS INT),
		CAST(parsename(version, 1) AS INT)


Peter Larsson
Helsingborg, Sweden
Go to Top of Page

Arnold Fribble
Yak-finder General

United Kingdom
1961 Posts

Posted - 09/06/2006 :  02:56:42  Show Profile  Reply with Quote
Blimey, it's a long time since I last saw this thread!
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.08 seconds. Powered By: Snitz Forums 2000