Written by Allen Wyatt (last updated December 23, 2023)
This tip applies to Excel 97, 2000, 2002, and 2003
Doug has a data table that includes a column of part numbers. This data is sorted by the part numbers column. The part numbers are not unique; for instance, some part numbers appear three times in the table and others appear five times. Doug would like to format the table so that the rows of the table have a "green bar" effect.
For instance, the first five rows may have the same part number, so Doug wants those rows to be shaded green. The next two rows have a different part number, so he wants those to have no green shading. The next three rows have the next part number, so those should be green again, and so on. Every time the part number changes, the shading of the row (green or not green) should change.
One easy way to accomplish this task is to create a helper column that displays either a 0 or a 1 depending upon the part number in column A. For instance, let's say you wanted to put your helper column in column Z. You could put the following formula in cell Z2:
=IF(A2=A1,Z1,1-Z1)
Copy the formula down column Z for each row in your data table. When done, column Z will contain either 1 or 0, switching only when the part number in column A changes. You can then use the value in column Z as a controlling value for your conditional formatting. All you need to do is set the formula in the format so that if column Z contains 1, then your cells are green.
You should note that once your conditional formatting is set up and working properly, you can hide column Z so that it isn't a distraction to anyone using your data table.
If you can't use a helper column for some reason, then there is a pretty cool formula you can use in the conditional format itself. Just make sure your data table is sorted by column A (the part numbers) and then select all the cells in the table, with the exception of any column headers. Then define a conditional format that uses this formula:
=MOD(SUMPRODUCT(--(($A$1:INDIRECT(ADDRESS(ROW()-1,1,3,1)) =$A$2:INDIRECT(ADDRESS(ROW(),1,3,1)))=FALSE)),2)
Remember that this is a single formula, entered in the conditional formatting rule, all on one line. This formula assumes that the part numbers are in column A and that the data table begins in cell A2. Further, if you delete any rows in the data table, you'll want to reapply the conditional format to all the cells in the data table.
Finally, there are any number of macros that you could write to apply the formatting. All you need to do is have the macro step through the cells in column A, determining whether the part number changes, and then apply the correct formatting based on what it finds out. Here is an example:
Sub ShadeRows() Dim ThisOrder As Long Dim PrvOrder As Long Dim LastRow As Long Dim Clr As Integer Dim R As Long LastRow = ActiveSheet.Range("A" & Rows.Count).End(xlUp).Row ' Enter desired color codes here ' (24 is Lavender, 35 is Light Green) RwColor = Array(24, 35) Clr = 0 ' Used to toggle between the two colors For R = 2 To LastRow ThisOrder = Cells(R, 1).Value PrvOrder = Cells(R - 1, 1).Value If ThisOrder <> PrvOrder Then Clr = 1 - Clr ' Select only the columns that are used Range("A" & R & ":M" & R).Select Selection.Interior.ColorIndex = RwColor(Clr) Next R End Sub
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10517) 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: Changing Shading when a Column Value Changes.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
Conditional formatting is a great tool. You may need to use this tool to tell the difference between cells that are empty ...
Discover MoreConditional formatting is very powerful, but at some point you may want to make the formatting "unconditional." In other ...
Discover MoreThe conditional formatting capabilities of Excel are very helpful when you want to call attention to different values ...
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 © 2025 Sharon Parq Associates, Inc.
Comments