+ Reply to Thread
Results 1 to 11 of 11

Nested If

  1. #1
    Forum Contributor
    Join Date
    09-10-2011
    Location
    Chicago
    MS-Off Ver
    Excel 2007
    Posts
    176

    Nested If

    Hi,

    I have 25 conditions to check and I am unable to do nested if as it is not allowing more than 7 conditions in 2007. Could any one please have a look and help me?

    I have attached the sample file for your reference.

    for example:

    if A2=1 & B2=1 then C2 Should be Sev1
    if A2=2 & B2=2 then C2 Should be Sev2
    if A2=1 & B2=5 then C2 Should be Sev4

    Thanks in advance for your help!!

    Regards,
    Humac
    Last edited by humacdeep; 02-21-2012 at 04:28 PM. 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: Nested If

    Try:

    ="Sev"&INDEX($H$6:$L$10,MATCH(A2,$G$6:$G$10),MATCH(B2,$H$5:$L$5))

    copied down
    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 Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    25,422

    Re: Nested If

    Put this in D2:

    =IF(OR(A2="",A2>$G$10,B2="",B2>$L$5),"","Sev"&INDEX($H$6:$L$10,MATCH(A2,$G$6:$G$10),MATCH(B2,$H$5:$L$5)))

    then copy down to D26, to reproduce what you have in column C.

    Hope this helps.

    Pete

  4. #4
    Forum Contributor
    Join Date
    09-10-2011
    Location
    Chicago
    MS-Off Ver
    Excel 2007
    Posts
    176

    Re: Nested If

    Hi Pete & NVBC - Thanks for the formula... its working as desired, but is it possible to have a formula with out using Index?

    I will not have the table which is used for Index in your formula. I kept that in sheet for your understanding.

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

    Re: Nested If

    Try:

    ="Sev"&IF(MAX(A2,B2)<=4,IF(A2=B2,A2,MAX(A2,B2)),4)

    copied down

  6. #6
    Forum Contributor
    Join Date
    09-10-2011
    Location
    Chicago
    MS-Off Ver
    Excel 2007
    Posts
    176

    Re: Nested If

    Its working, but it is also giving Sev5 where as I need only till Sev4. Please have a look.

    If A2=5 & B2 = 1 then it is giving Sev5 instead of Sev4

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

    Re: Nested If

    You were too fast... I edited the formula.... see above.

  8. #8
    Forum Contributor
    Join Date
    09-10-2011
    Location
    Chicago
    MS-Off Ver
    Excel 2007
    Posts
    176

    Re: Nested If

    I just tested that and its working great

  9. #9
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    25,422

    Re: Nested If

    Okay, here's an alternative from me (slightly different):

    =IF(OR(A2="",A2>$G$10,B2="",B2>$L$5),"","Sev"&MIN(MAX(A2,B2),4))

    Hope this helps.

    Pete

    EDIT: If you don't need the error checking, then you could do this:

    ="Sev"&MIN(MAX(A2,B2),4)

  10. #10
    Forum Contributor
    Join Date
    09-10-2011
    Location
    Chicago
    MS-Off Ver
    Excel 2007
    Posts
    176

    Re: Nested If

    Thanks Pete, I have modified the formula as below (as I said earlier I will not have G10 & L5 in my orginal data) and it working.

    =IF(OR(A2="",A2>5,B2="",B2>5),"","Sev"&MIN(MAX(A2,B2),4))

    Thanks once again for all your help...

  11. #11
    Forum Guru Pete_UK's Avatar
    Join Date
    12-31-2011
    Location
    Warrington, England
    MS-Off Ver
    Office 2019 (still learning)
    Posts
    25,422

    Re: Nested If

    Refresh time on this Forum is very long - I received the email notification of your last post before I saw it here.

    Glad to be able to help.

    Pete

+ 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