+ Reply to Thread
Results 1 to 7 of 7

Formula to search array for text and return value from an offset cell

  1. #1
    Registered User
    Join Date
    09-21-2012
    Location
    Louisiana
    MS-Off Ver
    Excel 2010
    Posts
    3

    Formula to search array for text and return value from an offset cell

    I am looking for a formula that will search an array for a partial text string. Once that string is found, I would like it to return the value that is 2 rows below and 1 clolumn to the right.

    I have attached a sample worksheet. I have tried approaching this from several different ways and can't find the solution.

    Location 1
    applicable due
    test 1 15 0
    test 2 5 3
    test 3 13 0

    Location 2
    applicable due
    test 1 5 1
    test 2 59 17
    test 3 25 7
    Attached Files Attached Files

  2. #2
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Formula to search array for text and return value from an offset cell

    something like
    =INDEX($B$5:$B$101,MATCH("*location 2*",$A$5:$A$101,0)+2)
    "Unless otherwise stated all my comments are directed at OP"

    Mojito connoisseur and now happily retired
    where does code go ?
    look here
    how to insert code

    how to enter array formula

    why use -- in sumproduct
    recommended reading
    wiki Mojito

    how to say no convincingly

    most important thing you need
    Martin Wilson: SPV
    and RSMBC

  3. #3
    Registered User
    Join Date
    10-02-2012
    Location
    Baku
    MS-Off Ver
    Excel 2010
    Posts
    273

    Re: Formula to search array for text and return value from an offset cell

    =OFFSET($A$4,MATCH(A3,A5:A101,0)+2,1,1,1)

    This formula give value 15 for "Location 1" and 59 for location 2

    Is this what you want
    Attached Files Attached Files

  4. #4
    Registered User
    Join Date
    09-21-2012
    Location
    Louisiana
    MS-Off Ver
    Excel 2010
    Posts
    3

    Re: Formula to search array for text and return value from an offset cell

    @martindwilson

    your formula worked perfectly for what I am trying to do - I applied it to my acutal workbook and this is it:
    =INDEX(BCOL,MATCH("*JENN CARE MANAGER TM A*",TIF,0)+2)

    One question though. Is there a way to get the row number in the formula to increase by 1 if i drag it down?
    +3, +4, +5, etc....

  5. #5
    Forum Expert martindwilson's Avatar
    Join Date
    06-23-2007
    Location
    London,England
    MS-Off Ver
    office 97 ,2007
    Posts
    19,320

    Re: Formula to search array for text and return value from an offset cell

    =INDEX(BCOL,MATCH("*JENN CARE MANAGER TM A*",TIF,0)+rows($a$1:a2))

  6. #6
    Registered User
    Join Date
    09-21-2012
    Location
    Louisiana
    MS-Off Ver
    Excel 2010
    Posts
    3

    Re: Formula to search array for text and return value from an offset cell

    That worked perfectly. Thanks!!

  7. #7
    Forum Moderator vlady's Avatar
    Join Date
    09-22-2011
    Location
    Philippines - OLSHCO -Guimba-Nueva Ecija
    MS-Off Ver
    2021
    Posts
    4,366

    Re: Formula to search array for text and return value from an offset cell

    Based on your last post it seems that you are satisfied with the solution(s) you've received but you haven't marked your thread as "SOLVED".
    For the meantime I'll do it for you.

    How?
    New quick method:
    Select Thread Tools-> Mark thread as Solved. To undo, select Thread Tools-> Mark thread as Unsolved.

    Or you can use this way:

    How to mark a thread Solved
    Go to the first post
    Click edit
    Click Go Advanced
    Just below the word Title you will see a dropdown with the word No prefix.
    Change to Solved
    Click Save

    Note:
    You can also thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given.
    By doing so you can add to the reputation(s) of those who helped and shared their time in helping you.
    I think people forget the word "THANK YOU!!!!" Do you still know it???

    There is a little star ( ADD REPUTATION ) below those person who helped you. Click it to say your "PRIVATE APPRECIATION TO THEIR EFFORT ON THEIR CONTRIBUTIONS "

    Regards,
    Vladimir

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Tags for this Thread

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