list all unique combinations from list

palaeontology

Active Member
Joined
May 12, 2017
Messages
444
Office Version
  1. 2016
Platform
  1. Windows
I have the following dynamic list (and yes, the list can sometimes [like in this example] have some blank entries at the beginning) ...

8.JPG


Is there a way (either through formula or vb code .. I'm trying to avoid the need for the user to click a series of ribbon options, etc) to return a list of all possible unique combinations of letters from that list ?

For example, the unique combinations for the list above would be ....

BK
BO
KO

Note: I don't want BB, KK or OO to be returned.

Here's another example ...

9.JPG

This list should yield the following unique combinations ...

RG
RA
RF
RJ
GA
GF
GJ
AF
AJ
FJ

I've tried to set up a matrix solution, but not sure how to do that in excel, or even if that will return the result that I need.

I know that the number of unique combinations follows Pascal's Triangle. So ...
2 letters will have 1 possible combination
3 letters will have 3 possible combination
4 letters will have 6 possible combination
5 letters will have 10 possible combination
etc

but not sure how to use that knowledge in deriving a solution.

Any assistance would be greatly appreciated.

Very kind regards,

Chris
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Another approach that you could consider.

VBA Code:
Sub All2Combos()
  Dim a As Variant, b As Variant
  Dim i As Long, j As Long, x As Long, y As Long
 
  a = Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
  ReDim b(1 To UBound(a))
  For i = 1 To UBound(a)
    If Len(a(i, 1)) > 0 Then
      x = x + 1: b(x) = a(i, 1)
    End If
  Next i
  ReDim a(1 To WorksheetFunction.Combin(x, 2), 1 To 1)
  For i = 1 To x - 1
    For j = i + 1 To x
      y = y + 1: a(y, 1) = b(i) & b(j)
    Next j
  Next i
  Range("C2").Resize(y).Value = a
End Sub
Hi, your code works wonderfully, but I'm looking for something similar but don't omit the combination if the elements are repeated. For example, I want to keep RR, GG, KK. How would I modify the code?
 
Last edited by a moderator:
Upvote 0
Hi, your code works wonderfully, but I'm looking for something similar but don't omit the combination if the elements are repeated. For example, I want to keep RR, GG, KK. How would I modify the code?
You have quoted the code from post #5. That code, modified to allow letters to be repeated would be:

VBA Code:
Sub All2CombosWithDupes()
  Dim a As Variant, b As Variant
  Dim i As Long, j As Long, x As Long, y As Long
  
  a = Range("A2", Range("A" & Rows.Count).End(xlUp)).Value
  ReDim b(1 To UBound(a))
  For i = 1 To UBound(a)
    If Len(a(i, 1)) > 0 Then
      x = x + 1: b(x) = a(i, 1)
    End If
  Next i
  ReDim a(1 To WorksheetFunction.Combin(x + 1, 2), 1 To 1)
  For i = 1 To x
    For j = i To x
      y = y + 1: a(y, 1) = b(i) & b(j)
    Next j
  Next i
  Range("C2").Resize(y).Value = a
End Sub

My sample data and results:

BigBeachBananas.xlsm
ABC
1
2RR
3RG
4RRA
5GRF
6ARJ
7FGG
8JGA
9GF
10GJ
11AA
12AF
13AJ
14FF
15FJ
16JJ
17
Sheet1
 
Upvote 0

Forum statistics

Threads
1,223,907
Messages
6,175,300
Members
452,633
Latest member
DougMo

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