Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Modifying Proper Capitalization

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.

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

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.

Related Tips:

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!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

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

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.