INDEX MATCH With a Twist

Mynda Treacy

January 12, 2012

My Toughest Excel Challenge So Far!

Recently a member contacted me with a VLOOKUP question, but when I further understood the requirements it became a challenge I’d never come across before.

This pushed me to my Excel limits and I have to be honest…I nearly gave up twice! By giving up I mean I was going to settle for a work-around solution instead.

The Challenge

Christy wanted to find the last value in a row for a specific part number using a table of data in Sheet1 like this:

Index Match Formula

Notice how some rows don’t have a value in every cell? This is what makes this challenge unique.

You see Christy wanted to find the value for say, part A10106, for the month of June, but if June didn’t have a value then find the value for the previous month, and if May didn’t have a value then go to the previous month and so on.

And it wasn’t just one part, it was over 2000 parts and for every month of the year.

Not being one to shy away from a challenge I persisted, and this is my formula (Note: The table above was on Sheet1 and my formula is on Sheet2):

=IFERROR(INDEX(INDIRECT("Sheet1!"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)),MATCH(9.99999999999999E+307,INDIRECT("Sheet1!" &ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)))),0)

Phew. I’m not ashamed to say that I cheered out loud when I cracked this one.

Find Last Value in a Range

The first part of the challenge was to find the last value in each row.

We can use an INDEX and MATCH formula like this to find the last value in row 2:

=INDEX(Sheet1!A2:M2,MATCH(9.99999999999999E+307,Sheet1!A2:M2))

=52

Index Match Formula

But I need to find the last value for each month and for that I need the range A2:M2 to change for each month I look up, and for each part.

So that for Part Number A10106 for the month of June I look up the range Sheet1!A2:G2 and for the month of August I look up Sheet1!A2:I2, and so on.

To do this I need to replace the range Sheet1!A2:M2 with some functions that will dynamically update when I change the month and the Part Number, and for this I used INDIRECT, MATCH and ADDRESS.

Dynamic Range using INDIRECT, MATCH and ADDRESS

So my formula went from this:

=INDEX(Sheet1!A2:M2,MATCH(9.99999999999999E+307,Sheet1!A2:M2))

To this by replacing the ranges Sheet1!A2:M2 with the sections in blue:

=IFERROR(INDEX(INDIRECT("Sheet1!"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)),MATCH(9.99999999999999E+307,INDIRECT("Sheet1!" &ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)))),0)

Note: cell A4 contains the part number and B3 contains the month I want to look up.

The INDIRECT function returns a reference specified by a text string.

In this case the text string is generated using the MATCH function and I've used the ampersand to join components of the text string together.

The ADDRESS function obtains the address of a cell or range of cells. For example, ADDRESS(1,2) returns $A$2.

Index Match Functions

IFERROR - The Icing on the Top

And finally, if Excel couldn’t find the part number in the table I used the IFERROR function to enter a zero.

Download the Workbook

Enter your email address below to download the sample workbook.



By submitting your email address you agree that we can email you our Excel newsletter.

You’ll find the evaluate tool on the Formulas tab of the Ribbon in the Formula Auditing group.

Feedback

I’d love to know if you have a simpler way to tackle this challenge. Please post your solution below in the comments for us all to share.

