Concatenate Multiple Cells with Array Formula

mgirvin

Well-known Member
Joined
Dec 15, 2005
Messages
1,245
Office Version
  1. 365
Platform
  1. Windows
Dear Smartest Excelers In The World,

If I have the following data set in cells A1:C9:

ID Comment First Unique
109876 Low Oil TRUE
109876 Checked On 12/12 FALSE
109877 Checked on 12/15 TRUE
109878 Correct Level TRUE
109877 Correct Level FALSE
109878 Perfect FALSE
109877 New FALSE
109878 Correct Level FALSE

In the First Unique column (column C) I have formulas. In C2 I have this formula (and then I copied it down):

=COUNTIF(A$2:A2,A2)=1

In cell E2, I have this formula to count unique occurrences:

=SUMPRODUCT(C2:C9*1)

In cell G2 I have this formula to extract unique records (entered with Ctrl + Shift + Enter):

=IF(ROWS(G$2:G2)<=E$2,INDEX(A$2:A$9,SMALL(IF(C$2:C$9=TRUE,ROW(C$2:C$9)-ROW(C$2)+1),ROWS(G$2:G2))),"")

Now, in cell H2 I would like a formula that would concatenate all the comments from the Comments column in the data set for each unique ID.

For example, For ID # 109876, I would like the formula to yield this text string in cell H2:

“Low Oil, Checked On 12/12”

Any ideas?
 

Excel Facts

What is the shortcut key for Format Selection?
Ctrl+1 (the number one) will open the Format dialog for whatever is selected.
Dear pgc01,

Thank you. That is good information.

Does the term "Native" mean one cell?
 
Upvote 0
Does the term "Native" mean one cell?

No, it means the functions available in excel when you install it, like SUM(), VLOOKUP(), AVERAGE(), etc.

You can then add the functions you write, you call them UDFs (Used Defined Functions).

In this case you can write, for ex., a function that concatenates an array.
 
Upvote 0
This function was posted here recently (Jindon?) and does what you want, I believe:
Code:
Function JoinAll(ByVal BaseValue, ByRef rng As Range, ByVal delim As String)
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

Used like:
=JoinAll(Cell,Range,Delimiter)

Here it is in action:
 
Upvote 0
Dear jbeaucaire,

Wow!

That user defined function by Jindon is so efficient- so perfect for this task!

Blows away the formula approach that I was attempting.

Thanks!
 
Upvote 0
Definitely. I looked up and confirmed the authorship and added it permanently to the code itself, appropriate, don't you think?

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

Jindon
 
Upvote 0
The arguments of the UDF ConcatIf mirror those of SumIf, with the addtition of an optional Delimiter argument. For your situation the formula would be
=ConcatIf(A:A, 109876, B:B, ", ")
Code:
Function ConcatIf(ByVal compareRange As Range, ByVal xCriteria As Variant, Optional ByVal stringsRange As Range, _
                            Optional Delimiter As String, Optional NoDuplicates As Boolean) As String
    Dim i As Long, j As Long
    With compareRange.Parent
    Set compareRange = Application.Intersect(compareRange, Range(.UsedRange, .Range("a1")))
     End With
    If compareRange Is Nothing Then Exit Function
    If stringsRange Is Nothing Then Set stringsRange = compareRange
    Set stringsRange = compareRange.Offset(stringsRange.Row - compareRange.Row, _
                                                stringsRange.Column - compareRange.Column)
    
        For i = 1 To compareRange.Rows.Count
            For j = 1 To compareRange.Columns.Count
                If (Application.CountIf(compareRange.Cells(i, j), xCriteria) = 1) Then
                    If InStr(ConcatIf, Delimiter & CStr(stringsRange.Cells(i, j))) <> 0 Imp Not (NoDuplicates) Then
                        ConcatIf = ConcatIf & Delimiter & CStr(stringsRange.Cells(i, j))
                    End If
                End If
            Next j
        Next i
        ConcatIf = mid(ConcatIf, Len(Delimiter) + 1)
    End Function
 
Upvote 0
The following solution uses MCONCAT function from MoreFunc Add-in as mentioned by PgC01 earlier ...

<html><head><title>Excel Jeanie HTML</title></head><body>
Excel Workbook
ABCDEF
2109876Low OilTRUE*109876Low Oil,Checked On 12/12
3109876Checked On 12/12FALSE***
4109877Checked on 12/15TRUE***
5109878Correct LevelTRUE***
6109877Correct LevelFALSE***
7109878PerfectFALSE***
8109877NewFALSE***
9109878Correct LevelFALSE***
Sheet7


</body></html>
 
Upvote 0
Dear mikerickson and Yogi,

Wow, so many great solutions! Thanks!

And, yes, jbeaucaire, your extra code is appropriate. However, when I pasted mine, I put:

‘Jindon with help from jbeaucaire

You all are great!
 
Upvote 0

Forum statistics

Threads
1,224,830
Messages
6,181,228
Members
453,025
Latest member
Hannah_Pham93

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