Finding a repeated value in Col A, then merging all values in next cell (Col B) into one cell

emedley

New Member
Joined
Nov 17, 2015
Messages
23
Please could someone provide a formula to do the following?

I have a table with 3 columns A, B, C
Col A is an ITEM number
Col B is the EDITION number of the ITEM
Col C is where I manually enter the ITEM number I am interested in
Col D is where the final result needs to be displayed

Example: I enter the ITEM number of interest to me in Col C, in this case "p5".
The formula I need (to be in Col D) finds all instances of ITEM "p5" in Col A, then returns all of the ITEM's EDITION values (Col B) into one cell, separating each value with a hash (#)

Conditions:
ITEM numbers (Col A) are not sorted and can be repeated at random intervals.
COL A
ITEM
COL B
ITEM'S EDITION
COL C
CHOSEN ITEM
COL D
ITEM's EDITIONS
p11ap5j#1#f3
p24r
p33
p41
p5j
p51
p30
p103
p43c
p5f3

<colgroup><col><col><col><col></colgroup><tbody>
</tbody>
 

Excel Facts

When did Power Query debut in Excel?
Although it was an add-in in Excel 2010 & Excel 2013, Power Query became a part of Excel in 2016, in Data, Get & Transform Data.

mohammad2060

New Member
Joined
Jul 28, 2015
Messages
19
use this UDF:

Function vlookupall(sSearch As String, rRange As Range, _
Optional lLookupCol As Long, Optional sDel As String) As String
Dim i As Long, sTemp As String
If lLookupCol > rRange.Columns.Count Or sSearch = "" Or _
(lLookupCol < 0 And rRange.Columns.Count > 1) Then
vlookupall = CVErr(xlErrValue)
Exit Function
End If
vlookupall = ""
For i = 1 To rRange.Rows.Count
If rRange(i, 1).Text = sSearch Then
If lLookupCol >= 0 Then
vlookupall = vlookupall & sTemp & rRange(i, lLookupCol).Text
Else
vlookupall = vlookupall & sTemp & rRange(i).Offset(0, lLookupCol).Text
End If
sTemp = sDel
End If
Next i
End Function
 

emedley

New Member
Joined
Nov 17, 2015
Messages
23
I tried running it but got an error message:
"Compile error:
Expected End Sub"
 

emedley

New Member
Joined
Nov 17, 2015
Messages
23

ADVERTISEMENT

Found a formula-based solution!

(Assume Column headers are Row 1 and data starts in row 2)

Array formula (press CTRL/Shift/Enter) to enter in Col D is:

=TEXTJOIN("#",1,REPT($B$2:$B$11,1*($A$2:$A$11=C$2)))
 

emedley

New Member
Joined
Nov 17, 2015
Messages
23
Thanks, but it's in Arabic script, which I cannot read.

Good news is, I've since found a solution using an (array) formula, which I have posted.
 

Peter_SSs

MrExcel MVP, Moderator
Joined
May 28, 2005
Messages
51,826
Office Version
  1. 365
Platform
  1. Windows

ADVERTISEMENT

You could also use this slightly simpler array formula
=TEXTJOIN("#",1,IF(A2:A11=C2,B2:B11,""))
 

Forum statistics

Threads
1,148,108
Messages
5,744,876
Members
423,907
Latest member
zerocool88

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
Top