+ Reply to Thread
Results 1 to 5 of 5

Matching multiple criteria where one of the them needs to match a range or closest value

  1. #1
    Registered User
    Join Date
    01-31-2021
    Location
    Philippines
    MS-Off Ver
    365
    Posts
    4

    Matching multiple criteria where one of the them needs to match a range or closest value

    Hi all!

    I'm in dire need of help. =(

    I have 2 tables:
    Table 1: is what I need to be filled out. The column I need to fill out is the Standard Level.
    Table 2: is my reference table.
    The criteria that needs to matched are the Standard Title, Market Grade, and BillRate.
    The pinch is that the BillRate on the Table 1 does not exactly match the billrate on table 2, it's either higher or lower, but that's acceptable, it just needs to be within +/-15% range or whatever is closest if it's beyond +/-15% [I know. It's confusing. =(].
    It's easy enough using IndexMatch if the billrates match but the threshold is killing me. =(
    Help please!!
    Attached Files Attached Files

  2. #2
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Matching multiple criteria where one of the them needs to match a range or closest val

    Hi

    first attempt

    =IFERROR(INDEX(Table2[Ref_Standard Level],AGGREGATE(15,6,ROW(Table2[Ref_Standard Level])-1/((Table2[Ref_Standard Title]=A2)*(Table2[Ref_Market Grade]=C2)*(ABS(Table2[Ref_BillRates]-D2)<=D2*15%)),1)),"")

    =IFERROR(INDEX(Table2_Reference!B$2:B$226,AGGREGATE(15,6,ROW($2:$226)-1/((Table2_Reference!A$2:A$226=A2)*(Table2_Reference!C$2:C$226=C2)*(ABS(Table2_Reference!D$2:D$226-D2)<=D2*15%)),1)),"")

    Regards
    -----------------------------------------------------

    At Excelforum, you can say "Thank you!" by clicking the star icon ("Add Reputation") below the post.

    Please, mark your thread [SOLVED] if you received your answer.

  3. #3
    Registered User
    Join Date
    01-31-2021
    Location
    Philippines
    MS-Off Ver
    365
    Posts
    4

    Re: Matching multiple criteria where one of the them needs to match a range or closest val

    Quote Originally Posted by canapone View Post
    Hi

    first attempt

    =IFERROR(INDEX(Table2[Ref_Standard Level],AGGREGATE(15,6,ROW(Table2[Ref_Standard Level])-1/((Table2[Ref_Standard Title]=A2)*(Table2[Ref_Market Grade]=C2)*(ABS(Table2[Ref_BillRates]-D2)<=D2*15%)),1)),"")

    =IFERROR(INDEX(Table2_Reference!B$2:B$226,AGGREGATE(15,6,ROW($2:$226)-1/((Table2_Reference!A$2:A$226=A2)*(Table2_Reference!C$2:C$226=C2)*(ABS(Table2_Reference!D$2:D$226-D2)<=D2*15%)),1)),"")

    Regards
    Hi canapone!

    Thank you for this!

    Question though, if we remove the 15% threshold and just go with the closest possible value, would this still work?

    Thank you!

  4. #4
    Forum Expert
    Join Date
    12-03-2009
    Location
    Florence, Italy
    MS-Off Ver
    Excel 2019
    Posts
    1,796

    Re: Matching multiple criteria where one of the them needs to match a range or closest val

    Hi

    try to substitute the segment <=D2*15% with

    =AGGREGATE(15,6,Abs(Table2_Reference!$D$2:$D$226-D2)/((Table2_Reference!$A$2:$A$226=A2)*(Table2_Reference!$C$2:$C$226=C2)),1)

    Regards
    Last edited by canapone; 02-01-2021 at 03:42 AM.

  5. #5
    Registered User
    Join Date
    01-31-2021
    Location
    Philippines
    MS-Off Ver
    365
    Posts
    4

    Re: Matching multiple criteria where one of the them needs to match a range or closest val

    Quote Originally Posted by canapone View Post
    Hi

    try to substitute the segment <=D2*15% with

    =AGGREGATE(15,6,Abs(Table2_Reference!$D$2:$D$226-D2)/((Table2_Reference!$A$2:$A$226=A2)*(Table2_Reference!$C$2:$C$226=C2)),1)

    Regards


    I looked for some references and was able to simplify the formula and actually found something that worked.
    =INDEX(Table2[Ref_Standard Level],MATCH(1,INDEX((Table2[Ref_Standard Title]=A2)*(Table2[Ref_Market Grade]=C2)*(Table2[Ref_BillRates]>=D2),0),0))

    Thank you so much for your help!!

+ 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. Closest match with multiple criteria (3 criteria) Not matching perfectly!
    By JulianS96 in forum Excel Formulas & Functions
    Replies: 1
    Last Post: 11-04-2019, 10:50 AM
  2. match closest date from within range matching ID number
    By Vend1301 in forum Excel General
    Replies: 4
    Last Post: 11-18-2015, 02:53 PM
  3. [SOLVED] Closest match on Multiple Criteria
    By rbetts in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 04-20-2014, 08:33 AM
  4. Replies: 2
    Last Post: 12-04-2013, 01:01 PM
  5. Replies: 1
    Last Post: 01-17-2013, 05:27 PM
  6. [SOLVED] match closest date from within range matching ID number
    By adrianjaeggi in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 12-09-2012, 03:33 PM
  7. closest match from multiple criteria
    By wongja in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 07-31-2010, 01:37 AM

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