Written by Allen Wyatt (last updated April 12, 2025)
This tip applies to Excel 97, 2000, 2002, and 2003
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
Note:
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.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Character codes are the numeric values used, by a computer, to signify various alphanumeric characters. You can use the ...
Discover MoreThe process of combining string (text) values to make a new string is called concatenation. Excel provides the ...
Discover MoreYou can use the CLEAN worksheet function to remove any non-printable characters from a cell. This can come in handy when ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments