+ Reply to Thread
Results 1 to 7 of 7

Excel 2007 : Lookup different tables

Hybrid View

  1. #1
    Registered User
    Join Date
    07-20-2010
    Location
    london, england
    MS-Off Ver
    Excel 2007
    Posts
    67

    Lookup different tables

    Hi,

    I really need some help. I need to use a look up function twice. i need to find the postcode area when the postcode is entered. (i have listed the postcodes and areas on the postcode tab, the postcodes in red are the exceptions and have different codes).

    I then need to look up the correct rate for the customer from the postcode area and age (on the rates page)

    any help?? i am really confused! I have attached the spreadsheet for you as i dont think my explination is very good!

    thanks
    clare
    Attached Files Attached Files
    Last edited by NBVC; 08-18-2010 at 07:33 AM. Reason: solved

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

    Re: Lookup function

    Try in B9:

    =VLOOKUP(B3,postcodes!A:B,2,0)

    and in B10:

    =INDEX(rates!$B$3:$H$7,MATCH(B8+1&"*",rates!$A$3:$A$7),MATCH(B9,rates!$B$2:$H$2))

    Note: if you want a 0 or error if age below 25 or over 69 is entered then

    =IF(OR(B8<25,B8>69),"error",INDEX(rates!$B$3:$H$7,MATCH(B8+1&"*",rates!$A$3:$A$7),MATCH(B9,rates!$B$2:$H$2)))

    or

    =IF(OR(B8<25,B8>69),0,INDEX(rates!$B$3:$H$7,MATCH(B8+1&"*",rates!$A$3:$A$7),MATCH(B9,rates!$B$2:$H$2)))
    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.

  3. #3
    Registered User
    Join Date
    07-20-2010
    Location
    london, england
    MS-Off Ver
    Excel 2007
    Posts
    67

    Re: Lookup function

    Hi,

    thanks for the reply. I have tried that, but its coming up with #NA, so i dont think it is working. any ideas?

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

    Re: Lookup function

    See attached.
    Attached Files Attached Files

  5. #5
    Registered User
    Join Date
    07-20-2010
    Location
    london, england
    MS-Off Ver
    Excel 2007
    Posts
    67

    Re: Lookup different tables

    Hi,

    I have worked out why it isnt working. i have been entering the full postcode. your reply is great. is there a way i can get the formula to work to calculate the first 4 digits when you enter a full postcode? its just the postcodes in red are exceptions. such as cn1 is group 3 but the rest of cn is group 1.

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

    Re: Lookup different tables

    Try:

    =VLOOKUP(LEFT(B3,IF(ISNUMBER(MATCH(LEFT(B3,4),postcodes!A:A,0)),4,IF(ISNUMBER(MATCH(LEFT(B3,3),postcodes!A:A,0)),3,2))),postcodes!A:B,2,0)

  7. #7
    Registered User
    Join Date
    07-20-2010
    Location
    london, england
    MS-Off Ver
    Excel 2007
    Posts
    67

    Re: Lookup different tables

    thats great!! it works beautifully thank you for your help and patience!!!

+ 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