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: Making PROPER Skip Certain Words.

Making PROPER Skip Certain Words

by Allen Wyatt
(last updated December 17, 2016)

Terry uses the PROPER worksheet function all the time to change the case of text in his worksheets. He wonders if there is a way to instruct the function to ignore certain words, so that they aren't started with a capital letter. It is not unusual for him to have to go back after using PROPER and change words like "the" or "an" to all lowercase. If PROPER could skip changing such words automatically, it would be a big help.

One way to approach this is to use the SUBSTITUTE worksheet function in conjunction with the PROPER function. For instance, if you wanted to find instances of the word "The" with "the", you could use the following:

=SUBSTITUTE(PROPER(A1)," The "," the ")

Note the inclusion of the space before and after what you are searching for and what you are replacing. This insures that only full words are modified. It also makes sure that no changes are made at the beginning of the cell value or at the end.

If you wanted to search for other words that needed replacing, you can simply increase the number of instances of SUBSTITUTE in the formula:

=SUBSTITUTE(SUBSTITUTE(SUBSTITUTE(PROPER(A1)," The ",
" the ")," An "," an ")," And "," and ")

This can obviously get a bit awkward if you have a lot of words you want to exclude from being modified. In that case you'll need to resort to using a macro. The following macro, written as a user-defined function, can be used to convert all words in a cell to initial caps (just like PROPER), but make sure that certain defined words are lowercase.

Function Title(ByVal ref As Range) As String
    Dim vaArray As Variant
    Dim c As String
    Dim i As Integer
    Dim J As Integer
    Dim vaLCase As Variant
    Dim str As String

    ' Array contains terms that should be lower case
    vaLCase = Array("a", "an", "and", "in", "is", _
      "of", "or", "the", "to", "with")

    c = StrConv(ref, 3)
    'split the words into an array
    vaArray = Split(c, " ")
    For i = 2 To UBound(vaArray)
        For J = LBound(vaLCase) To UBound(vaLCase)
            ' compare each word in the cell against the
            ' list of words to remain lowercase. If the
            ' Upper versions match then replace the
            ' cell word with the lowercase version.
            If UCase(vaArray(i)) = UCase(vaLCase(J)) Then
                vaArray(i) = vaLCase(J)
            End If
        Next J
    Next i

  ' rebuild the sentence
    str = ""
    For i = 1 To UBound(vaArray)
        str = str & " " & vaArray(i)
    Next i

    Title = Trim(str)
End Function

To use the macro, all you need to do is use the following in your worksheet:

=Title(A1)

If you get an error when you try to run this macro, chances are good that you are using Excel 97. The Split function was not added until Excel 2000, so Excel 97 users will get an error. If you do, then add the following macro which emulates what the Split function does.

Function Split(Raw As String, Delim As String) As Variant
    Dim vAry() As String
    Dim sTemp As String
    Dim J As Integer
    Dim Indx As Integer

    Indx = 0
    sTemp = Raw
    J = InStr(sTemp, Delim)
    While J > 0
        Indx = Indx + 1
        ReDim Preserve vAry(1 To Indx)
        vAry(Indx) = Trim(Left(sTemp, J))
        sTemp = Trim(Mid(sTemp, J, Len(sTemp)))
        J = InStr(sTemp, Delim)
    Wend
    Indx = Indx + 1
    ReDim Preserve vAry(1 To Indx)
    vAry(Indx) = Trim(sTemp)
    Split = vAry()
End Function

You can also find an additional approach on accomplishing the desired conversion at this site:

http://dmcritchie.mvps.org/excel/proper.htm

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10559) 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: Making PROPER Skip Certain Words.

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

Iterating Circular References

Does your data require that you perform calculations using circular references? If so, then you'll want to be aware of the ...

Discover More

Printing Based on Cell Contents

Would you like to have a worksheet automatically printed when a particular cell contains a specified value? You can achieve ...

Discover More

Data Source File in Word 2003

The security features introduced in Word 2003 resulted in a change in the dialog boxes you see when opening mail-merge source ...

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)

Specifying Proper Case

If you need to change the case of letters in a cell, one of the functions you can use is the PROPER function. This tip ...

Discover More

Returning the Left-most Characters

When working with text in a formula, you may need to extract the left-most characters from a string of text or from a cell. ...

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