+ Reply to Thread
Results 1 to 7 of 7

How to find sheet in formula by (part) cell reference. use Indirect ???

  1. #1
    Registered User
    Join Date
    12-21-2006
    Posts
    3

    How to find sheet in formula by (part) cell reference. use Indirect ???

    Dear all,

    Your help would be much appreciated.

    How can I refer in a formula to a sheet by using the first three letters of a cell. I have two files and I need to find the sheet in one file by the reference of the product code (THA005). I understand this is possible with INDIRECT and INDIRECT.EXT which requires the morefun.xll add-in.

    The value of cell A13 is THA005. The sheet name in the other file is called THA. The formulas I have to integrate this in are underneath. Any ideas how to integrate this into the formulas?

    (original formula)
    =MATCH(A13, [TFWebsite.xls]Tha!$A$5:$A$5000,0)
    (original formula)
    =IF(ISNUMBER(C13),INDEX([TFWebsite.xls]Tha!$C$5:$C$5000,C13),0)

    (my own attempt, doesn't work)
    =MATCH(A14, [TFWebsite.xls] indirect(A14&!$A$5:$A$5000,0))

    My own attempt doesn't work, probably because of the fact that the cell value is THA005 while to sheet is called Tha. In addition most likely a problem because the sheet is in another file. ?????

    Your e-mail on this is welcome [email protected]

    Many thanks,

    Kris

  2. #2
    Forum Contributor
    Join Date
    11-29-2003
    Posts
    1,203
    I think it will work if you put the entire address inside the Indirect function, and enclose it in quotes.

    Instead of

    =MATCH(A14, [TFWebsite.xls] indirect(A14&!$A$5:$A$5000,0))


    Try

    =MATCH(A14, indirect("[TFWebsite.xls]"&A14&"!$A$5:$A$5000"),0)

  3. #3
    Forum Contributor VBA Noob's Avatar
    Join Date
    04-25-2006
    Location
    London, England
    MS-Off Ver
    xl03 & xl 07(Jan 09)
    Posts
    11,988
    Hi,

    Try

    =MATCH(A14,indirect("[TFWebsite.xls]"&left(A14,3)&"!$A$5:$A$5000"),0)

    Should return the sheet name THA

    VBA Noob
    _________________________________________


    Credo Elvem ipsum etian vivere
    _________________________________________
    A message for cross posters

    Please remember to wrap code.

    Forum Rules

    Please add to your signature if you found this link helpful. Excel links !!!

  4. #4
    Registered User
    Join Date
    12-21-2006
    Posts
    3
    Thank you the first formula (MATCH) works fine.
    =MATCH(A14,indirect("[TFWebsite.xls]"&left(A14,3)&"!$A$5:$A$5000"),0)

    How about the second formula, if I try the same concept there I mess up and get an error. This is what I tried:
    =IF(ISNUMBER(C14),INDEX("[TFWebsite.xls]"&left(A14,3)&"!$C$5:$C$5000,C14),0)

    Please look above for the original IF formula and advise me what should be correct. Same concept, to look for the sheet by the first three letters of the cell value.

    I can't see why this doesn't work????????

    Thanks guys

  5. #5
    Forum Contributor VBA Noob's Avatar
    Join Date
    04-25-2006
    Location
    London, England
    MS-Off Ver
    xl03 & xl 07(Jan 09)
    Posts
    11,988
    Hi,

    Does this work. I assume A14 is still THA005

    =IF(ISNUMBER(C14),INDEX(INDIRECT("[TFWebsite.xls]"&LEFT(A14,3)&"!$C$5:$C$5000"),C14),0)

    VBA Noob

  6. #6
    Registered User
    Join Date
    12-21-2006
    Posts
    3
    That works perfectly,

    I oversaw that, getting late.

    Thanks a lot.

    =IF(ISNUMBER(C14),INDEX(INDIRECT("[TFWebsite.xls]"&LEFT(A14,3)&"!$C$5:$C$5000"),C14),0)


    PERFECT

  7. #7
    Forum Contributor VBA Noob's Avatar
    Join Date
    04-25-2006
    Location
    London, England
    MS-Off Ver
    xl03 & xl 07(Jan 09)
    Posts
    11,988
    Glad you got a solution

    VBA Noob

+ 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