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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2901) applies to Microsoft Excel 97, 2000, 2002, and 2003.
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!
When reading information from a text file, your macro may need to start reading at a place other than the beginning of ...
Discover MoreIf someone sends you a worksheet that has lots of data in it, you might want to "spread out" the data so you can have ...
Discover MoreMost charts you create in Excel are based on information stored in a worksheet. You can also create charts based on ...
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 © 2024 Sharon Parq Associates, Inc.
Comments