Need all unique combinations of a single column

Goldheart

New Member
Joined
Dec 15, 2021
Messages
3
Office Version
  1. 2016
Platform
  1. Windows
I need to create a list of unique name combinations from a single column, for example:

Mary
Jim
Henry
Candy

And output all unique combinations but also grouped up to the number of names. E.G. Mary + Jim, Mary + Jim + Henry, etc. The name column may vary in total names. Perhaps output one column with pairs, one with triples, quads, etc.

Thank you for any assistance!
 

Excel Facts

Why does 9 mean SUM in SUBTOTAL?
It is because Sum is the 9th alphabetically in Average, Count, CountA, Max, Min, Product, StDev.S, StDev.P, Sum, VAR.S, VAR.P.
I don't think that 2016 has the Concat function. This might be trouble.

Cell Formulas
RangeFormula
B3:B18B3=ROW(INDIRECT("1:"&2^COUNTA(A3:A29)))
C3:C18C3=CONCAT(IF(BITAND(B3,(2^(ROW(INDIRECT("1:"&COUNTA($A$3:$A$20)))-1)))>0,INDEX($A$3:$A$20,ROW(INDIRECT("1:"&COUNTA($A$3:$A$20)))) & " ",""))
Dynamic array formulas.
 
Upvote 0
Here's a macro version. Starting with

Book1
A
1Names
2Mary
3Jim
4Henry
5Candy
6
Sheet15


Run this macro:

VBA Code:
Sub Subsets()
Dim MyNames As Variant, OutCell As Range, MyDic As Object, i As Long

    MyNames = Range(Range("A2"), Range("A2").End(xlDown)).Value
    Set OutCell = Range("C1")
    
    For i = 1 To UBound(MyNames)
        Set MyDic = CreateObject("Scripting.Dictionary")
        MyDic(0) = "Sets of " & i
        Call RecurSubs(MyNames, i, 0, 0, "", MyDic)
        OutCell.Offset(, i - 1).Resize(MyDic.Count).Value = WorksheetFunction.Transpose(MyDic.items)
        Set MyDic = Nothing
    Next i
    
End Sub

Sub RecurSubs(ByRef MyNames, ByRef MaxLevel, ByVal CurLevel, ByVal ix, ByVal str1, ByRef MyDic)
Dim i As Long

    If CurLevel = MaxLevel Then
        MyDic(MyDic.Count) = Left(str1, Len(str1) - 2)
        Exit Sub
    End If
    
    For i = ix + 1 To UBound(MyNames)
        Call RecurSubs(MyNames, MaxLevel, CurLevel + 1, i, str1 & MyNames(i, 1) & ", ", MyDic)
    Next i
    
End Sub

And you'll get this:

Book1
ABCDEF
1NamesSets of 1Sets of 2Sets of 3Sets of 4
2MaryMaryMary, JimMary, Jim, HenryMary, Jim, Henry, Candy
3JimJimMary, HenryMary, Jim, Candy
4HenryHenryMary, CandyMary, Henry, Candy
5CandyCandyJim, HenryJim, Henry, Candy
6Jim, Candy
7Henry, Candy
8
Sheet15


It adjusts for a variable number of names. You can set the input cell (A2) in the top line of the macro, and the output starting cell (C1) in the next line.
 
Upvote 0
Solution
Here's a macro version. Starting with

Book1
A
1Names
2Mary
3Jim
4Henry
5Candy
6
Sheet15


Run this macro:

VBA Code:
Sub Subsets()
Dim MyNames As Variant, OutCell As Range, MyDic As Object, i As Long

    MyNames = Range(Range("A2"), Range("A2").End(xlDown)).Value
    Set OutCell = Range("C1")
   
    For i = 1 To UBound(MyNames)
        Set MyDic = CreateObject("Scripting.Dictionary")
        MyDic(0) = "Sets of " & i
        Call RecurSubs(MyNames, i, 0, 0, "", MyDic)
        OutCell.Offset(, i - 1).Resize(MyDic.Count).Value = WorksheetFunction.Transpose(MyDic.items)
        Set MyDic = Nothing
    Next i
   
End Sub

Sub RecurSubs(ByRef MyNames, ByRef MaxLevel, ByVal CurLevel, ByVal ix, ByVal str1, ByRef MyDic)
Dim i As Long

    If CurLevel = MaxLevel Then
        MyDic(MyDic.Count) = Left(str1, Len(str1) - 2)
        Exit Sub
    End If
   
    For i = ix + 1 To UBound(MyNames)
        Call RecurSubs(MyNames, MaxLevel, CurLevel + 1, i, str1 & MyNames(i, 1) & ", ", MyDic)
    Next i
   
End Sub

And you'll get this:

Book1
ABCDEF
1NamesSets of 1Sets of 2Sets of 3Sets of 4
2MaryMaryMary, JimMary, Jim, HenryMary, Jim, Henry, Candy
3JimJimMary, HenryMary, Jim, Candy
4HenryHenryMary, CandyMary, Henry, Candy
5CandyCandyJim, HenryJim, Henry, Candy
6Jim, Candy
7Henry, Candy
8
Sheet15


It adjusts for a variable number of names. You can set the input cell (A2) in the top line of the macro, and the output starting cell (C1) in the next line.
Perfect! Works great thank you!
 
Upvote 0
By the way, I think we have the same or similar name. I am Eric West.
 
Upvote 0

Forum statistics

Threads
1,223,903
Messages
6,175,284
Members
452,630
Latest member
OdubiYouth

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