Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Calculating the Distance between Points.

Calculating the Distance between Points

Written by Allen Wyatt (last updated August 3, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


1

Mike tracks latitude and longitude values in an Excel worksheet. As these are essentially points on a grid, Mike would like to calculate the distance between any two given latitude/longitude points.

If the latitude and longitude pairs were really just points on a grid, then calculating the distance between them would be easy. The problem is that they are really points on a sphere, which means that you can't use flat-grid calculations to determine distance. In addition, there are many ways that you can calculate distances: shortest surface distance, optimum flight path ("as the crow flies"), distance through the earth, driving distance, etc.

Obviously, this could be a complicated question. In the space available, I'll examine a couple of ways to determine the great circle distance ("as the crow flies"), and then provide some references for additional information on the other types of calculations.

The first thing you need to figure out is how the latitude and longitude of each point will be represented in Excel. There are several ways it could be represented. For instance, you could enter the degrees, minutes, and seconds in individual cells. Or, you could have them in a single cell as DD:MM:SS. Either way is acceptable, but they will need to be treated differently in your formulas. Why? Because if you enter latitude and longitude as DD:MM:SS, then Excel will convert them internally into a time value, and you just need to take that conversion into account.

What you are going to need to do, no matter what, is convert your latitude and longitude into a decimal value in radians. If you have a coordinate in three separate cells (degrees, minutes, and seconds), then you can use the following formula to do the conversion to a decimal value in radians:

=RADIANS((Degrees*3600+Minutes*60+Seconds)/3600)

The formula uses named ranges for your degrees, minutes, and seconds. It converts those three values into a single value representing total degrees, and then uses the RADIANS function to convert this to radians. If you start with a value of 32 degrees, 48 minutes, and 0 seconds, the formula ends up looking like this:

=RADIANS((32*3600+48*60+0)/3600)
=RADIANS((115200+2880+0)/3600)
=RADIANS(118080/3600)
=RADIANS(32.8)
=0.572467995

If you are storing your coordinates in the format of DD:MM:SS in a single cell (in this example, cell E12), then you can use the following formula to convert to a decimal value in radians:

=RADIANS((DAY(E12)*86400+HOUR(E12)*3600+MINUTE(E12)*60+SECOND(E12))/3600)

Assuming that cell E12 contains 32:48:00, then the formula ends up looking like this:

=RADIANS((1*86400+8*3600+48*60+0)/3600)
=RADIANS((86400+28800+2880+0)/3600)
=RADIANS(118080/3600)
=RADIANS(32.8)
=0.572467995

With your coordinates in radians, you can use a trigonometric formula to calculate distance along the surface of a sphere. There are many such formulas that could be used; the following formula will suffice for our purposes:

=ACOS(SIN(Lat1)*SIN(Lat2)+COS(Lat1)*COS(Lat2)*COS(Lon2-Lon1))*180/PI()*60

In this formula, each of the latitude (Lat1 and Lat2) and longitude (Lon1 and Lon2) coordinates must be a decimal value, in radians, as already discussed. The formula returns a value in nautical miles, which you can then apply various formulas to in order to convert to other units of measure, as desired.

You should realize that the values you come up with by using any formula that calculates distance on the surface of a sphere will give slightly erroneous results. Why? Because the Earth is not a perfect sphere. Thus, the distances should only be considered approximate. If you want to get a bit more accurate, then you can use the following formula to determine your nautical miles:

=ACOS(SIN(Lat1)*SIN(Lat2)+COS(Lat1)*COS(Lat2)*COS(Lon2-Lon1))*3443.89849

This formula substitutes the radius of the earth (3443.89849 nautical miles) for the radius of a sphere (180/PI()*60, or 3437.746771). Either way, the answer should still be considered approximate.

As you can tell, the formula to calculate distances is quite long. You may find it easier to develop your own user-defined function that will do the calculation for you. The following function takes four values (the two pairs of latitudes and longitudes, in degrees), and then returns a result in nautical miles:

Function CrowFlies(dlat1, dlon1, dlat2, dlon2)
    Pi = Application.Pi()
    earthradius = 3443.89849  'nautical miles

    lat1 = dlat1 * Pi / 180
    lat2 = dlat2 * Pi / 180
    lon1 = dlon1 * Pi / 180
    lon2 = dlon2 * Pi / 180

    cosX = Sin(lat1) * Sin(lat2) + Cos(lat1) _
      * Cos(lat2) * Cos(lon1 - lon2)
    CrowFlies = earthradius * Application.Acos(cosX)
End Function

If you would like to see a more in-depth discussion of latitudes and longitudes, and the math involved, you can find a good selection of articles at this site:

http://mathforum.org/library/drmath/sets/select/dm_lat_long.html

With the math under your belt, then you can start to look about at various formulas you can use. There is an interesting one in VBA at this Web page:

http://www.freevbcode.com/ShowCode.asp?ID=5532

A good general-purpose discussion can also be found at Chip Pearson's site, here:

http://www.cpearson.com/excel/LatLong.aspx

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9512) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Calculating the Distance between Points.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Keeping the Styles Pane Open by Default

Word doesn't provide a way that you can display the Styles task pane by default. If you get tired of manually displaying ...

Discover More

Excluding Some Data from a Chart

Excel is a whiz at creating charts from your worksheet data. When the program tries to determine what should be included ...

Discover More

Accepting Only a Single Digit

Want a quick way to enter a series of single digits into consecutive cells? The best approach is with a macro, and this ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Solving a Quadratic Equation

One of the staples of high school algebra classes is the quadratic equation. If you need to solve such equations in ...

Discover More

Counting Asterisks

For some operations and functions, Excel allows you to use wild card characters. One such character is an asterisk. What ...

Discover More

Criteria-Based Counting in a Filtered Column

The filtering capabilities of Excel are excellent, providing you with great control over which records in a worksheet are ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 + 7?

2019-08-03 11:31:52

Ron

The whole process can be simplified if the latitude and longitude are expressed in the more straightforward decimal format (D.DDDD)) like you will find in Google Maps and many navigation systems. Then you can skip a lot of the math and start with RADIANS (D.DDDD). That is short enough that you can embed all the math into a single formulas like so ...

=ACOS(SIN(RADIANS(Lat1))*SIN(RADIANS(Lat2))+COS(RADIANS(Lat1))*COS(RADIANS(Lat2))*COS(RADIANS(Lon2)-RADIANS(Lon1)))*180/PI()*60

Note: In Google Maps, if you click on a point on a map, it will display a three-line box where the bottom line has the coordinates in decimal format. If you then click on those coordinates, Google Maps will transfer those numbers to its search box where you can copy them for pasting into Excel.


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.