Alternate Cell Color According to Date In Cell

eglick

New Member
Joined
Dec 28, 2021
Messages
2
Office Version
  1. 2010
Platform
  1. Windows
Hello,

I have a spreadsheet where in column ‘J’ I tabulate the total daily lbs. sold. This means that when the date changes in column ‘A’, the tally in column ‘J’ starts over. To make this more readily clear for the user, I wanted to alternate the cell color in column ‘J’ as the date changes in column ‘A’. For the record, the dates are completely random and can have any sort chronological gap.

I’ve used cell conditional formatting before using the formula “A8<>A7” to highlight when days change, but that only highlights the actual date change. This formula would need to determine if the date has changed, and if the following dates are the same, to use the same fill color for those cells. Basically, the cell color needs to alternate between dates like in the mock-up below.

Alternate Fill Color.jpg


I explored using this formula “=AND(J144>=J143,A144=A143)”, but that doesn’t fully perform the needed highlights, and gives me the following results.

Alternate Fill Color2.jpg


Instead of conditionally assigning a fill color, is there a way to tell Excel to conditionally match the previous cell color?

Thank you for reading my post.
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Welcome to the MrExcel board!

For providing sample data in the future, I suggest that you investigate the following:
MrExcel has a tool called “XL2BB” that lets you post samples of your data that will allow us to copy/paste it to our Excel spreadsheets, so we can work with the same copy of data that you are. Instructions on using this tool can be found here: XL2BB Add-in

Note that there is also a "Test Here” forum on this board. This is a place where you can test using this tool (or any other posting techniques that you want to test) before trying to use those tools in your actual posts.

I would use a helper column (which could be hidden) like this.

21 12 29.xlsm
AJU
1DateAmount0
205-Aug-216,7671
305-Aug-212,2761
405-Aug-212,4111
505-Aug-213,4821
605-Aug-219,7741
707-Aug-218,1560
807-Aug-219,6540
908-Aug-211,4511
1025-Aug-212,3020
1125-Aug-211,6180
1225-Aug-215,5170
1325-Aug-214,3250
1425-Aug-217,6370
1516-Nov-215,2511
1616-Nov-211,1551
Cond Format In Groups
Cell Formulas
RangeFormula
U2:U16U2=IF(A2=A1,U1,1-U1)
Cells with Conditional Formatting
CellConditionCell FormatStop If True
J2:J16Expression=$U2textNO
 
Upvote 0
Solution
Hi Peter,

Thank you so much for your solution. Never thought of using a hidden helper column, that does the trick. I'll have to remember that on future sheets.

Thanks again, I'm off and running again. :)(y)
 
Upvote 0
You're welcome. Thanks for the follow-up. :)
 
Upvote 0

Forum statistics

Threads
1,214,591
Messages
6,120,432
Members
448,961
Latest member
nzskater

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top