Hlookup multiple corresponding values

kac1125

Board Regular
Joined
Jul 31, 2014
Messages
77
Office Version
  1. 365
Platform
  1. Windows
Hello,
I am looking for a formula that will list out all the possible transport modes horizontally to the right of Item. all the transport mode associated with the ship ID can be found on sheet 2. I need to see them all horizontally next to item in sheet 1. Please let me know if you have any ideas


Sheet1
A1 B1 C1
[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Ship ID[/TD]
[TD]Item[/TD]
[TD]Transport mode[/TD]
[TD][/TD]
[/TR]
[TR]
[TD][TABLE="width: 122"]
<tbody>[TR]
[TD="width: 122"]100819-0000116[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]111123[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD]100812-0000135

[/TD]
[TD]111124

[/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
[TR]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[TD][/TD]
[/TR]
</tbody>[/TABLE]

Sheet 2
A1 B1
[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]Ship ID[/TD]
[TD]Transport mode[/TD]
[/TR]
[TR]
[TD]100819-0000116[/TD]
[TD]Truck 1[/TD]
[/TR]
[TR]
[TD]100819-0000116[/TD]
[TD]Truck 2[/TD]
[/TR]
[TR]
[TD]100819-0000116[/TD]
[TD]Truck 3[/TD]
[/TR]
[TR]
[TD]100812-0000135[/TD]
[TD]Truck 1[/TD]
[/TR]
[TR]
[TD]100812-0000135[/TD]
[TD]Truck 2[/TD]
[/TR]
</tbody>[/TABLE]


Thanks in advance!
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
In C2 of Sheet1 control+shift+enter, not just enter, and copy down:

=TEXTJOIN(", ",TRUE,IF(Sheet2!$A$2:$A$6=$A2,Sheet2!$B$2:$B$6,""))
 
Upvote 0
Thank you for reviewing. This worked, but is there a way to make it so the Transport modes each show in their own Cells? so for Ship ID 100819-0000116 i would want truck 1 in C2 truck 2 in D2 and truck 3 in E2 and so forth if there are more records.
Please let me know. Thanks again for your help!
 
Upvote 0
Thank you for reviewing. This worked, but is there a way to make it so the Transport modes each show in their own Cells? so for Ship ID 100819-0000116 i would want truck 1 in C2 truck 2 in D2 and truck 3 in E2 and so forth if there are more records.
Please let me know. Thanks again for your help!

In C2 of Sheet1 control+shift+enter, not just enter, copy across, and down:

=IFERROR(INDEX(Sheet2!$B$2:$B$6,SMALL(IF(Sheet2!$A$2:$A$6=$A2,ROW(Sheet2!$B$2:$B$6)-ROW(Sheet2!$B$2)+1),COLUMNS($C2:C2))),"")
 
Upvote 0

Forum statistics

Threads
1,223,164
Messages
6,170,444
Members
452,326
Latest member
johnshaji

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