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: Colors in an IF Function.
Written by Allen Wyatt (last updated November 18, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
Steve would like to create an IF statement (using the worksheet function) based on the color of a cell. For example, if A1 has a green fill, he wants to return the word "go", if it has a red fill, he wants to return the word "stop", and if it is any other color return the word "neither". Steve prefers to not use a macro to do this.
Unfortunately, there is no way to acceptably accomplish this task without using macros, in one form or another. The closest non-macro solution is to create a name that determines colors, in this manner:
=IF(GET.CELL(38,Sheet1!A1)=10,"GO",IF(GET.CELL(38,Sheet1!A1) =3,"Stop","Neither"))
With this name defined, you can, in any cell, enter the following:
=mycolor
The result is that you will see text based upon the color of the cell in which you place this formula. The drawback to this approach, of course, is that it doesn't allow you to reference cells other than the one in which the formula is placed.
The solution, then, is to use a user-defined function, which is (by definition) a macro. The macro can check the color with which a cell is filled and then return a value. For instance, the following example returns one of the three words, based on the color in a target cell:
Function CheckColor1(range) If range.Interior.Color = RGB(256, 0, 0) Then CheckColor1 = "Stop" ElseIf range.Interior.Color = RGB(0, 256, 0) Then CheckColor1 = "Go" Else CheckColor1 = "Neither" End If End Function
This macro evaluates the RGB values of the colors in a cell, and returns a string based on those values. You could use the function in a cell in this manner:
=CheckColor1(B5)
If you prefer to check index colors instead of RGB colors, then the following variation will work:
Function CheckColor2(range) If range.Interior.ColorIndex = 3 Then CheckColor2 = "Stop" ElseIf range.Interior.ColorIndex = 14 Then CheckColor2 = "Go" Else CheckColor2 = "Neither" End If End Function
Whether you are using the RGB approach or the color index approach, you'll want to check to make sure that the values used in the macros reflect the actual values used for the colors in the cells you are testing. In other words, Excel allows you to use different shades of green and red, so you'll want to make sure that the RGB values and color index values used in the macros match those used by the color shades in your cells.
One way you can do this is to use a very simple macro that does nothing but return a color index value:
Function GetFillColor(Rng As Range) As Long GetFillColor = Rng.Interior.ColorIndex End Function
Now, in your worksheet, you can use the following:
=GetFillColor(B5)
The result is the color index value of cell B5 is displayed. Assuming that cell B5 is formatted using one of the colors you expect (red or green), you can plug the index value back into the earlier macros to get the desired results. You could simply skip that step, however, and rely on the value returned by GetFillColor to put together an IF formula, in this manner:
=IF(GetFillColor(B5)=14,"Go", IF(GetFillColor(B5)=3,"Stop", "Neither"))
You'll want to keep in mind that these functions (whether you look at the RGB color values or the color index values) examine the explicit formatting of a cell. They don't take into account any implicit formatting, such as that applied through conditional formatting.
For some other good ideas, formulas, and functions on working with colors, refer to this page at Chip Pearson's website:
http://www.cpearson.com/excel/colors.aspx
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10779) 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: Colors in an IF Function.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
The IF worksheet function is very handy to make conditional evaluations. You are not limited to a single IF comparison, ...
Discover MoreEver want the IF function to only return a value if the condition it is testing is true, and not if the condition is ...
Discover MoreProgrammers know that a staple of any language is the ability to create conditional statements. Excel understands this, ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-01-22 23:48:07
dexter
There is no menu Insert -> name in Excel 2010
2017-06-25 17:44:41
n
Nice tip! I'm trying to count colors! Let's see IFF this works!
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