Written by Allen Wyatt (last updated May 3, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365
Sam has a large number of addresses in a worksheet. In those addresses he needs to make sure that all compass directions (NE, SE, NW, and SW) are all uppercase. It would be very helpful if Sam could figure out how to change any of these lowercase (or mixed case) directions that appear only at the end of a cell with their uppercase counterparts. He can't just search for a space followed by "ne", as that would change Newton to NEwton, so he wonders how he can make sure that the replacement occurs only when the letters appear at the end of a cell.
There is no way to accomplish this task using the Find and Replace tools in Excel. That means that you need to use a formula or a macro to do the task. Formulas can be used to make sure that the last two characters of a cell are uppercase:
=LEFT(A1,LEN(A1)-2) & UPPER(RIGHT(A1,2))
The problem with such a formula, however, is that it is non-discriminating. As long as any cell it is used on has a compass direction as its last two characters, there is no problem. But if some cells don't have the compass direction, then you run into problems real fast. In that case you need to actually have the formula check the last characters:
=IF(RIGHT(A1,3)=" ne", LEFT(A1,LEN(A1)-2) & "NE", IF(RIGHT(A1,3)=" se", LEFT(A1,LEN(A1)-2) & "SE", IF(RIGHT(A1,3)=" nw", LEFT(A1,LEN(A1)-2) & "NW", IF(RIGHT(A1,3)=" sw", LEFT(A1,LEN(A1)-2) & "SW", A1))))
This formula checks the last three characters to see if there is a space followed by either ne, se, nw, or sw. If this is the case, then those last two characters are made uppercase. The formula can be shortened if you approach it differently:
=IF(OR(RIGHT(A1,3)=" ne", RIGHT(A1,3)=" se", RIGHT(A1,3)=" nw", RIGHT(A1,3)=" sw"), LEFT(A1,LEN(A1)-2) & UPPER(RIGHT(A1,2)), A1)
You can shorten it even more by using an array of compass directions in the formula:
=IF(OR(RIGHT(A1,3)={" ne"," se"," sw"," nw"}), LEFT(A1,LEN(A1)-2) & UPPER(RIGHT(A1,2)), A1)
If you prefer to not use a formula, you can easily create a macro that will do the checking and conversion for you:
Sub CapDirections1() Dim C As Range For Each C In Selection CText = UCase(Right(C, 3)) If CText = " NE" Or CText = " SE" _ Or CText = " SW" Or CText = " NW" Then C = Left(C, Len(C) - 3) & CText End If Next End Sub
To use the macro, just select the cells containing the addresses, and then run it. It checks to see if one of the four compass points are at the end of the cell value, and if it is then it makes sure that the compass direction is uppercase.
You could shorten the macro somewhat by combining the compass directions in a string and then checking against that:
Sub CapDirections2() Dim C As Range For Each C In Selection C = Trim(C) If InStr(" ne se sw nw", Right(C, 3)) Then C = Replace(C, Right(C, 2), UCase(Right(C, 2))) End If Next C End Sub
The macro uses InStr to determine if the rightmost 3 characters in the cell are equal to one of the four compass directions. If so, then Replace function is used to uppercase the two rightmost characters in the cell.
You should note that these solutions are based upon there only being four possible compass directions in your addresses. If your addresses have more wide-ranging compass directions (like N or SSE) then you will definitely want to use a macro-based solution because the checking quickly becomes very complex for a formula. Here, for example, is a macro-based solution that looks at sixteen possible compass directions:
Sub CapDirections3() Dim C As Range Dim sComp() As String Dim sText As String Dim sTemp As String Dim J As Integer Dim K As Integer sComp = Split("N NNE NE ENE E ESE SE SSE S SSW SW WSW W WNW NW NNW") For Each C In Selection.SpecialCells(xlCellTypeConstants, xlTextValues) sText = RTrim(C) J = InStrRev(sText, " ") sTemp = UCase(Replace(Mid(sText, J), "-", "")) For K = 0 To 15 If sTemp = sComp(K) Then C = Left(sText, J) & sTemp Exit For End If Next K Next C End Sub
This macro is quite a bit more robust than the earlier ones. It puts the 16 compass directions into an array (sComp) and then starts stepping through the selected cells. In this case, it only looks at those cells that contain text values. The value of the cell is placed into sText, and the last location of a space in sText is determined (J). Any dashes in that trailing portion of the string are then removed. (This is done in case someone entered the directions such as N-E or W-S-W.)
The macro then checks each of the 16 compass directions to see if it matches what was pulled from the end of the cell value (sTemp). If there is a match, then the updated address is stuffed back into the cell.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9746) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Replacing Characters at the End of a Cell.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2019 For Dummies today!
Want to use Excel's Find feature to locate cells based on what those cells display? It's easy if you know how to adjust ...
Discover MoreThe Find and Replace feature in Excel is one of the workhorse editing tools you can use. When the Find and Replace dialog ...
Discover MoreFinding and replace dates contained within other text in a cell can be a bit tricky. This tip looks at some approaches to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2025 Sharon Parq Associates, Inc.
Comments