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

by Allen Wyatt
(last updated June 27, 2015)

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.

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

Understanding Microdermabrasion

Want smoother, healthier-looking skin? Some people think you can achieve it with microdermabrasion treatments.

Discover More

Removing Borders

Need to get rid of the borders around a cell? The shortcut in this tip can make quick work of this formatting task.

Discover More

Paragraph Formatting Shortcuts

Paragraphs are one of the elemental building blocks in a Word document. Formatting those paragraphs is easy to do if you ...

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 Error Values

Want to get rid of error values in your worksheet? There are a couple of ways you can approach this particular challenge, as ...

Discover More

Find and Replace in Headers

Using Find and Replace is something quite routine in Excel, as it easily allows you to find and replace information in your ...

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 for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)

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.

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.

Links and Sharing
Share