Results 1 to 4 of 4

Thread: Conditional Formatting for Groups of Observations
Thanks Thanks: 0 Likes Likes: 0

  1. #1
    New Member
    Join Date
    Jun 2013
    Posts
    16
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Conditional Formatting for Groups of Observations

    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

  2. #2
    Board Regular DanteAmor's Avatar
    Join Date
    Dec 2018
    Location
    México
    Posts
    4,475
    Post Thanks / Like
    Mentioned
    41 Post(s)
    Tagged
    12 Thread(s)

    Default Re: Conditional Formatting for Groups of Observations

    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.
    Regards Dante Amor

  3. #3
    New Member
    Join Date
    Jun 2013
    Posts
    16
    Post Thanks / Like
    Mentioned
    0 Post(s)
    Tagged
    0 Thread(s)

    Default Re: Conditional Formatting for Groups of Observations

    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/fyoapvreul...late.xlsx?dl=0

    Thank you!

  4. #4
    Board Regular DanteAmor's Avatar
    Join Date
    Dec 2018
    Location
    México
    Posts
    4,475
    Post Thanks / Like
    Mentioned
    41 Post(s)
    Tagged
    12 Thread(s)

    Default Re: Conditional Formatting for Groups of Observations

    Quote Originally Posted by Mayanwolfe View Post
    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/fyoapvreul...late.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/5b0gkpwy1f...late.xlsx?dl=0
    Regards Dante Amor

Some videos you may like

User Tag List

Tags for this Thread

Like this thread? Share it with others

Like this thread? Share it with others

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •