+ Reply to Thread
Results 1 to 5 of 5

One ID return multiple values

  1. #1
    Registered User
    Join Date
    09-18-2019
    Location
    the hague
    MS-Off Ver
    Office 365
    Posts
    5

    One ID return multiple values

    Hi there,

    I am trying to join two tables based on one column as I want to see what names occur for every ID.
    I cant figure out how to do this with vlookup or index match as there are multiple names for one ID (and the same name for multiple ID's). An example can be found in the attachement.

    Thank you in advance,
    Stalen Ros
    Attached Files Attached Files

  2. #2
    Forum Expert PaulM100's Avatar
    Join Date
    10-09-2017
    Location
    UK
    MS-Off Ver
    Office 365
    Posts
    2,108

    Re: One ID return multiple values

    I would start in O2(in my case S2): =IFERROR(IFERROR(LOOKUP(2, 1/(COUNTIF($S$1:S1,Tabel4[Name])=0), Tabel4[Name]), LOOKUP(2, 1/(COUNTIF($S$1:S1, Tabel5[Name2])=0), Tabel5[Name2])),"")
    Then for M: =IFERROR(INDEX(Tabel4[Year],MATCH($S2,Tabel4[Name],0)),"")
    for N: =IFERROR(IFERROR(INDEX(Tabel4[ID],MATCH($S2,Tabel4[Name],0)),INDEX(Tabel5[ID2],MATCH($S2,Tabel5[Name2],0))),"")
    for P:=IFERROR(VLOOKUP($S2,Tabel5[[Name2]:[Company]],2,0),"")
    Just change the S refferences to O.
    Click the * to say thanks.

  3. #3
    Registered User
    Join Date
    09-18-2019
    Location
    the hague
    MS-Off Ver
    Office 365
    Posts
    5

    Re: One ID return multiple values

    Thank you for the reply. It works partially.
    The names John and Jane occur in both tables, in table 1 with ID A1 and in table 2 with ID A3. I would like to show in the new table that there are two Johns and two Janes with different ID's. This is at the moment with the stated function not the case (and I cant get it to work).

    Stalen Ros

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: One ID return multiple values

    I'm not sure if I understand... but in L2, an array formula:
    =IFERROR(IFERROR(INDEX(Tabel4[Year]&"¦"&Tabel4[ID]&"¦"&Tabel4[Name], MATCH(0, COUNTIF($L$1:L1, Tabel4[Year]&"¦"&Tabel4[ID]&"¦"&Tabel4[Name]), 0)), INDEX("¦"&Tabel5[ID2]&"¦"&Tabel5[Name2]&"¦"&Tabel5[Company], MATCH(0, COUNTIF($L$1:L1, "¦"&Tabel5[ID2]&"¦"&Tabel5[Name2]&"¦"&Tabel5[Company]), 0))), "")

    copied down. Then, in M2, copied across and down:

    =TRIM(MID(SUBSTITUTE("¦"&$L2,"¦",REPT(" ",125)),125*COLUMNS($M:M),125))

    Array Formulae are a little different from ordinary formulae in that they MUST be confirmed in the FIRST CELL ONLY by pressing CTRL+SHIFT+ENTER to activate the array, not just ENTER. After that, the array can be dragged down as normal, to cover the desired range.

    You will know the array is active when you see curly brackets { } - or "curly braces" for those of you in the USA, or "flower brackets" for those of you in India - appear around the outside of your formula. If you do not use CTRL+SHIFT+ENTER you will (almost always) get an error message or an incorrect answer. Press F2 on that cell and try again.

    Don't type the curly brackets yourself - it won't work...
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  5. #5
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,893

    Re: One ID return multiple values

    Your file...
    Attached Files Attached Files

+ 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. Replies: 3
    Last Post: 03-10-2017, 07:56 PM
  2. Replies: 2
    Last Post: 05-26-2015, 07:29 PM
  3. Replies: 4
    Last Post: 05-12-2014, 07:10 PM
  4. Replies: 3
    Last Post: 12-13-2013, 06:23 AM
  5. [SOLVED] Return value if within range, return multiple values if ranges overlap
    By cde1983 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 08-17-2013, 06:16 AM
  6. Replies: 5
    Last Post: 08-04-2013, 09:49 AM
  7. How to find closest values in multiple columns and return adjacent values.
    By Patrician in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 01-28-2013, 01:47 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