+ Reply to Thread
Results 1 to 11 of 11

Multiple IF, OFFSET, MATCH criteria

  1. #1
    Registered User
    Join Date
    07-25-2014
    Location
    Wales
    MS-Off Ver
    2010
    Posts
    23

    Multiple IF, OFFSET, MATCH criteria

    I'm attempting to do a multiple offset match formula.
    In essence, I have 6 tables
    Based on the first "criteria", I need to look in a cell (A1), based on the value of that, I then need to do a offset, match (double lookup), based on the criteria from 2 other cells. However, thus far I've started the formula with an IF statement, then roll into the offset, match.
    I know I'm limited to 7 nested IF statement's.The problem I have is one of the values for the match is a decimal (0.387) and I need to round it to 0.4. Currently I"m using the following formula to round (IF(--MID(D44;3;1)>=5;ROUND(D44;2);ROUND(D44;2)). That means I run out of nested IF's

    Any advise would be appreciated.

    Regards,

    Nutzman

  2. #2
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,005

    Re: Multiple IF, OFFSET, MATCH criteria

    Attach a sample workbook.

    Make sure there is just enough data to demonstrate your need. Include a BEFORE sheet and an AFTER sheet in the workbook if needed to show the process you're trying to complete or automate. Make sure your desired results are shown, mock them up manually if necessary.

    Remember to desensitize the data.

    Click on GO ADVANCED and then scroll down to Manage Attachments to open the upload window.

  3. #3
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Multiple IF, OFFSET, MATCH criteria

    If you ARE using Excel 210, as stated in yoru profile, you can have 64 nested IFs. However, there's probably a much better way to achieve the same result.

    Will you please attach a SMALL sample Excel workbook (10-20 rows of data is usually enough)? Please don't attach a picture of one (no-one will want to re-type all your stuff before starting).

    1. Make sure that your sample data are truly REPRESENTATIVE of your real data. The use of unrepresentative data is very frustrating and can lead to long delays in reaching a solution.

    2. Make sure that your desired solution is also shown (mock up the results manually).

    3. Make sure that all confidential information is removed first!!

    4. Try to avoid using merged cells. They cause lots of problems!

    Unfortunately the attachment icon doesn't work at the moment. So, to attach an Excel file you have to do the following: Just before posting, scroll down to Go Advanced and then scroll down to Manage Attachments. Now follow the instructions at the top of that screen.
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  4. #4
    Registered User
    Join Date
    07-25-2014
    Location
    Wales
    MS-Off Ver
    2010
    Posts
    23

    Post Re: Multiple IF, OFFSET, MATCH criteria

    Hi Glen and John,

    I've mocked up a small sheet outlining my problem.

    Thanks in advance
    Attached Files Attached Files

  5. #5
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,005

    Re: Multiple IF, OFFSET, MATCH criteria

    One way:

    Define tables as named ranges called "Table_1", "Table_2" etc

    then use

    in F2

    =INDEX(INDIRECT("Table_"&$B$2),MATCH($B$3,INDEX(INDIRECT("Table_"&$B$2),0,1),1),MATCH($B$4,INDEX(INDIRECT("Table_"&$B$2),1,0),0))

    I believe result for you sample should be 0.99 UNLESS you are finding the nearest value.

    I also think the 0.5 value should be 0.05 (data in ascending order)

    an alternative is

    in D2

    =INDEX($A$8:$E$60,MATCH("Table " &$B$2,$A$8:$A$60,0)+MATCH($B$3,$A$10:$A$15,1)+1,MATCH($B$4,$A$9:$E$9,0))
    Attached Files Attached Files

  6. #6
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Multiple IF, OFFSET, MATCH criteria

    Another way, with a little rearrangement of your layout:

    =IFERROR(INDEX($C$10:$F$60,MATCH(C2&FLOOR(C3,0.05),INDEX($A$10:$A$61&$B$10:$B$61,0),0),MATCH(C4,$C$9:$F$9,0)),"")

    i agree about the 0.05
    Attached Files Attached Files

  7. #7
    Forum Expert
    Join Date
    05-05-2015
    Location
    UK
    MS-Off Ver
    Microsoft? Excel? for Microsoft 365 MSO (Version 2402 Build 16.0.17328.20068) 64-bit
    Posts
    28,005

    Re: Multiple IF, OFFSET, MATCH criteria

    @Glenn: innovative approach (as usual!)

  8. #8
    Registered User
    Join Date
    07-25-2014
    Location
    Wales
    MS-Off Ver
    2010
    Posts
    23

    Re: Multiple IF, OFFSET, MATCH criteria

    Glen and John,

    Thank you both for the innovative manner in which you both responded.
    Although I consider myself to be fairly good in excel, there's always room to learn?

  9. #9
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Multiple IF, OFFSET, MATCH criteria

    Always room to learn... and in my case, to forget as well!!

  10. #10
    Forum Expert
    Join Date
    12-09-2014
    Location
    Trakai, Lithuania
    MS-Off Ver
    2016
    Posts
    1,278

    Re: Multiple IF, OFFSET, MATCH criteria

    If interpolation is necessary, then such a formula can be applied.
    Formula: copy to clipboard
    Please Login or Register  to view this content.
    Attached Files Attached Files

  11. #11
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: Multiple IF, OFFSET, MATCH criteria

    You're welcome.



    If that takes care of your original question, please select "Thread Tools" from the menu link above and mark this thread as SOLVED.

    It'd also be appreciated if you were to click the Add Reputation button at the foot of any of the posts of all members who helped you reach a solution.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. Offset / Multiple Match criteria
    By JamesArmitage in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 03-09-2016, 09:42 AM
  2. Replies: 5
    Last Post: 02-06-2015, 08:44 PM
  3. [SOLVED] Need offset data from multiple match
    By SCDE in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 01-22-2015, 12:29 AM
  4. [SOLVED] OFFSET, Match for 2 criteria
    By IKZOUHETNIETWETEN in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 02-11-2014, 06:09 AM
  5. [SOLVED] Lookup with multiple criteria and offset
    By sasindiv in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 08-14-2013, 10:17 PM
  6. [SOLVED] Offset weeks with multiple criteria.
    By Sthlm in forum Excel General
    Replies: 5
    Last Post: 06-22-2012, 10:48 AM
  7. Multiple Offset and Match Functions
    By enjoi4586 in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 05-19-2008, 10:26 PM

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