Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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.

Changing Shading when a Column Value Changes

by Allen Wyatt
(last updated April 4, 2015)

6

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:

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 (10518) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Changing Shading when a Column Value Changes.

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

Counting Non-Blank Cells

Need to count the number of cells in a range that are not blank? You can use the COUNTA function of a more complex ...

Discover More

Reversing Names In Place

Do you want a way to reverse names within a cell, making them "last, first" instead of "first last?" Here's a handy macro ...

Discover More

Using the TRUNC Worksheet Function

Want to chop off everything after a certain point in a number? The TRUNC function can help with this need.

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Applying Conditional Formatting to Multiple Worksheets

If you just updated your copy of Excel, you may have noticed some differences in how the program handles applying ...

Discover More

Diagonal Borders in a Conditional Format

Conditional formatting is a great tool for changing how your data looks based on the data itself. Excel won't allow you ...

Discover More

Finding Cells that Use Conditional Formatting

Conditional Formatting is a great boon to effectively displaying the information in your worksheets. If you want to ...

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}] 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 8 - 1?

2017-10-19 18:54:51

Peter Atherton

Marie

You need another rule

Change the formula in Column D to:
=IF(COUNTIF($A$2:$A$21,$A$2:$A$21)>1,COUNTIF($A$2:$A$21,$A$2:$A$21),"")

Not in the Conditional Format form use the formula
=D2=""
and set the fill colour to white.

This is the trouble with doing these things late at night!


2017-10-19 18:43:11

Peter Atherton

Marie

I don't know about Google spreadsheets but will assume it has the same fumctions as Excel. The formula you need is:
=COUNTIF($A$2:$A$21,$A$2:$A$21)

If you have the formula =COUNTIF($A$2:$A$21,$A$2:$A$21)>1 and apply it to the range in Conditional format, it only partly works. The Last duplicate will will not change colour.

In Excel I used a helper cell in column D to get the count. Then select the range and in the condition format form use the formula =D2>1. This works OK.

HTH


2017-10-18 05:30:23

Anders

I've tried to translate this formula to Swedish Excel 2016
=REST(PRODUKTSUMMA(--(($A$1:INDIREKT(ADRESS(RAD()-1;1;3;1))=$A$2:INDIREKT(ADRESS(RAD();1;3;1)))=FALSKT));2)

This works if entered into a cell, but if I try it as a conditional format i get the following error (translated back to English)

You may not use reference operators (such as unions, intersections, and ranges) or array constants for conditional formatting criteria

Any ideas?


2016-01-06 11:35:27

James

The code for changing row color seems to have 2 limitations.

It doesn't account for the header row (throws type mismatch).

It won't color the first row even if remove the header row to get past the mismatch error.


2015-08-10 01:55:27

Ahmed

I want to highlight a CELL based on number of times its values changed.

e.g.
1)IF the cell value is changed '2nd TIME' it should highlight "Green".

2)IF the cell value changes '3rd TIME', it should highlight "BLUE" and so on.


2015-04-09 05:44:32

Maco

Hi,

I have an excel sheet with in column A my Purchasing Orders # (PO#).
Sometime I have 5-20 rows with the same PO#.
I'd like for the spreadsheet to color all rows that have the same PO#.
Ex:
A B C
1 PO# info1 info2
2 123 bla blabla
2 123 bla blabla
2 786 bla blabla
2 907 bla blabla

I tried the very sexy formula above but doesn't work in Google Spreadsheet.
Any other idea on how I can make this happen?

Thanks a bunch.

Marie


This Site

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.

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.