Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Changing Shading when a Column Value Changes.
Written by Allen Wyatt (last updated November 27, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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 (10518) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Changing Shading when a Column Value Changes.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
The Conditional Formatting capabilities of Excel are powerful. This tip shows how you can use a simple approach to ...
Discover MoreWhen you compare dates in a conditional formatting rule, you need to be careful how you put your comparisons together. Do ...
Discover MoreConditional formatting is a great tool for changing the format of cells based on whether certain conditions (rules) are ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-12-18 13:03:13
Hello. The formula in cell Z is not performing the task as defined by Doug. The request was to highlight all the rows for the 1st part number; do not apply highlighting for the 2nd part number; apply highlighting for the 3rd part number. When I use this formula, it highlights only one cell for part 1, then highlights the cell for part 2 (because the part number changed); then highlights the first cell for part 3 (because the part number changed).
2021-11-27 12:58:33
J. Woolley
My Excel Toolbox includes the following function:
=SetFill(Color, PatternStyle, PatternColor, Target)
When this function appears in a cell formula, it will set the Target range's fill properties. All parameters are optional. Missing property parameters are not changed; if Target is missing, the formula's cell is assumed.
Using this function might be more convient than conditional formatting or the Tip's macro. When used with an IF(...) function to set or reset fill properties, it returns an empty string ("") in a text formula, zero (0) in a numeric formula, or FALSE in a boolean formula.
For the Tip's example with part numbers in column A and 0 or 1 in helper column Z, this formula could be added to cell AA2 then copied down column AA and subsequently hidden:
=IF(Z2=1,SetFill("green",,"auto",A2),SetFill("none",,"none",A2))&CELL("type",A2)
The CELL function makes the formula Volatile, so shading in column A will update when recalculated (F9).
See https://sites.google.com/view/MyExcelToolbox/
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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