+ Reply to Thread
Results 1 to 4 of 4

Vlookup multiple commas separated values in a cell from another table

Hybrid View

  1. #1
    Registered User
    Join Date
    04-20-2009
    Location
    San Francisco
    MS-Off Ver
    Microsoft Excel for Mac 2011
    Posts
    5

    Question Vlookup multiple commas separated values in a cell from another table

    I need to do a vlookup for multiple comma separated values in cell in Table A to range in Table B

    Table A
    User Country
    John America,Europe,Japan
    Mark America
    Sarah Japan,India
    Alex India,Ireland
    Steve Australia


    Table B
    Country Country ID
    America 001
    Europe 002
    Japan 003
    India 004
    Ireland 005
    Australia 006

    Table C (Desired Results)
    User Country Country IDs
    John America,Europe,Japan 001,002,003
    Mark America 001
    Sarah Japan,India 003,004
    Alex India,Ireland 004,005
    Steve Australia 006
    Last edited by shakii; 05-09-2018 at 07:37 PM.

  2. #2
    Administrator FDibbins's Avatar
    Join Date
    12-29-2011
    Location
    Duncansville, PA USA
    MS-Off Ver
    Excel 7/10/13/16/365 (PC ver 2310)
    Posts
    53,048

    Re: Vlookup multiple commas separated values in a cell from another table

    Excel works best if each piece of info is in it's own cell, not combined into 1 cell like that. Is that something you could change to?
    1. Use code tags for VBA. [code] Your Code [/code] (or use the # button)
    2. If your question is resolved, mark it SOLVED using the thread tools
    3. Click on the star if you think someone helped you

    Regards
    Ford

  3. #3
    Registered User
    Join Date
    04-20-2009
    Location
    San Francisco
    MS-Off Ver
    Microsoft Excel for Mac 2011
    Posts
    5

    Re: Vlookup multiple commas separated values in a cell from another table

    Hi,

    This data needs to be in this format, it's actually to give user access for these countries, by entering this file to a DB, that will provide access.

  4. #4
    Forum Moderator
    Join Date
    01-21-2014
    Location
    St. Joseph, Illinois U.S.A.
    MS-Off Ver
    Office 365 V 2504
    Posts
    13,741

    Re: Vlookup multiple commas separated values in a cell from another table

    This uses VBA ... a borrowed User defined function by tigeravatar called Concatall.

    This is the code.
    'tigeravatar ExcelForum
    Public Function ConcatAll(ByVal varData As Variant, Optional ByVal sDelimiter As String = vbNullString, Optional ByVal bUnique As Boolean = False) As String
    'Created by TigerAvatar at www.excelforum.com, September 2012
    'Purpose is to concatenate many strings into a single string
    'Can be used with arrays, range objects, and collections
        
        Dim DataIndex As Variant    'Used to loop through arrays, range objects, and collections
        Dim strResult As String     'Used to build the result string
        
        'Test if varData is an Array, Range, or Collection
        If IsArray(varData) _
        Or TypeOf varData Is Range _
        Or TypeOf varData Is Collection Then
            
            'Found to be an, array, range object, or collection
            'Loop through each item in varData
            For Each DataIndex In varData
                'Check if the item isn't empty
                If Len(DataIndex) > 0 Then
                    'Found the item isn't empty, check if user specified bUnique as True
                    If bUnique = True Then
                        'bUnique is true, check if the item has been included in the result yet
                        If InStr(1, "||" & strResult & "||", "||" & DataIndex & "||", vbTextCompare) = 0 Then
                            'Item has not been included in the result, add item to the result
                            strResult = strResult & "||" & DataIndex
                        End If
                    Else
                        'bUnique is not true, add item to the result
                        strResult = strResult & "||" & DataIndex
                    End If
                End If
            Next DataIndex
            
            'Correct strResult to remove beginning delimiter and convert "||" to the specified sDelimiter
            strResult = Replace(Mid(strResult, 3), "||", sDelimiter)
            
        Else
            'Found not to be an array, range object, or collection
            'Simply set the result = varData
            strResult = varData
        End If
        
        'Output result
        ConcatAll = strResult
        
    End Function
    How to install your new code
    1. Copy the Excel VBA code
    2. Select the workbook in which you want to store the Excel VBA code
    3. Press Alt+F11 to open the Visual Basic Editor
    4. Choose Insert > Module
    5. Edit > Paste the code into the module that appeared
    6. Close the VBEditor
    7. Save your workbook (Excel 2007+ select a macro-enabled file format, like *.xlsm)


    The lookup table for IDs is sorted ascending by country.

    Then array enter this formula in C2 and fill down. If you aren’t familiar with array-entered formulas array enter means the formula must be committed from edit mode by simultaneously pressing and holding down Ctrl and Shift while hitting Enter.
    Formula: copy to clipboard
    =concatall(LOOKUP(TRIM(MID(SUBSTITUTE(B2,",",REPT(" ",LEN(B2))),(ROW(INDIRECT("1:"&LEN(B2)-
    LEN(SUBSTITUTE(B2,",",""))+1))-1)*LEN(B2)+1,LEN(B2))),$G$2:$H$7),",")



    A
    B
    C
    D
    E
    F
    G
    H
    1
    User
    Country
    Country
    Country ID
    2
    John
    America,Europe,Japan
    001,002,003
    America
    001
    3
    Mark
    America
    001
    Australia
    006
    4
    Sarah
    Japan,India
    003,004
    Europe
    002
    5
    Alex
    India,Ireland
    004,005
    India
    004
    6
    Steve
    Australia
    006
    Ireland
    005
    7
    Japan
    003
    Dave

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Formula to count values in single cell separated by commas
    By aimeecrystalaid in forum Excel Formulas & Functions
    Replies: 8
    Last Post: 06-25-2017, 01:01 AM
  2. Replies: 3
    Last Post: 03-10-2017, 07:56 PM
  3. [SOLVED] Return multiple matchng VLOOKUP values in one cell separated by commas?
    By zendoo in forum Excel Formulas & Functions
    Replies: 9
    Last Post: 12-14-2015, 06:10 AM
  4. Replies: 8
    Last Post: 03-31-2015, 01:06 PM
  5. Returning Multiple Values Separated by Commas to a single cell
    By enragedpigeon in forum Excel Formulas & Functions
    Replies: 3
    Last Post: 02-02-2015, 05:48 PM
  6. Find a Value In A Table of Cell Each With More Than 2 Values Separated By Commas
    By Misha322 in forum Excel Programming / VBA / Macros
    Replies: 3
    Last Post: 02-28-2012, 02:42 PM
  7. Replies: 7
    Last Post: 03-05-2010, 04:25 PM

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