Conditional Formatting for Groups of Observations

Mayanwolfe

New Member
Joined
Jun 5, 2013
Messages
27
Hello,

I have a large spreadsheet which contains several groups of observations as individual rows. For example, there is an "obs" column with ten rows having an observation value of "1", six rows having an observation value of "2", eight rows having an observation value of "3", and so on. For each observation group, users are expected to choose one line as a representative for that observation set. They will do this by selecting "Yes" from a drop down menu in a "Choice" column. All rows are defaulted to "No", otherwise.

In the end, each observation set will have one row with a value of "Yes", and the rest still set to "No". I would like to assist our users by providing some conditional formatting as a visual cue. For observation sets with all values still set to "No", I would like the rows belonging to that observation set in the "Choice" column to be highlighted yellow. Once they have chosen a "yes" row in the set, I would like those values to turn green. If they choose two "Yes" values for a set, the "Choice" column values for that set should turn red to indicate they have chosen too many representatives for that set.

The trouble I am having is getting the conditional formatting to recognize the observation sets as individual groups within the full data set. Since this sheet will be given to many users and distributed over online platforms, I would prefer to use formulas to accomplish this instead of macros.

I have a small sample sheet prepared that will perhaps illustrate what I am trying to do a bit better, if someone can advise me how to upload it.

I appreciate your time and suggestions!

Mayan
 

Excel Facts

Easy bullets in Excel
If you have a numeric keypad, press Alt+7 on numeric keypad to type a bullet in Excel.
You could upload a copy of your file to a free site such www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. If the workbook contains confidential information, you could replace it with generic data.
 
Upvote 0
Thanks Dante,

Here is the link to my example file. The data has been simplified and anonymized with random ID values. As you can see, each group of observations (column A) with all "No's" is highlighted yellow, while each group with one "Yes" is highlighted green. However, each group with more that one "Yes" is highlighted red, and has an X next to all of the "Yes" values. The X isn't strictly necessary, but would be nice to help users locate the erroneous selections.

https://www.dropbox.com/s/fyoapvreul9e2x3/Conditional Formatting for MD Template.xlsx?dl=0

Thank you!
 
Upvote 0
Thanks Dante,

Here is the link to my example file. The data has been simplified and anonymized with random ID values. As you can see, each group of observations (column A) with all "No's" is highlighted yellow, while each group with one "Yes" is highlighted green. However, each group with more that one "Yes" is highlighted red, and has an X next to all of the "Yes" values. The X isn't strictly necessary, but would be nice to help users locate the erroneous selections.

https://www.dropbox.com/s/fyoapvreul9e2x3/Conditional Formatting for MD Template.xlsx?dl=0

Thank you!

Put these formulas in conditional formats

Red =COUNTIF($A$2:$A$61,A2)-COUNTIFS($A$2:$A$61,A2,$D$2:$D$61,"No")>1
Gree =COUNTIF($A$2:$A$61,A2)-COUNTIFS($A$2:$A$61,A2,$D$2:$D$61,"No")=1
Yellow =COUNTIF($A$2:$A$61,A2)=COUNTIFS($A$2:$A$61,A2,$D$2:$D$61,"No")

Applies to:
=$D$2:$D$61

---
Change 61 for the last row with data
---

File test:
https://www.dropbox.com/s/5b0gkpwy1f3stqo/Conditional Formatting for MD Template.xlsx?dl=0
 
Upvote 0

Forum statistics

Threads
1,223,886
Messages
6,175,198
Members
452,616
Latest member
intern444

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