Modify a code to run all possible combinations

tony0217

Board Regular
Joined
Aug 31, 2012
Messages
134
I have a code below that runs all possible combinations for as many columns as i have in sheet 1.
the problem is that if i have a certain number of cells that would create more than 1,048,000 (excel line limit) different permutations, then the code will stop even though there could be more permutations to calculate.

Can anyone modify this code to continue over to column B and so on so that all possible permutations can be created?

thank you.





Code:
Sub Permute()
Dim ix(100, 1) As Long, rc As Long, m As Long, br As Long, md As Variant, i As Long, r As Long
Dim str1 As String

    rc = Cells(1, Columns.Count).End(xlToLeft).Column
    m = 0
    For i = 1 To rc
        br = Cells(Rows.Count, i).End(xlUp).Row
        If br > m Then m = br
        ix(i, 0) = br
        ix(i, 1) = 1
    Next i
    md = Range(Cells(1, 1), Cells(m, rc)).Value

    r = 0
Incr:
    str1 = ""
    For i = 1 To rc
        str1 = str1 & md(ix(i, 1), i)
    Next i
    r = r + 1
    Sheets("Sheet2").Cells(r, "A") = str1
    
    For i = rc To 1 Step -1
        ix(i, 1) = ix(i, 1) + 1
        If ix(i, 1) <= ix(i, 0) Then Exit For
        ix(i, 1) = 1
    Next i
    If i > 0 Then GoTo Incr:
    
End Sub
 
Last edited:
it seems we have the matching mixed up, but you are surely on the right track.

AB BC AC

I need to match the A's, B's and C's together. I think i told it to you backwards?

That would make this code perfect
 
Upvote 0

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Try:

Rich (BB code):
Sub Permute()
Dim ix(100, 1) As Long, rc As Long, m As Long, br As Long, md As Variant, i As Long, r As Long
Dim str1 As String, r1 As Long, c1 As Long, element(100) As Variant

    rc = Cells(1, Columns.Count).End(xlToLeft).Column
    m = 0
    For i = 1 To rc
        br = Cells(Rows.Count, i).End(xlUp).Row
        If br > m Then m = br
        ix(i, 0) = br
        ix(i, 1) = 1
    Next i
    md = Range(Cells(1, 1), Cells(m, rc)).Value
    r = 0
Incr:
    str1 = ""
    For i = 1 To rc
        str1 = str1 & md(ix(i, 1), i)
        element(i) = md(ix(i, 1), i)
    Next i

MyCode:
    If Mid(element(1), 2, 1) = Mid(element(2), 1, 1) And _
       Mid(element(2), 2, 1) = Mid(element(3), 2, 1) And _
       Mid(element(1), 1, 1) = Mid(element(3), 1, 1) Then
        r = r + 1
        r1 = ((r - 1) Mod Rows.Count) + 1
        c1 = Int((r - 1) / Rows.Count) + 1
        Sheets("Sheet2").Cells(r1, c1) = str1
    End If
    
    For i = rc To 1 Step -1
        ix(i, 1) = ix(i, 1) + 1
        If ix(i, 1) <= ix(i, 0) Then Exit For
        ix(i, 1) = 1
    Next i
    If i > 0 Then GoTo Incr:
    
End Sub
I tweaked it a bit. To make it a bit easier to read, I put the parts of each permutation in an array called "element". So element(1) is the element from the first column, element(2) from the second column, etc. Now to compare them, use the Mid function. Mid has 3 parameters: the string you are looking at, the starting position, and the length. So in the comparison above in red, there are 3 lines. One for the A, B, and C of your example. The first line compares the second letter of the first element with the first letter of the second element. And the other lines handle C and A. You should be able to modify that as needed. And the code already handles multiple columns, up to 100.

Good luck.
 
Upvote 0
Magnificent!
My question about adding columns, I mean if i want to add a fourth comparison in the fourth column how would i add it in?
like a fourth Mid element line.
 
Upvote 0
Just add another line to the IF statement in red from post 12, using Mid(element(4), x, 1) and whatever you want to compare it to.
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,176
Members
448,554
Latest member
Gleisner2

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