Need a VBA macro to convert 3 number combinations to 4 number combinations

goodwillhunting

New Member
Joined
Mar 22, 2023
Messages
1
Office Version
  1. 365
Platform
  1. Windows
Hi All
I have a set of combination of 3 numbers as shown below, in column A1 of an excel worksheet

1,2,4
1,2,5
1,3,4
1,3,5
1,4,5
2,3,5
2,4,5

Please create an excel vba program to convert the above combinations to the possible combination of 4 numbers in such a way that the original 3 number combinations are the subsets of the new 4 number combination.

The answer that I should get is this

1,2,4,5
1,3,4,5
1,2,3,5

Thanks in advance for your help.

Regards
Goodwill Hunting
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
I think this one is not an option since there is no 1,2,3.
Please try the code below. You must enable "Microsoft Scripting Runtime" from References to use dictionaries.
1679559942152.png
1679559975665.png

VBA Code:
Sub test()
  Dim lRow As Long, tmp As Variant, dict As New Scripting.Dictionary

  lRow = Cells(Rows.count, 1).End(xlUp).Row
  For i = 1 To lRow
    tmp = Split(Cells(i, 1).Value, ",")
    For Each t In tmp
      If Not dict.Exists(t) Then
      dict.Add t, 1
      End If
    Next
  Next
 
  SortDictionary dict
 
  Dim items() As Variant
  Dim combLen As Long
 
  combLen = 4
  ReDim items(1 To dict.count)
 
  For i = 1 To UBound(items)
    items(i) = dict.Keys(i - 1)
  Next
 
  items = binomial(items, combLen)
  Dim newComb As String

  For i = 1 To nChooseK(dict.count, combLen)
   For j = 1 To combLen
     newComb = newComb & "," & items(i, j)
   Next

   newComb = Right(newComb, Len(newComb) - 1)

    For k = 1 To lRow
      If Cells(k, 1).Value = Left$(newComb, InStrRev(newComb, ",") - 1) Then
        Range("B" & Cells(Rows.count, "B").End(xlUp).Offset(1).Row).Value = newComb
      End If
    Next
    newComb = ""
  Next
End Sub

Function binomial(ByRef v() As Variant, r As Long) As Variant()
  Dim i As Long, k As Long, z() As Variant, comboMatrix() As Variant
  Dim numRows As Long, numIter As Long, n As Long, count As Long
  
  count = 1
  n = UBound(v)
  numRows = nChooseK(n, r)
 
  ReDim z(1 To r)
  ReDim comboMatrix(1 To numRows, 1 To r)
  For i = 1 To r
    z(i) = i
  Next
  Do While (count <= numRows)
    numIter = n - z(r) + 1
    For i = 1 To numIter
      For k = 1 To r
        comboMatrix(count, k) = v(z(k))
      Next
      count = count + 1
     z(r) = z(r) + 1
    Next
    For i = r - 1 To 1 Step -1
      If Not (z(i) = (n - r + i)) Then
        z(i) = z(i) + 1
        For k = (i + 1) To r
          z(k) = z(k - 1) + 1
        Next
        Exit For
      End If
    Next
  Loop
  binomial = comboMatrix
End Function

Function nChooseK(n As Long, k As Long) As Long
  Dim temp As Double, i As Long
  temp = 1
  For i = 1 To k
    temp = temp * (n - k + i) / i
  Next
  nChooseK = CLng(temp)
End Function

Sub SortDictionary(dict As Object)
    Dim i As Long
    Dim key As Variant

    With CreateObject("System.Collections.SortedList")
        For Each key In dict
            .Add key, dict(key)
        Next
        dict.RemoveAll
        For i = 0 To .Keys.count - 1
            dict.Add .GetKey(i), .Item(.GetKey(i))
        Next
    End With
End Sub
Input is in column A, results are in column B:
1679559780636.png
 
Upvote 0
I think this one is not an option since there is no 1,2,3.
OK, now I got it. Try:
VBA Code:
Sub test()
  Dim lRow As Long, tmp As Variant, dict As New Scripting.Dictionary
  
  lRow = Cells(Rows.count, 1).End(xlUp).Row
  For i = 1 To lRow
    tmp = Split(Cells(i, 1).Value, ",")
    For Each t In tmp
      If Not dict.Exists(t) Then
      dict.Add t, 1
      End If
    Next
  Next
 
  SortDictionary dict
 
  Dim items() As Variant
  Dim combLen As Long
 
  combLen = 4
  ReDim items(1 To dict.count)
 
  For i = 1 To UBound(items)
    items(i) = dict.Keys(i - 1)
  Next
 
  items = binomial(items, combLen)
  Dim newComb As String
  Set findrange = Range("B:B")
  For i = 1 To nChooseK(dict.count, combLen)
    For j = 1 To combLen
      newComb = newComb & "," & items(i, j)
    Next

    newComb = Right(newComb, Len(newComb) - 1)
    
    For k = 1 To lRow
      If InStr(newComb, Cells(k, 1).Value) > 0 Then
        Set foundRng = findrange.Find(newComb)
        If foundRng Is Nothing Then
          Range("B" & Cells(Rows.count, "B").End(xlUp).Offset(1).Row).Value = newComb
        End If
      End If
    Next
    newComb = ""
  Next
End Sub

Function binomial(ByRef v() As Variant, r As Long) As Variant()
  Dim i As Long, k As Long, z() As Variant, comboMatrix() As Variant
  Dim numRows As Long, numIter As Long, n As Long, count As Long
  
  count = 1
  n = UBound(v)
  numRows = nChooseK(n, r)
 
  ReDim z(1 To r)
  ReDim comboMatrix(1 To numRows, 1 To r)
  For i = 1 To r
    z(i) = i
  Next
  Do While (count <= numRows)
    numIter = n - z(r) + 1
    For i = 1 To numIter
      For k = 1 To r
        comboMatrix(count, k) = v(z(k))
      Next
      count = count + 1
     z(r) = z(r) + 1
    Next
    For i = r - 1 To 1 Step -1
      If Not (z(i) = (n - r + i)) Then
        z(i) = z(i) + 1
        For k = (i + 1) To r
          z(k) = z(k - 1) + 1
        Next
        Exit For
      End If
    Next
  Loop
  binomial = comboMatrix
End Function

Function nChooseK(n As Long, k As Long) As Long
  Dim temp As Double, i As Long
  temp = 1
  For i = 1 To k
    temp = temp * (n - k + i) / i
  Next
  nChooseK = CLng(temp)
End Function

Sub SortDictionary(dict As Object)
    Dim i As Long
    Dim key As Variant

    With CreateObject("System.Collections.SortedList")
        For Each key In dict
            .Add key, dict(key)
        Next
        dict.RemoveAll
        For i = 0 To .Keys.count - 1
            dict.Add .GetKey(i), .Item(.GetKey(i))
        Next
    End With
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,820
Messages
6,181,162
Members
453,021
Latest member
Justyna P

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