+ Reply to Thread
Results 1 to 2 of 2

Explain this Formula that lookups up over multiple sheets

  1. #1
    Registered User
    Join Date
    01-13-2011
    Location
    Alabama
    MS-Off Ver
    Excell 2007
    Posts
    1

    Explain this Formula that lookups up over multiple sheets

    I'd like to apologize in advance if this is in the wrong area of the forums.

    I was trying to run a vlookup on multiple worksheets and came across this formula while searching the net:

    =VLOOKUP(B2,INDIRECT("'"&INDEX(D2:D8,MATCH(TRUE,COUNTIF(INDIRECT("'"&D2:D8&"'!C1:C25"),B2)>0,0))&"'!C1:P25"),2,0)

    Now I managed to get it to work with what I was doing. My problem is, I have on idea how this formula works. Like the Indirect function? And what is the purpose of the "'" and &? Or the >0?

    I can look at a simple vlookup formula and break down what each part is doing. But I have no idea where to start with this.

    I realize this is probably a lot to ask. Hopefully someone will have enough free time and knowledge to help me with this.

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

    Re: Explain this Formula

    So you have a list of sheet names in D2:D8, and you want to look in range C1:C25 on each of those sheets to see where a match to B2 occurs. and then you want to return from column 2 of range C1:P25 from whichever sheet the match is found.

    The first thing the formula does is create an array of ranges C1:C25 for each of the sheets listed in D2:D8. the "'"& and "'! that surround the ranges is adding the necessary syntax to reference sheets that can possibly have spaces or special characters in them. If you reference a sheet name directly you might see that you get something like 'Sheet X'!C1:C25. So everything between quotes is building a sheet reference.

    The INDIRECT function is required to indirectly refer to those sheetnames.

    The Countif is countif how many matches are found and ensuring there is more then 0 (hence >0). The Match(True()) part looks for the first instance that a match is found and returns that sheet and range... once that is done, the normal Vlookup process happens only with that matched sheet and range.

    If you go to Formulas menu, Evaluate Formula and step through you will see how the formula is working.
    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.

+ 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