+ Reply to Thread
Results 1 to 6 of 6

Multiple Conditions & Lookup, Conditional Formatting

  1. #1
    Registered User
    Join Date
    04-19-2010
    Location
    Florida, USA
    MS-Off Ver
    Excel 2007
    Posts
    4

    Multiple Conditions & Lookup, Conditional Formatting

    Hi

    New to the forum and I am so helping that one of you Excel Gods can show me the error of my ways...so I can go home some time this evening! I like my job...but this is getting crazy! Needless to say that I have been struggling for some time now...you could probably guess that I am generaly reluctant to ask for help---but, I now know...I need help desperately!

    I know that this is probably pretty basic but it has me stumped.

    Here is what I need to accomplish.

    I have a template that generates a % based on inputs--lets say that this value is in cell K3. Depending on another criteria (that is user entered and is in J3) we have established acceptable ranges for the calculated %.

    For example if cell J3 = A then if the % in cell K3 is less than 5% it is red, between 5 & 10% it is yellow and greater than 10% it is green. This stop light conditional formatting needs to take place in cell L3.

    There are 12 different values that one can select from a drop down list for J3.

    To make it simpler--I am posting an attachment.

    Please help! I am using Excel 2003

    Thanks in advance
    Attached Files Attached Files
    Last edited by mancinl; 04-20-2010 at 09:47 AM. Reason: Solved

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Struggle with Multiple Conditions & Look Up Plus Cond. Format Results

    One suggestion could be to fill in your table in C14:R24 with the actual words, "Green", "Yellow" and "Red" in the appropriate spots (without quotes)

    Then change your conditional formatting to Formula is:

    =INDEX($C$15:$R$24,MATCH(J3,$B$15:$B$24,0),MATCH(K3*100,$C$14:$R$14))="Green"

    =INDEX($C$15:$R$24,MATCH(J3,$B$15:$B$24,0),MATCH(K3*100,$C$14:$R$14))="Yellow"

    =INDEX($C$15:$R$24,MATCH(J3,$B$15:$B$24,0),MATCH(K3*100,$C$14:$R$14))="Red"

    for the respective colours
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Forum Expert teylyn's Avatar
    Join Date
    10-28-2008
    Location
    New Zealand
    MS-Off Ver
    Excel 365 Insider Fast
    Posts
    11,372

    Re: Struggle with Multiple Conditions & Look Up Plus Cond. Format Results

    Hello,

    enter a value of 10% in F27 instead of the text you currently have. This is your lookup table.

    Format L3 to have a yellow fill as a default. Then set two conditional formatting rules with FormulaIs

    green =$K$3>=VLOOKUP($J$3,$C$27:$F$36,4,FALSE)
    red =$K$3<VLOOKUP($J$3,$C$27:$F$36,2,FALSE)

    So, the formula compares the value in K3 with the result of looking up the letter in J3 in the lookup table and returning the number in column 2 for red and column 4 for green.

  4. #4
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Struggle with Multiple Conditions & Look Up Plus Cond. Format Results

    One more option would be to fill in the bottom table...

    First column all 0's

    Second column, the lower bounds of the yellow groups

    Third column, the lower bounds of the green groups
    Then title each in D26:F26 as "Red", "Yellow", "Green"

    Then Conditional Formats... formula is:

    =INDEX(D26:F26,MATCH(K3,INDEX($D$27:$F$36,MATCH(J3,$C$27:$C$36,0),0))="Green"

    =INDEX(D26:F26,MATCH(K3,INDEX($D$27:$F$36,MATCH(J3,$C$27:$C$36,0),0)))="Yellow"

    =INDEX(D26:F26,MATCH(K3,INDEX($D$27:$F$36,MATCH(J3,$C$27:$C$36,0),0)))="Red"

    respectively.

  5. #5
    Registered User
    Join Date
    04-19-2010
    Location
    Florida, USA
    MS-Off Ver
    Excel 2007
    Posts
    4

    Re: Struggle with Multiple Conditions & Look Up Plus Cond. Format Results

    You both are amazing! That worked. There is hope that I can go home soon.

    Thanks you so much!

  6. #6
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898

    Re: Struggle with Multiple Conditions & Look Up Plus Cond. Format Results

    If you are satisfied with the solution(s) provided, please mark your thread as Solved.

    How to mark a thread Solved
    Go to the first post
    Click edit
    Click Go Advanced
    Just below the word Title you will see a dropdown with the word No prefix.
    Change to Solved
    Click Save

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1