Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Making PROPER Skip Certain Words.

Making PROPER Skip Certain Words

by Allen Wyatt
(last updated July 12, 2014)

6

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 = (LBound(vaArray)+1) 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 = LBound(vaArray) 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)

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

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

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 (10560) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel 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

Overcoming Automatic Word Selection

When you select text with the mouse, Word usually selects entire words for you. If you don't want to do this, you can use ...

Discover More

Controlling Repagination in Macros

Want to turn off document repagination while your macro does its work? Here are two approaches you can use.

Discover More

Adding Diagonal Borders

Want to add a border diagonally, through the middle of a table cell? It's easy if you follow the formatting steps ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

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

Calculating the Day of the Year

Need to know what day of the year a certain date is? You can figure it out easily using the formulas in this tip.

Discover More

Using a Week Number as One Criterion in a Formula

The SUMIFS function can be quite powerful in conditionally summing information based on criteria you specify. This tip ...

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}] 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 six more than 8?

2018-11-07 11:05:01

J. Woolley

Here is my version of the Title function, which uses two modified versions of Excel's PROPER function. (Apologies for poor VBA formatting when posting comments at this site.)

=====================

Public Function Title(ByVal Text As Variant) As Variant
'
' Return Text converted to title case, for example
' Now Is the Time for All Good Men to Come to the Aid of Their Country
' The rules for title case are varied and imprecise,
' so carefully review the results of this function
' see http://capitalizemytitle.com/
' For best results, all Text words should be lower case except
' words that must be capitalized like IBM or iPhone or McDonald's
'
' Example of Text followed by Title(Text):
' my "old-lady" isn't at McDonald's with her 2nd 'Apple-PC' (a.k.a. iPhone)
' My "Old-Lady" Isn't at McDonald's with Her 2nd 'Apple-PC' (A.K.A. iPhone)
'
' Nov 2018 by J. Woolley
'
Dim sText() As String, sWords() As String, sLower() As String
Dim sHash As String, c As String
Dim last As Integer, i As Integer, j As Integer

If WorksheetFunction.IsError(Text) Then
Title = Text ' return same error (like Excel's PROPER function)
Exit Function
End If

' split Text into an array of words (space character is assumed delimiter)
sText = Split(Text) ' Split() arrays are Base 0 (ignoring Option Base...)

' convert Text to proper case, then split that into an array of words
sWords = Split(ProperY(Text))
last = UBound(sWords)

' split those that should be lower case into an array of words plus a hash string
sLower = Split("A An And As At But By For From In Nor Of On Or So The To Up With")
sHash = ""
For j = 0 To UBound(sLower)
sHash = sHash + Left(sLower(j), 1) ' concatenate first letters
Next j

' update words that should be lower case (except first and last words)
For i = 1 To (last - 1)
If sWords(i) <> vbNullString Then
c = Left(sWords(i), 1) ' first letter of word
j = 0
Do While True
j = InStr((j + 1), sHash, c) ' look for first letter in sLower hash string
If j = 0 Then
Exit Do
ElseIf sWords(i) = sLower(j - 1) Then ' should be lower case
sWords(i) = LCase(sWords(i))
Exit Do
End If
Loop
End If
Next i

' unless Text is all caps, restore words like IBM or iPhone or McDonald's
If Not (Text = UCase(Text)) Then
For i = 0 To last ' look for a capitalized letter after the first character
If sText(i) Like "?*[A-Z]*" Then sWords(i) = sText(i)
Next i
End If

' rebuild the final text
Title = Join(sWords)

End Function

Public Function ProperX(ByVal Text As Variant) As Variant
'
' Return Text converted to proper case like Excel's PROPER(Text)
' except after digit or apostrophe
'
' Example of Text then PROPER(Text) then ProperX(Text) then VBA's StrConv:
' my "old-lady" isn't at McDonald's with her 2nd 'Apple-PC' (a.k.a. iPhone)
' My "Old-Lady" Isn'T At Mcdonald'S With Her 2Nd 'Apple-Pc' (A.K.A. Iphone)
' My "Old-Lady" Isn't At Mcdonald's With Her 2nd 'apple-Pc' (A.K.A. Iphone)
' My "old-lady" Isn't At Mcdonald's With Her 2nd 'apple-pc' (a.k.a. Iphone)
'
' Nov 2018 by J. Woolley
'
Dim s As String, c2 As String
Dim i As Integer, last As Integer

If WorksheetFunction.IsError(Text) Then
ProperX = Text ' return same error (like Excel's PROPER function)
ElseIf WorksheetFunction.IsNonText(Text) Then
If IsDate(Text) Then Text = CLng(Text) ' convert to long (like PROPER)
ProperX = CStr(Text) ' convert to string (like PROPER)
Else
s = WorksheetFunction.Proper(Text)
last = Len(s) - 1
For i = 1 To last
c2 = Mid(s, i, 2) ' this character and next character
If (c2 Like "'[A-Z]") Or (c2 Like "#[A-Z]") Then
s = Left(s, (i - 1)) + LCase(c2) + Right(s, (last - i))
i = i + 1 ' skip next character (because it's a letter)
End If
Next i
ProperX = s
End If

End Function

Public Function ProperY(ByVal Text As Variant) As Variant
'
' Return Text converted to proper case like ProperX(Text)
' except words with initial apostrophe
'
' Example of Text then PROPER(Text) then ProperX(Text) then ProperY(Text):
' my "old-lady" isn't at McDonald's with her 2nd 'Apple-PC' (a.k.a. iPhone)
' My "Old-Lady" Isn'T At Mcdonald'S With Her 2Nd 'Apple-Pc' (A.K.A. Iphone)
' My "Old-Lady" Isn't At Mcdonald's With Her 2nd 'apple-Pc' (A.K.A. Iphone)
' My "Old-Lady" Isn't At Mcdonald's With Her 2nd 'Apple-Pc' (A.K.A. Iphone)
'
' Nov 2018 by J. Woolley
'
Dim s As String, c3 As String
Dim i As Integer, last As Integer

