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: Replacing Characters at the End of a Cell.
Written by Allen Wyatt (last updated April 5, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 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 CapDirections() For Each RCell In Selection CText = UCase(Right(RCell.Value, 3)) If CText = " NE" Or CText = " SE" _ Or CText = " SW" Or CText = " NW" Then RCell.Value = Left(RCell.Value, _ Len(RCell.Value) - 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 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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9746) 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: Replacing Characters at the End of a Cell.
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!
When you display the Find tab of the Find and Replace dialog box, you'll notice that any search, by default, will be on ...
Discover MoreTired of the Find and Replace dialog box blocking the view of your worksheet when you are searching for information? Do ...
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."
2023-04-19 10:37:56
J. Woolley
Re. RTrim, LTrim, and Trim discussed in earlier comments below, My Excel Toolbox now includes the following functions useful in cell formulas:
=TrimHead(Text,[NumChars])
=TrimTail(Text,[NumChars])
TrimHead trims leading characters from Text and returns the result. If optional NumChars < 1 (default), all leading space characters are trimmed; otherwise, NumChars leading text characters are trimmed.
TrimTail is analogous except it trims trailing characters.
Here are abbreviated versions:
Function TrimHead(Text As String, Optional NumChars As Integer) As String
If NumChars < 1 Then
TrimHead = LTrim(Text)
Else
TrimHead = Mid(Text, (NumChars + 1))
End If
End Function
Function TrimTail(Text As String, Optional NumChars As Integer) As String
If NumChars < 1 Then
TrimTail = RTrim(Text)
Else
Dim n As Integer
n = Len(Text) - NumChars
If n > 0 Then TrimTail = Left(Text, n) 'else return null default
End If
End Function
See https://sites.google.com/view/MyExcelToolbox/
2023-04-14 10:18:33
J. Woolley
@Willy Vanhaelen
I forgot about RTrim. I should have used it. Thank you for reminding me.
Curiously, RTrim and Trim are difficult to find alphabetically in Microsoft's VBA documents because they are listed with LTrim (i.e., "LTrim, RTrim, and Trim").
See https://learn.microsoft.com/en-us/office/vba/language/reference/functions-visual-basic-for-applications
2023-04-13 13:13:28
Willy Vanhaelen
@J. Woolley
Your macro is a well thought out work piece. I wonder though if you have a special reason to use a Do While Loop to remove trailing spaces (if any) instead of the RTrim function?
Adding the .SpecialCells(xlCellTypeConstants, xlTextValues) to Selection in my macro would make it more robust .
@Peter Atherton
Adding C = RTrim(C) would also make my macro more robust.
2023-04-10 11:11:51
J. Woolley
Willy's version is very clever. Here is my version. It's a little more robust and accommodates hyphenated directions like N-E.
For all text constants in Selection, capitalize the last word after deleting any hyphens if it represents one of 16 points on the compass:
Sub CapDirections3()
Dim rCell As Range, sComp() As String, sText As String, sTemp As String
Dim nChar As Integer, n As Integer
sComp = Split("N NNE NE ENE E ESE SE SSE S SSW SW WSW W WNW NW NNW")
For Each rCell In Selection.SpecialCells(xlCellTypeConstants, xlTextValues)
sText = rCell.Value
Do While Right(sText, 1) = " "
sText = Left(sText, (Len(sText) - 1))
Loop
nChar = InStrRev(sText, " ")
sTemp = UCase(Replace(Mid(sText, (nChar + 1)), "-", ""))
For n = 0 To 15
If sTemp = sComp(n) Then
rCell.Value = Left(sText, nChar) + sTemp
Exit For
End If
Next n
Next rCell
End Sub
2023-04-10 06:00:56
Peter Atherton
Willy, Nice one but I'd add a line to deal with Allen's point about typos
For Each C In Selection
C = Trim(C)
2023-04-09 14:04:52
Willy Vanhaelen
The macro in this tip does a fine job but my version hereafter uses a different approach and is a bit simpler:
Sub CapDirections2()
Dim C As Range
For Each C In Selection
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 code is almost self explanatory:
IF the 3 last characters in the cell are found in the string being searched THEN
Replace the utmost 2 characters of the cell by there upper case ones
END IF
That's it :-)
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