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: Modifying Proper Capitalization.

Modifying Proper Capitalization

Written by Allen Wyatt (last updated May 18, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003


Like many people, Kirk copies information into Excel worksheets that originates in other places. The information that Kirk copies typically is all in CAPS, and he wants to convert it to what Excel refers to as "proper case" (only the first letter of each word is capitalized). The problem is, the PROPER worksheet function, which does the conversion, doesn't pay attention to the words it is capitalizing. Thus, words like a, an, in, and, the, and with are all initial-capped. Kirk doesn't want those words (and perhaps some others) capitalized.

There are several ways you can approach this problem. One is to use a rather long formula to do the conversion:

=SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(
SUBSTITUTE(SUBSTITUTE(PROPER($B$13);" A ";" a ");
" An ";" an ");" In ";" in ");" And ";" and ");
" The ";" the ");" With ";" with ")

Remember, this is all a single formula. It does the case conversion, but then substitutes the desired lowercase words (a, an, in, and, the, with). While this is relatively easy, the utility of the formula becomes limited as you increase the number of words for which substitutions should be done.

Perhaps a better approach is to use a user-defined function macro to do the case conversion for you. The following function checks for some common words that should not have initial caps, making sure they are lowercase.

Function MyProper(str As String)
    Dim vExclude
    Dim i As Integer
    vExclude = Array("a", "an", "in", "and", _
      "the", "with", "is", "at")

    Application.Volatile
    str = StrConv(str, vbProperCase)
    For i = LBound(vExclude) To UBound(vExclude)
        str = Application.WorksheetFunction. _
          Substitute(str, " " & _
          StrConv(vExclude(i), vbProperCase) _
          & " ", " " & vExclude(i) & " ")
    Next
    MyProper = str
End Function

Words can be added to the array, and the code automatically senses the additions and checks for those added words. Notice, as well, that the code adds a space before and after each word in the array as it does its checking. This is so that you don't have the code making changes to partial words (such as "and" being within "stand") or to words at the beginning of a sentence. You can use the function within a worksheet in this way:

=MyProper(B7)

This usage returns the modified text without adjusting the original text in B7.

If you prefer, you can use a function that takes its list of words from a named range in the workbook. The following function uses a range of cells named MyList, with a single word per cell. It presumes that this list is in a worksheet named WordList.

Function ProperSpecial(cX As Range)
' rng = target Cell

    Dim c As Range
    Dim sTemp As String

    sTemp = Application.WorksheetFunction.Proper(cX.Value)
    For Each c In Worksheets("WordList").Range("MyList")
        sTemp = Application.WorksheetFunction.Substitute( _
          sTemp, Application.WorksheetFunction.Proper( _
          " " & c.Value & " "), (" " & c.Value & " "))
    Next c

    ProperSpecial = sTemp
End Function

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 (3467) 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: Modifying Proper Capitalization.

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

Setting Fraction Bar Thickness in the Equation Editor

The Equation Editor is a great tool for easily creating fancy-looking equations in your document. You can even control ...

Discover More

Understanding Smart Cut and Paste

Editing is generally made easier by a feature that Word calls smart cut and paste. If you prefer, you can turn the ...

Discover More

Viewing Formula Results

When editing information in a cell, you may need to know the result of a portion of your formula. The shortcut described ...

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)

Reordering Last Name and First Name

If you've got a list of names in a column, you may want to change the order of each name. For instance, the name have the ...

Discover More

Repeating Cell Contents

Want to repeat cell contents over and over again within a single cell? Excel provides two ways you can duplicate the content.

Discover More

Checking for Text

Need to figure out if a particular cell contains text? You can use the ISTEXT function to easily return this bit of trivia.

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 2 + 2?

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.

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.