13 thoughts on “INDEX MATCH With a Twist”

  1. I’ve only just seen this post and decided to have a go at doing it and see if dynamic arrays might help. Is the following formula simpler?
    =OFFSET(Sheet1!A1, MATCH(A4,part_number,0),
    MAX(IFERROR(MATCH(“?*” & “_” & SEQUENCE(MATCH(B3, months,0)),
    TRANSPOSE(OFFSET(Sheet1!A1,MATCH(A4,part_number,0),1,1,MATCH(B3, months,0))) & “_”
    & SEQUENCE(MATCH(B3, months,0)), 0), 0)))

    I have attached the original workbook to this post in the forum with my formula added on Sheet 2, together with another workbook that explains a technique I used – not sure if this is known. The basic idea is to extend the MATCH function so that it instead of returning just the first index where a match occurs, you return an array listing all the indexes where a match occurs.

    Reply
    • Nice use of Dynamic Arrays, Howard! I’m not sue it’s much simpler, but it’s better because we don’t need INDIRECT. Thanks for sharing 🙂

      Reply
  2. I really need assistance with date formatting from numbers (20170227) or text (02-27-2017). My data is pulled with either formats, from which I need to convert to date and thereafter calculate the aging and do a pivot grouping monthly.

    Example :
    Customer inv invdate terms
    ABC1234 0056 20170227 14days
    Abc3446 0013 20161213 45days
    ABC5644 0045 20170202 30days

    Reply
    • Hi Aganack,

      Try this formula:

      =LEFT(A1,LEN(A1)-6)&MID(A1,LEN(A1),1)&MID(A1,LEN(A1)-1,1)&MID(A1,LEN(A1)-2,1)&MID(A1,LEN(A1)-3,1)&MID(A1,LEN(A1)-4,1)&MID(A1,LEN(A1)-5,1)
      

      Cheers.

      Carlo

      Reply
  3. Hi Mynda,
    very good idea to use MATCH function with a big value …
    IFERROR is a good feature of version 2007 … I tried to write a function that works with the 2003 version, you can probably do better … so here:

    =IF(COUNT(INDEX(INDEX(Sheet1!A1:A20,MATCH(A4,Sheet1!A1:A20,)):INDEX(Sheet1!1:1,,MATCH(B3,Sheet1!A1:M1,)),MATCH(A4,Sheet1!A1:A20,),)),VLOOKUP(A4,Sheet1!A1:M20,MATCH(10*1E+307,INDEX(INDEX(Sheet1!A1:A20,MATCH(A4,Sheet1!A1:A20,)):INDEX(Sheet1!1:1,,MATCH(B3,Sheet1!A1:M1,)),MATCH(A4,Sheet1!A1:A20,),)),),0)

    best regards
    r

    Reply
    • Thanks for sharing, Roberto….although I doubt I would come up with a better solution!

      If you’re reading this and wondering about Roberto’s use of 10*1E+307, it is simply an alternative to 9.99999999999999E+307. They are not the same number, but both are BIG numbers.

      You could in fact use any number in place of these two, as long as it is greater than any of the numbers in the table you are referencing.

      For example, this formula would also work in Christy’s example above:

      =IFERROR(INDEX(INDIRECT("Sheet1!"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)),MATCH(1000,INDIRECT("Sheet1!"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),1,1)&":"&ADDRESS(MATCH(A4, Sheet1!$A:$A,0),MATCH(B3, Sheet1!$1:$1,0),1)))),0)

      or with Roberto’s formula:

       =IF(COUNT(INDEX(INDEX(Sheet1!A1:A20,MATCH(A4,Sheet1!A1:A20,)):INDEX(Sheet1!1:1,,MATCH(B3,Sheet1!A1:M1,)),MATCH(A4,Sheet1!A1:A20,),)),VLOOKUP(A4,Sheet1!A1:M20,MATCH(1000,INDEX(INDEX(Sheet1!A1:A20,MATCH(A4,Sheet1!A1:A20,)):INDEX(Sheet1!1:1,,MATCH(B3,Sheet1!A1:M1,)),MATCH(A4,Sheet1!A1:A20,),)),),0)

      Click here to read more of Roberto’s groundbreaking Excel insights.

      Reply
      • Mynda … thank you too!
        in both cases … no higher number can be typed … even if a higher number may appear as a result of a formula … but you’re right when you say “both are BIG numbers” 🙂
        regards
        r

        Reply
  4. Hi! i have been follwing your mails. Frankly, my knowledge in excel is completly different now, almost transformed me from Basic – Expert level. However, could you tell me how to use Vlookup with Arrays? i tried to understand it on my own, but some how it is not progressing.

    Thanks
    Raghu.A.J.M.

    Reply
    • Hi Raghu,

      Thanks for your kind words. I’ll email you directly about your VLOOKUP with Arrays question as I need more information.

      Kind regards,

      Mynda.

      Reply
  5. I am responding today because I actually had a similar problem and came up with this solution yesterday. This is a little simpler than the formula that you used. With all the free stuff you give I thought maybe I can give back a little.

    The formula is on the same sheet as the table of data. =VLOOKUP(O2,A1:M20,MATCH(P2,A1:M1,0),FALSE) in cell Q3. I used the data validation in cells O2 (for Part) and P2 (for Month) like you did. The trick was to use the columns of the months (A1:M1) in match to determine how many columns vlookup needs to go over.

    Let me know if this makes sense or not.

    Reply
    • Hi Shay,

      Thanks for your example.

      It is almost the same but with my example I have missing data, so if you look up August and August doesn’t have a value, I need Excel to look up July, and if July doesn’t have a value then look up June, and so on. Hence I needed to use =INDEX(Sheet1!A2:M2,MATCH(9.99999999999999E+307,Sheet1!A2:M2)) and then make it dynamic by using INDIRECT, MATCH and ADDRESS.

      Any ideas on how we could incorporate finding the last value in a range into your formula?

      Cheers,

      Mynda.

      Reply

Leave a Comment

Current ye@r *