Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. 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: Displaying Latitude and Longitude.
Written by Allen Wyatt (last updated January 22, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
If you do much geographic work, you may wonder if you can use Excel to display longitude and latitude in a cell in terms of degrees, minutes, and seconds. There are three ways that a solution can be approached.
First, if you just want to affect the display, you can follow these steps:
Figure 1. The Number tab of the Format Cells dialog box.
Now, if you type a number such as 1234543 into the cell, it is displayed as 123 degrees, 45 minutes, and 43 seconds.
Sometimes, however, you may want to take a decimal value that represents latitude and longitude and display it in degrees, minutes, and seconds. For instance, you may want 122.44 (which is a decimal representation of degrees) to be displayed as 122 degrees, 26 minutes, and 24 seconds. This cannot be accomplished with formatting the cell in which the number is contained. Instead, you must use a formula to achieve the proper display. For instance, if 122.44 is in cell A7, then you can put the following in cell B7:
=TEXT(TRUNC(A7), "0" & CHAR(176) & " ") & TEXT(INT((ABS(A7) - INT(ABS(A7)))*60), "0' ") & TEXT(((((ABS(A7)-INT(ABS(A7)))*60) - INT((ABS(A7) - INT(ABS(A7)))*60))*60), " 0''")
This is a long formula, but it provides the desired formatting of the latitude or longitude value. The result is text, and cannot be used in any calculations. If you want to use a display instead, you can simply divide the decimal value of the latitude or longitude by 24, which converts it into the same value ranges used by Excel to represent times. Then you can format the display of the formula as follows:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9457) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Displaying Latitude and Longitude.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
If you need to easily change the font colors in a group of cells, one of the esoteric commands Excel provides is the ...
Discover MoreIf you want to format currency values so that Excel uses periods between groups of thousands and commas as a decimal ...
Discover MoreExcel allows you to apply several types of alignments to cells. One type of alignment allows you to indent cell contents ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-01-27 00:17:09
I sail (on Georgian Bay) and frequently use Canadian Notices to Mariners to mark changes to the nautical charts in my GPS and chart plotter. The problem I had was the opposite of the one described by Allen. I needed to convert a position entry e.g., 44°54′56.6″N 080°09′52.3″W to decimal degrees entries for latitude and longitude. The position entry imported from NotMar is just a string of text giving both latitude and longitude. I needed two decimal numbers to upload into the two devices I use. To achieve this I created two user defined functions: LatDD(position) and LonDD(position). If you copy the code into your VBA editor, you can then align the numbering of the string characters so it is easy to see which parts of the string are extracted.
The functions depend on the position of each element, rather than using °, ', and " as delimiters. This could be done because NotMar is very consistent in formatting the position.
--------------------------------------------------
Public Function LatDD(PositionDMS As String) As Double
'Converts Position given in NotMar in DMS to Latitude in Decimal Degrees
'Requires PositionDMS to follow format like: 45°46'03.2"N 080°36'58.8"W
' in-string pos: 12345678901234567890123456
'this argument is a string of 26 characters and gives position with one decimal for seconds for both Lon and Lat
'will assume nothern latitude (+)
'A sister function is LonDD
Dim Degs As Double, Mins As Double, Secs As Double
Degs = Val(Left(PositionDMS, 2))
Mins = Val(Mid(PositionDMS, 4, 2))
Secs = Val(Mid(PositionDMS, 7, 4))
LatDD = Degs + Mins / 60 + Secs / 3600
End Function 'LatDD
Public Function LonDD(PositionDMS As String) As Double
'Converts Position given in NotMar in DMS to Latitude in Decimal Degrees
'Requires PositionDMS to follow format like: 45°46'03.2"N 080°36'58.8"W
' in-string pos: 12345678901234567890123456
'this argument is a string of 26 characters and gives position with one decimal for seconds for both Lon and Lat
'will assume western longitude (-)
'A sister function is LonDD
Dim Degs As Double, Mins As Double, Secs As Double
Degs = Val(Mid(PositionDMS, 14, 3))
Mins = Val(Mid(PositionDMS, 18, 2))
Secs = Val(Mid(PositionDMS, 21, 4))
LonDD = -(Degs + Mins / 60 + Secs / 3600)
End Function 'LonDD
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments