Multiple results in VLOOKUP

jwpickett

New Member
Joined
Jan 19, 2005
Messages
36
I'm trying to figure out how to retrieve multiple values from a VLOOKUP.

There are instances where a particiular tax number may have many names attached to it, and I need to incorporate those names onto another sheet with thousands of lookup values.

For example,
Tax Number, Name
12345, jones
12345, smith
12345, doe
12345, johnson
23456, davis
23456, williams
23456, taylor
34567, smythe
(commas indicate column separation and each tax number is on a separate line)

My result should appear as:
12345, jones/smith/doe/johnson
23456, davis/williams/taylor
34567, smythe

Construction of the VLOOKUP is not a problem. It's getting all the answers.

Thanks
 

Excel Facts

Quick Sum
Select a range of cells. The total appears in bottom right of Excel screen. Right-click total to add Max, Min, Count, Average.
Unfortunately vlookup cannot handle duplicate values ... you can only obtain the first or last entry. I do not believe there are any formulas that can help you out in this situation. If macros are an option, you should go that route.
 
Upvote 0
I guess for a dumb response I could say,
"If I knew how do do a macro I probably wouldn't need to post my questions".

And I thought a VBA was a very boisterous "person".

But I was afraid you might say what you did. It was one of those "tell me it ain't so"!
 
Upvote 0
First, download and install the free add-in, Morefunc. Then try the following...

D2:

=COUNTDIFF(A2:A9)

E2, copied down:

=IF(ROWS(E$2:E2)<=$D$2,INDEX(UNIQUEVALUES($A$2:$A$9,1),ROWS(E$2:E2)),"")

F2, confirmed with CONTROL+SHIFT+ENTER, and copied down:

=SUBSTITUTE(MCONCAT(IF($A$2:$A$9=E2,"/"&$B$2:$B$9,"")),"/","",1)

Hope this helps!
 
Upvote 0
You can install a small function of your own if you don't want to install an entire pack. Jindon from here on the forum offers this:
Code:
Function JoinAll(ByVal BaseValue, ByRef rng As Range, ByVal delim As String)
'code by Jindon, MrExcel.com MVP
Dim a, i As Long
a = rng.Value
For i = 1 To UBound(a, 1)
    If a(i, 1) = BaseValue Then JoinAll = JoinAll & _
        IIf(JoinAll = "", "", delim) & a(i, 2)
Next
End Function
Add it to your sheet by pressing Alt-F11 to open the VBEditor
Click Insert > Module
Paste in the code above
Al-F11 to close the Editor
Save your sheet.

Now, to get your unique values use the two formulas listed below in D1 and D2, array entered with CTRL-SHIFT-ENTER, not just enter or it won't work. The formula in D2 can then be dragged down as far as necessary to get all the unique values to appear.

Then in E1, use the new function you installed above. Type in the E1 formula and just copy it down.

Excel Workbook
ABCDE
112345jones*12345jones, smith, doe, johnson
212345smith*23456davis, williams, taylor
312345doe*34567smythe
412345johnson***
523456davis***
623456williams***
723456taylor***
834567smythe***
Sheet3
 
Upvote 0

Forum statistics

Threads
1,223,840
Messages
6,174,953
Members
452,593
Latest member
Jason5710

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top