Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Replacing Characters at the End of a Cell.

Replacing Characters at the End of a Cell

Written by Allen Wyatt (last updated March 19, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


2

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(LOWER(RIGHT(A1,3))=" ne", LEFT(A1,LEN(A1)-2) & "NE",
IF(LOWER(RIGHT(A1,3))=" se", LEFT(A1,LEN(A1)-2) & "SE",
IF(LOWER(RIGHT(A1,3))=" nw", LEFT(A1,LEN(A1)-2) & "NW",
IF(LOWER(RIGHT(A1,3))=" sw", LEFT(A1,LEN(A1)-2) & "SW", A1))))

This formula checks the last three characters to see if they are 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 just a bit if you approach it differently:

=IF(OR(LOWER(RIGHT(A1,3))=" ne", LOWER(RIGHT(A1,3))=" se",
LOWER(RIGHT(A1,3))=" nw", LOWER(RIGHT(A1,3))=" sw"),
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 address 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:

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 (9745) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Replacing Characters at the End of a Cell.

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

Creating a Footer

Adding a predefined footer to your worksheets is easy, and it helps convey valuable information when you make a printout. ...

Discover More

Searching for Non-Black Text

Searching for text having (or not having) specific formatting is generally pretty easy. It is more difficult to search ...

Discover More

Automatically Updating Styles

When you add formatting to some text in your document, Word may apply your formatting to every other part of your ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (menu)

Using Find and Replace to Pre-Pend Characters

Need to add some characters to the beginning of the contents in a range of cells? It's not as easy as you might hope, but ...

Discover More

Finding and Replacing in Text Boxes

Finding and replacing information in a worksheet is easy. Finding and replacing in other objects (such as text boxes or ...

Discover More

Wildcards in 'Replace With' Text

When doing searches in Excel, you can use wildcard characters in the specification of what you are searching. However, ...

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 two more than 7?

2023-04-06 13:00:28

Willy Vanhaelen

@Rick Rothstein
If you replace FIND with SEARCH and use lower case for the wind directions then the REPLACE function is skipped making the formula a bit faster in case the wind direction is already upper case. Of course this applies also to your one-liner.

=IF(ISNUMBER(FIND(RIGHT(A1,3)," ne nw se sw")),REPLACE(A1,LEN(A1)-1,2,UPPER(RIGHT(A1,2))),A1)


2022-03-19 10:58:38

Rick Rothstein

Here is a shorter formula which should work as well as the one you posted...

=IF(ISNUMBER(SEARCH(RIGHT(A1,3)," NE NW SE SW")),REPLACE(A1,LEN(A1)-1,2,UPPER(RIGHT(A1,2))),A1)

Of course, this formula will upper case letters even if they are already upper case, but I don't think that should prove to burdensome efficiency wise. As for a macro solution, here is a one-liner (albeit it a longish one) that will also work...

Sub CapDirections()

Selection = Evaluate(Replace("IF(ISNUMBER(SEARCH(RIGHT(@,3),"" NE NW SE SW"")),REPLACE(@,LEN(@)-1,2,UPPER(RIGHT(@,2))),@)", "@", Selection.Address))

End Sub


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.