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.
Written by Allen Wyatt (last updated July 7, 2021)
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.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Changing the capitalization of text is, believe it or not, a common task in Excel. Common or not, it can be frustrating ...
Discover MoreNeed to know the character value of the first character in a string? It's easy to do, without using a macro, by using the ...
Discover MoreThe PROPER worksheet function is used to change the case of text so that the first letter of each word is capitalized. If ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-11-23 12:19:56
Willy Vanhaelen
@Jaisu
A user defined function must be placed in a module. You probably put it in a sheet's code page.
2017-11-21 12:43:24
jaisu
Hey,
I've been trying to incorporate this function into my VBA editor but whenever I try to use it i get a #NAME? error. What could be causing this?
2017-03-08 00:57:26
Violet
Hi, is it possible to use this from a macro sub and on a "selection" of cells?
2017-02-15 07:35:15
Willy Vanhaelen
@Tharum
Here is an example of how to do it:
Sub test()
Dim A_title As String, Result As String
A_title = "a title test of a test string"
Result = Title(A_title)
MsgBox Result
End Sub
To make it work in the macro of my post of 19 December 2016:
change: Function Title(ByVal ref As Range) As String
to: Function Title(ByVal ref As String) As String
2017-02-14 13:11:54
Tharun
how to call this function from macro Sub instead of typing =title (A1) in the worksheet, can you please help
2016-12-19 10:12:12
Willy Vanhaelen
Oops!!!
In the 6th line:
correct -> For i = 2 To UBound(vaArray)
to -> For i = 1 To UBound(vaArray)
So here it is again:
Function Title(ByVal ref As Range) As String
Dim i As Integer, J As Integer
Dim vaArray As Variant, vaLCase As Variant
vaLCase = Array("a", "an", "and", "in", "is", "of", "or", "the", "to", "with")
vaArray = Split(StrConv(ref, 3), " ")
For i = 1 To UBound(vaArray)
For J = LBound(vaLCase) To UBound(vaLCase)
If LCase(vaArray(i)) = vaLCase(J) Then
vaArray(i) = vaLCase(J)
End If
Next J
Next i
Title = Join(vaArray, " ")
End Function
2016-12-19 10:05:56
Willy Vanhaelen
@Don
You are right but you didn't notice that the first loop:
For i = 2 To UBound(vaArray)
is also wrong. It should be:
For i = 1 To UBound(vaArray)
It starts with 1 instead of 0 because the first word must not be checked, it has to be always proper case.
The 'rebuild sentence' part can be reduced to only one line (not for Excel 97):
Title = Join(vaArray, " ")
So I rewrote the macro and simplfied it a bit:
Function Title(ByVal ref As Range) As String
Dim i As Integer, J As Integer
Dim vaArray As Variant, vaLCase As Variant
vaLCase = Array("a", "an", "and", "in", "is", "of", "or", "the", "to", "with")
vaArray = Split(StrConv(ref, 3), " ")
For i = 2 To UBound(vaArray)
For J = LBound(vaLCase) To UBound(vaLCase)
If LCase(vaArray(i)) = vaLCase(J) Then
vaArray(i) = vaLCase(J)
End If
Next J
Next i
Title = Join(vaArray, " ")
End Function
2016-12-18 14:40:21
Don
When I got to the 'rebuild sentence' part of the macro, it skipped the first word. I figured out that the line:
For i = 1 To UBound(vaArray)
should have been:
For i = 0 To UBound(vaArray)
since the first element in vaArray is 0.
However, when I feed it the phrase "what the world needs now is love", it capitalizes the second word "The" but should not. In face, whatever word I put in second position is capitalized. I'm pretty sure it's an array numbering thing, but I get lost in the incrementing i and j variables.
What am I not seeing?
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 © 2024 Sharon Parq Associates, Inc.
Comments