Counting Cells with Text Colors

Written by Allen Wyatt (last updated March 5, 2022)
This tip applies to Excel 97, 2000, 2002, and 2003


Michala has a worksheet of survey responses that includes different text in different colors. For instance, if survey response is "I dislike dogs," the word "dogs" may be colored red and the rest of the text is black. A response might have multiple colors in it, for instance in the response "I like dogs and cats," the word "dogs" may be in red and the word "cats" in blue. Michala needs a way to highlight a range of cells and count how many cells contain text of a specific color, such as red or blue.

This is best done by developing a user-defined function that can do the counting for you. The following example steps through a range of cells and counts for whatever color index value you specify.

Function CountColorIndex(rng As Range, iColor As Integer)
    Dim v As Variant
    Dim rCell As Range
    Dim str As String
    Dim sChar As String
    Dim x As Integer
    Dim iCount As Integer

    iCount = 0
    For Each rCell In rng
        v = rCell.Font.ColorIndex
        If IsNull(v) Then
            For x = 1 To Len(rCell.Value)
                If rCell.Characters(x, 1).Font.ColorIndex _
                  = iColor Then
                    iCount = iCount + 1
                    Exit For
                End If
            Next
        ElseIf v = iColor Then
            iCount = iCount + 1
        End If
    Next
    CountColorIndex = iCount
End Function

The function first looks at the font color of the cell as a whole. If the cell color is Null, that means that the color of individual characters has been changed and so the function starts looking through each character. If it finds the matching color, the count (iCount) is incremented and the function stops looking through each character.

If the cell color is not Null, then the function determines if the font color of the cell as a whole matches the desired color. If it does, then the count is incremented.

This process is repeated for each cell in the specified range, and the function then returns the value of the count. You use the function in the following manner:

=CountColorIndex(B7:D42,3)

This formula checks the range B7:D42 to see if there are instances of the color red. The count is then returned by the formula.

It is worth mentioning that the function relies on color index values. The normal, default value for red is 3 and the value for blue is 5, but these values can be modified by the user, and they may vary based on the version of Excel you are using. For the function to return the desired results, you'll need to modify the color index value, specified in the second parameter of the formula, so that it represents the color indexes used in your particular workbook.

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 (2901) applies to Microsoft Excel 97, 2000, 2002, and 2003.

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

Bogging Down with Calculated Items

Create a complex PivotTable and you may find that your system slows to a crawl. The reason for this may be due to the way ...

Discover More

Functions that Can Access Closed Workbooks

When creating a workbook, you can include formulas that reference data stored in other workbooks. Some functions will ...

Discover More

Error Opening Second Workbook

If you try to open a second workbook and you see an error message, it could be because of the way you are opening the ...

Discover More

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!

More ExcelTips (menu)

Converting Numbers Into Words

Write out a check and you need to include the digits for the amount of the check and the value of the check written out ...

Discover More

Using Seek In a Macro

When reading information from a text file, your macro may need to start reading at a place other than the beginning of ...

Discover More

Forcing Manual Calculation For a Workbook

If you have a large, complex workbook, you may want to make sure that it is always calculated manually instead of ...

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}] (all 7 characters, in the sequence shown) 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 nine more than 8?

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.

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.