+ Reply to Thread
Results 1 to 7 of 7

vlookup of multiple references in same cell

  1. #1
    Registered User
    Join Date
    08-10-2009
    Location
    london, England
    MS-Off Ver
    Excel 2003
    Posts
    7

    vlookup of multiple references in same cell

    Hi All

    Hope someone out therecan help put me on the right track to solving this problem.

    I have multiple cells which all have various amounts of data in them, the core part of the data is always in the same format but the string length of the data can vary from cell to cell. I need to be able to use each segment as a reference for a Vlookup which will ultmately sum up all the results of the individual lookups.

    Cell format is

    A1 DP 001DP 002 DP 003DP 004
    A2 DP 125DP 235 DP 555DP 652DP 555DP 012
    ETC

    The data I need to extract and perform lookup with is DP xxx, so I want to look at a section of the cell which is always 6 characters long .

    The cells are in a column and each cell is of a varying legth but always in multiples of 6. I am able tp extract the information by just using a simple left/right character formula but this is a very manual process and I have a grid of 90*90 cells that i need to work on.


    Hope someone can help

    M

  2. #2
    Forum Expert
    Join Date
    06-18-2004
    Location
    Canada
    MS-Off Ver
    Office 2016
    Posts
    1,474

    Re: vlookup of multiple references in same cell

    Somewhat unclear... VLOOKUP accepts wildcard characters. So, for example, your lookup value can be as follows...

    "*DP 002*"

    or

    "*"&A2&"*"

    ...where A2 contains DP 002.

  3. #3
    Forum Expert JBeaucaire's Avatar
    Join Date
    03-21-2004
    Location
    Bakersfield, CA
    MS-Off Ver
    2010, 2016, Office 365
    Posts
    33,492

    Re: vlookup of multiple references in same cell

    You don't go far enough in explaining your need. You already know how to isolate 6 characters in a cell, so that's not your problem.

    I am guessing it is your final results that are eluding you. Can just post up you 90x90 grid of data and a manual mockup of some (all?) of the results you want to get?

    If we can see you starting line and your goal line, the stuff in the middle should get much easier to suggest.

    Click GO ADVANCED and use the paperclip icon to post up your workbook.
    _________________
    Microsoft MVP 2010 - Excel
    Visit: Jerry Beaucaire's Excel Files & Macros

    If you've been given good help, use the icon below to give reputation feedback, it is appreciated.
    Always put your code between code tags. [CODE] your code here [/CODE]

    ?None of us is as good as all of us? - Ray Kroc
    ?Actually, I *am* a rocket scientist.? - JB (little ones count!)

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

    Re: vlookup of multiple references in same cell

    Assuming you have this: "DP 125DP 235 DP 555DP 652DP 555DP 012" in A1,

    Then create helper column to determine number of DP items:

    Please Login or Register  to view this content.
    copied down..

    then assuming your Lookup table is in H1 to I5, make sure column H is sorted in Ascending order... then you can apply this formula to sum corresponding values:

    Please Login or Register  to view this content.
    copied down. Where B1 contains the Helper column result, correspondingly

    Adjust ranges to suit.
    Attached Files Attached Files
    Last edited by NBVC; 08-10-2009 at 05:01 PM. Reason: Added sample workbook
    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.

  5. #5
    Registered User
    Join Date
    08-10-2009
    Location
    london, England
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: vlookup of multiple references in same cell

    Sorry for lack of info, I have atached an example of what I am trying to do.

    Range name "data" is the range hich I want to do individual Vlookups on.

    Range name "route_link" contains the cells which I want to examine, the model I am working on will calculate distances between 2 different sites and the refernce DP xxx is actually a specific route on a network map. The input in this range is simply a concatenation of the links that need to be traversed to get from point 1 to point 2.

    Range name "route_km" is where I wish to put all my calculated distances.

    I have cut the number of colums down to 5 but in the Workbook I am working on there will actually be a grid which is 90*90.

    so for the first cell I would have end up with Vlookups that sum up to 10384.

    Hope this is sufficient.

    M
    Attached Files Attached Files

  6. #6
    Forum Expert
    Join Date
    06-18-2004
    Location
    Canada
    MS-Off Ver
    Office 2016
    Posts
    1,474

    Re: vlookup of multiple references in same cell

    Try...

    G4, copied down:

    =SUMPRODUCT(SUMIF($B$4:$B$43,MID($F4,ROW(INDIRECT("1:"&(LEN($F4)-LEN(SUBSTITUTE($F4,"DP","")))/2))*6-6+1,6),$C$4:$C$43))

    Note, however, the following should be more efficient...

    First define the following...

    1) Select G4

    2) Insert > Name > Define

    Name: Array

    Refers to:

    =EVALUATE("{"&SUBSTITUTE(SUBSTITUTE($F4,"DP",""",""DP")&"""",""",","",1)&"}")

    3) Click Ok

    Then try...

    G4, copied down:

    =SUMPRODUCT(SUMIF($B$4:$B$43,Array,$C$4:$C$43))

  7. #7
    Registered User
    Join Date
    08-10-2009
    Location
    london, England
    MS-Off Ver
    Excel 2003
    Posts
    7

    Re: vlookup of multiple references in same cell

    Many thanks to all of you, this has been a real help.

    M

+ 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