+ Reply to Thread
Results 1 to 9 of 9

Lookup partial number

Hybrid View

iljott Lookup partial number 06-13-2011, 05:53 PM
tlafferty Re: Lookup partial number 06-13-2011, 06:11 PM
iljott Re: Lookup partial number 06-13-2011, 06:15 PM
Haseeb Avarakkan Re: Lookup partial number 06-13-2011, 06:18 PM
iljott Re: Lookup partial number 06-13-2011, 06:26 PM
  1. #1
    Registered User
    Join Date
    06-13-2011
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    5

    Lookup partial number

    I'm a bit of an Excel noob and urgently need some help. This will probably be simple for some of you but I can't seem to figure it out myself.

    I basically have an Excel sheet where Column A contains a dialing prefix and Column B contains a cost. I would like to enter a full number dialed and get the corresponding cost from Column B that has the most number of left-most digits from A. Below is a simple example.

    A B
    1 44 0.50
    2 447 0.55
    3 4470 0.60
    4 4487 0.50
    5 4489 0.75
    6 44121276 1.00

    Example 1: 4489123456 = 0.75 because the first 4 digits correspond to Row 5
    Example 2: 4412345678 = 0.50 because only the first 2 digits correspond to Row 1
    Example 3: 4412127612 = 1.00 because the first 7 digits correspond to Row 6

    I was thinking of using VLookup, but I'm not sure how to go about this as I've only previously used VLookup with the same amount of digits to compare with.

    Can anyone please help?

  2. #2
    Valued Forum Contributor tlafferty's Avatar
    Join Date
    04-08-2011
    Location
    United States, Tacoma, WA
    MS-Off Ver
    Excel 2010, Excel 2013 Customer Preview
    Posts
    1,112

    Re: Lookup partial number

    try sorting your data then use TRUE as the final argument instead of false.
    If your question has been satisfactorily addressed, please consider marking it solved. Click the Thread Tools dropdown and select Mark thread as solved.
    Also, you might want to add to the user's reputation by clicking the star icon in the lower left corner of the post with the answer- it's why we do what we do...

    Thomas Lafferty
    Analyst/Programmer

  3. #3
    Registered User
    Join Date
    06-13-2011
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    5

    Re: Lookup partial number

    Quote Originally Posted by tlafferty View Post
    try sorting your data then use TRUE as the final argument instead of false.
    Hi tlafferty,

    Thanks for your quick reply. My data is already sorted in ascending order (Column A - sorry it's a bit difficult to see it properly above). If I used TRUE I wouldn't get an answer since the number I want to match is longer than any of the numbers in the lookup range.

  4. #4
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    365
    Posts
    2,243

    Re: Lookup partial number

    Hello iljott, Welcome to the forum!

    My data is already sorted in ascending order
    If so, try this.

    Say in D1, your lookup number,

    =LOOKUP(40000,SEARCH($A$1:$A$6,D1),$B$1:$B$6)
    Regards,
    Haseeb Avarakkan

    __________________________________
    "Feedback is the breakfast of champions"

  5. #5
    Registered User
    Join Date
    06-13-2011
    Location
    Malta
    MS-Off Ver
    Excel 2010
    Posts
    5

    Re: Lookup partial number

    Quote Originally Posted by Haseeb A View Post
    Hello iljott, Welcome to the forum!



    If so, try this.

    Say in D1, your lookup number,

    =LOOKUP(40000,SEARCH($A$1:$A$6,D1),$B$1:$B$6)
    Hi Haseeb,

    Thanks for your great response! This almost works perfectly! The only thing is that the lookup looks everywhere within the number I give it - for example, if I enter 123447, I would get the value 0.55 (because of the 447), but I actually only want to use it if the numbers are at the beginning of the cell (I have a much longer list than 6 rows ).

  6. #6
    Forum Guru
    Join Date
    05-24-2011
    Location
    India
    MS-Off Ver
    365
    Posts
    2,243

    Re: Lookup partial number

    Try this one,

    =IFERROR(LOOKUP(40000,SEARCH(LEFT(D1,ROW(INDEX(A:A,1):INDEX(A:A,LEN(D1)))),$A$1:$A$6),$B$1:$B$6),"Nothing Found")

+ 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