Count Cells Based on Formatting/Color

Denzel777

New Member
Joined
Jun 9, 2022
Messages
3
Office Version
  1. 2013
Platform
  1. Windows
Hi,

I am trying to get a sum of particular cells based upon their color. I have conditionally formatted cells to be Red, Yellow or Green based up the date a report was submitted, based upon the date is was due.

For example A1 contains the day an audit was carried out. Staff have 5 working days from the date in A1. The actual date the reported is submitted is the entered into B1 manually. If it is within 5 working days, it turns green as it is timely. If it is submitted after 5 working days, it turns yellow as it was late. If A1 contains a date and the report submission date is blank, the report is outstanding and stays red until a date is entered. If A1 is blank, B1 stays blank. I have got all the conditionally formatting working for this.

What I now require is a total sum of timely (Green), Late (Yellow), and Outstanding (Red), purely based on the format of each cell.

I cannot find how to do this.

The alternative I have is to add an additional column, C1, where I can record, Yes, No or N/A based upon the content of B1. Yes being Green, No being Yellow and N/A being Red. I can then use the COUNTIF function to collate the results from C1. I do not know how to generate the N/A in the same IF function however so can only get Yes or No based upon the Date range.

I would very much appreciate a solution to either the sum count based on formatting, or alternatively by using the additional column but need help generating the correct formula to provide three outcomes.

I have included an exemplar below to help explain. As you can see, both Yellow and Red is generating No which would give me incorrect values as totals.

1654763961872.png


Thank you in advance for your help!
 

Excel Facts

Create a Pivot Table on a Map
If your data has zip codes, postal codes, or city names, select the data and use Insert, 3D Map. (Found to right of chart icons).
Hello,

I did some research and I also cannot find an easy way to count based on cell color. There are ways to do it, but it looks like it requires workarounds and filters. Personally, I would just use the helper column as you suggested.

For your Yes/No/N/A,
=IF(ISBLANK(C3),"N/A",IF(C3-B3>5,"No","Yes"))

For your Countif,
=COUNTIF(D3:D5,"Yes")
=COUNTIF(D3:D5,"No")
=COUNTIF(D3:D5,"N/A")

I hope this helps.
 
Upvote 0
if you use the same rules as conditional formatting , then you are not trying to use the fill colour

for example
Green
=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>=1),--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)<=5))

Amber
=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>5))
Red
=COUNTIFS(A2:A22,"<>",B2:B22,"")

does that work for you ????

Book2
ABCDEFG
1GreenredAmber
26/30/227/3/22green622
36/21/22red
46/16/226/24/22amber
56/1/226/2/22
66/2/22
76/3/226/4/22
86/4/226/12/22
96/5/226/6/22
106/6/226/20/22
116/7/226/8/22
Sheet1
Cell Formulas
RangeFormula
E2E2=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>=1),--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)<=5))
F2F2=COUNTIFS(A2:A22,"<>",B2:B22,"")
G2G2=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>5))
 
Upvote 0
Hello,

I did some research and I also cannot find an easy way to count based on cell color. There are ways to do it, but it looks like it requires workarounds and filters. Personally, I would just use the helper column as you suggested.

For your Yes/No/N/A,
=IF(ISBLANK(C3),"N/A",IF(C3-B3>5,"No","Yes"))

For your Countif,
=COUNTIF(D3:D5,"Yes")
=COUNTIF(D3:D5,"No")
=COUNTIF(D3:D5,"N/A")

I hope this helps.
Thank you! This works perfectly and I can hide the C3 cell.
 
Upvote 0
if you use the same rules as conditional formatting , then you are not trying to use the fill colour

for example
Green
=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>=1),--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)<=5))

Amber
=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>5))
Red
=COUNTIFS(A2:A22,"<>",B2:B22,"")

does that work for you ????

Book2
ABCDEFG
1GreenredAmber
26/30/227/3/22green622
36/21/22red
46/16/226/24/22amber
56/1/226/2/22
66/2/22
76/3/226/4/22
86/4/226/12/22
96/5/226/6/22
106/6/226/20/22
116/7/226/8/22
Sheet1
Cell Formulas
RangeFormula
E2E2=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>=1),--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)<=5))
F2F2=COUNTIFS(A2:A22,"<>",B2:B22,"")
G2G2=SUMPRODUCT(--(NETWORKDAYS($A$2:$A22+0,$B$2:$B22+0)>5))
Wow! This is fantastic and removes the need for the additional column. Thank you so much!
 
Upvote 0
you are welcome , sometimes though a helper column can be helpful to see if you dont get the correct answer and why
 
Upvote 0

Forum statistics

Threads
1,214,905
Messages
6,122,174
Members
449,071
Latest member
cdnMech

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