Pull together same category winners VBA? or Textjoin

szita2000

Board Regular
Joined
Apr 25, 2012
Messages
101
Office Version
  1. 365
Platform
  1. Windows
Hi Guys.

I am trying to find a solution to this.
I have a list of winners and categories they won in.
KL
20Jimmy JohnSinging
21Billy BobDancing
22Sue PartridgeSinging
23Jones SmithGuitar
24Blake BorisDrum
25John WellingtonGuitar

<tbody>
</tbody>



I need to pull them together where each category have one cell and the winners are displayed with a separator. Like a result of a SUMIF only to "Bring me out if..."


AB
24SingingJimmy John, Sue Partridge
25DancingBilly Bob
26GuitarJones Smith, John Wellington
27DrumBlake Boris

<tbody>
</tbody>


1. Is there any way to do this with formula, or I will need to do it with VBA?
I am aware of the new TEXTJOIN formula, but I can't figure out, how would I get out the first, second and nth occurence.

2.How would you do it in VBA?
My best guess is to loop through each category and if it matches the list, bring out the name. with an offset + a separator

Thanks

Thomas


 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
How about


Book1
ABIJKL
20Jimmy JohnSinging
21Billy BobDancing
22Sue PartridgeSinging
23Jones SmithGuitar
24SingingJimmy John, Sue PartridgeBlake BorisDrum
25DancingBilly BobJohn WellingtonGuitar
26GuitarJones Smith, John Wellington
27DrumBlake Boris
RC
Cell Formulas
RangeFormula
B24{=TEXTJOIN(", ",TRUE,IF($L$20:$L$25=A24,$K$20:$K$25,""))}
Press CTRL+SHIFT+ENTER to enter array formulas.
 
Upvote 0
Hi Fluff.

Thanks again!

You know, the beauty of this solution is that it is so simple once you decipher it. :)
Thanks a mill.
 
Upvote 0
You're welcome & thanks for the feedback
 
Upvote 0
Hi there
And if you like a vba code Try this
Code:
Sub test()
    Dim a As Variant, lr
    a = Range("k20:k" & Cells(Rows.Count, 11).End(xlUp).Row).Resize(, 2)
    With CreateObject("scripting.dictionary")
        For i = 1 To UBound(a)
            If Not .exists(a(i, 2)) Then
                .Add a(i, 2), a(i, 1)
            Else
                .Item(a(i, 2)) = .Item(a(i, 2)) & "," & a(i, 1)
            End If
        Next
        Range("a24").Resize(.Count) = Application.Transpose(.Keys)
        Range("b24").Resize(.Count) = Application.Transpose(.items)
    End With
End Sub
 
Upvote 0
Something similar to mohadin's code.
Before running the macro, select the source range.
Code:
Sub Consolidate()


    Dim dic1        As Object
    Dim rngS        As Range
    Dim varData     As Variant
    Dim i           As Long
    Dim rngDest     As Range


    Set rngS = Selection


    varData = rngS.Value


    Set dic1 = CreateObject("Scripting.Dictionary")


    For i = 1 To UBound(varData)
        If dic1.Exists(varData(i, 2)) Then
            dic1(varData(i, 2)) = dic1(varData(i, 2)) & ", " & varData(i, 1)
        Else
            dic1.Add varData(i, 2), varData(i, 1)
        End If
    Next i


    On Error Resume Next
    Set rngDest = Application.InputBox("Choose destination", Type:=8)
    If Err.Number <> 0 Then Exit Sub
    On Error GoTo 0
    
    rngDest.Resize(dic1.Count).Value = Application.Transpose(dic1.Keys)
    rngDest.Offset(, 1).Resize(dic1.Count).Value = Application.Transpose(dic1.Items)


End Sub
Artik
 
Upvote 0

Forum statistics

Threads
1,214,985
Messages
6,122,606
Members
449,089
Latest member
Motoracer88

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