If WorksheetFunction.IsError(Text) Then
ProperY = Text ' return same error (like Excel's PROPER function)
Else
s = " " + ProperX(Text) ' add initial space in case it begins with apostrophe
last = Len(s) - 2
For i = 1 To last
c3 = Mid(s, i, 3) ' this character and next two characters
If (c3 Like " '[a-z]") Then
s = Left(s, (i - 1)) + UCase(c3) + Right(s, (last - i))
i = i + 2 ' skip next two characters (apostrophe-letter)
End If
Next i
ProperY = Right(s, last + 1) ' strip initial space (see above)
End If

End Function

=====================

These functions are included in the exported module text file M_Miscellaneous.bas, which can be imported into your Excel VBAProject. That file can be downloaded from Google Drive here:
https://drive.google.com/open?id=16c3dz00carhoykC5-AXFDoVDY7FhtX2e


2018-10-15 17:58:08

Peter Atherton

Herman

On second thoughts you could enter the names in the array to normally change to lower case. e.g. ABC Cinemas Ltd you might want to enter ABC into the vaArray (in Allen's code). Or with my version the name ABC Cinemas Ltd returns the same format because ABC is not listed in the words to change I have not tested with the original.


2018-10-15 03:45:00

Peter Atherton

Herman

You can, but each noun must be specified, see my post 6 Jan 2015 and the Special cases.


2018-10-15 00:38:13

Herman

Can I also set exceptions for some proper nouns?


2015-06-04 08:33:57

John K

I'm interested in this, however I can't use macros in my case. Is it possible to use an array formula for this.. i.e. create a table of exclusions, and use that to exclude the specific words?


2015-01-06 18:43:56

Peter Atherton

Here is my version of Title case.

Function Title(ByVal ref As Range, Optional bFormal As Boolean = True) As String
'Thanks to Jim Cone who pointed out that the original function _
did not deal with hyphens & upper case words such as 'IBM' or indeed Mcs and Macs.
'Completed 5 Jan 2015
'
Dim vaArray As Variant
Dim LLo As Long, LMid As Long, LHi As Long
Dim c As String, sTemp As Variant
Dim i As Integer, iWrdCap As Variant
Dim iPos As Integer, iMc As Integer, _
iMac As Integer, iHyphen As Integer
Dim vaLCase As Variant
Dim Str As String, sChr As String

'Is there a capitalised word in the reference? e.g. IBM or BAE _
if so find out its position for later
sTemp = Split(ref, " ")
iWrdCap = ""
For i = LBound(sTemp) To UBound(sTemp)
If sTemp(i) = StrConv(sTemp(i), vbUpperCase) Then
iWrdCap = i
Exit For
End If
Next i

' Array contains terms that should be lower case
vaLCase = Array("A", "Am", "An", "And", "Be", "Der", "Do", "Du", "In", "Is", _
"Me", "My", "Of", "On", "Or", "She", "Than", "The", "To", "Van", "Von", "We", "with")

If bFormal Then
c = WorksheetFunction.Proper(ref)
Else
c = StrConv(ref, vbProperCase)
End If
'=======================================
'Special Cases
iMac = InStr(1, c, "Mac")
If iMac > 0 Then
Mid(c, iMac + 3, 1) = UCase(Mid(c, iMac + 3, 1))
End If

iMc = InStr(1, c, "Mc")
If iMc > 0 Then
Mid(c, iMc + 2, 1) = UCase(Mid(c, iMc + 2, 1))
End If

iPos = InStr(1, c, "-On-")
If iPos > 0 Then
c = Replace(c, "-On-", "-on-")
End If

iHyphen = InStr(1, c, " - ")
If iHyphen > 0 Then
c = Replace(c, " - ", "-")
End If
'=======================================
'split the words into an array
vaArray = Split(c, " ")

'i ignores the first value - that should be Proper case
For i = 1 To UBound(vaArray)
LLo = LBound(vaLCase)
LHi = UBound(vaLCase)
If Right(vaArray(i), 1) Like "[',.]" Then
sChr = Left(vaArray(i), Len(vaArray(i)) - 1)
Else
sChr = vaArray(i)
End If

'Binary Search for sChr
Do Until LLo > LHi
'Find the midpoint of the array
LMid = (LLo + LHi) 2
If sChr = vaLCase(LMid) Then
'sChr is found so return the location & quit loop
vaArray(i) = LCase(sChr)
Exit Do

ElseIf sChr < vaLCase(LMid) Then
'sFind is higher than mid-point so _
throw away the top half
LHi = LMid - 1
Else
'sFind is lower than than mid-point so _
discard the bottom half
LLo = LMid + 1
End If

Loop


Next i

' rebuild the sentence
Str = ""
For i = LBound(vaArray) To UBound(vaArray)
If i = iWrdCap Then
Str = Str & " " & UCase(vaArray(i))
Else:
Str = Str & " " & vaArray(i)
End If
Next i


Title = Trim(Str)
End Function

Enter the formula as =Title(a1) to use the application.Proper function as the working basis. or =Title(a1,False) to use visual basic's strConv function.

StrConv will return I'd as I'd where the Proper function returns I'D.

In most cases False is not required.


This Site

Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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.