Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Listing Combinations.
Written by Allen Wyatt (last updated June 29, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Ron knows he can use the COMBIN function to determine the number of combinations that can be made from a number of digits. He's wondering, however, if there is a way to list out all the combinations themselves.
There is no built-in way to list combinations in Excel. You can, however, create a macro to do the listing for you. If you want to find the unique combinations in a set of sequential numbers starting at 1, then the following set of macros will do the trick. All you need to do is run the function TestCNR and you will end up with a "matrix" of cells that represent the number of 4-digit combinations in the sequential set of values ranging from 1 to 10.
Sub TestCNR() Cnr 10, 4 End Sub
Sub Cnr(n, r) i = 1 For j = 1 To r Cells(i, j).Value = j Next Do Until Finished(n, r, i) j = FindFirstSmall(n, r, i) For k = 1 To j — 1 Cells(i + 1, k).Value = Cells(i, k).Value Next Cells(i + 1, j).Value = Cells(i, j).Value + 1 For k = j + 1 To r Cells(i + 1, k).Value = Cells(i + 1, k - 1).Value + 1 Next i = i + 1 Loop End Sub
Function Finished(n, r, i) Temp = True For j = r To 1 Step -1 If Cells(i, j).Value <> j + (n - r) Then Temp = False End If Next Finished = Temp End Function Function FindFirstSmall(n, r, i) j = r Do Until Cells(i, j).Value <> j + (n - r) j = j - 1 Loop FindFirstSmall = j End Function
The macro overwrites whatever is in your worksheet, so make sure you run the test with a blank worksheet displayed. If you want to change the size of the set or the number of elements in the subset, just change the values passed in the TestCNR routine.
If you want to pull unique combinations from a string of characters (for instance, the letters of the alphabet), then you need to use a different set of macros. The following will work fine; it assumes that the characters you want to use as your "universe" is in cell A1 and the number you want in each unique combination is in cell A2.
Sub FindSets() Dim iA() As Integer Dim sUniv As String Dim iWanted As Integer Dim j As Integer Dim k As Integer sUniv = Cells(1, 1).Value iWanted = Cells(2, 1).Value ReDim iA(iWanted) For j = 1 To iWanted iA(j) = j Next j iRow = PutRow(iA, sUniv, 1) Do Until DoneYet(iA, Len(sUniv)) j = WorkHere(iA, Len(sUniv)) iA(j) = iA(j) + 1 For k = j + 1 To iWanted iA(k) = iA(k - 1) + 1 Next k iRow = PutRow(iA, sUniv, iRow) Loop End Sub
Function DoneYet(iB, n) As Boolean iMax = UBound(iB) Temp = True For j = iMax To 1 Step -1 If iB(j) <> j + (n - iMax) Then Temp = False End If Next DoneYet = Temp End Function
Function WorkHere(iB, n) As Integer iMax = UBound(iB) j = iMax Do Until iB(j) <> j + (n - iMax) j = j - 1 Loop WorkHere = j End Function
Function PutRow(iB, sUniv, i) iMax = UBound(iB) sTemp = "" For j = 1 To iMax sTemp = sTemp & Mid(sUniv, iB(j), 1) Next j Cells(i, 2).Value = sTemp PutRow = i + 1 End Function
Run the FindSets macro and the different combinations desired end up in column 2. Be careful when running the macro, however. The number of combinations can get very large very quickly.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11891) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Listing Combinations.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Do you ever have a need to return just a few digits out of a number? This tip shows different formulas you can use to ...
Discover MoreWhen working with large amounts of data, it is a good idea to make sure that the data all consistently follows a pattern. ...
Discover MoreSearching for a value using Excel's Find tool is easy; searching for that same value using a formula or a macro is more ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-07-08 07:04:44
Graham
Hi Allen, I'm attempting to list out combinations for a set of numbers, such as 11, 12, 13, 14, 15, 16 in 4-digit combinations (eg 12 13 14 15; 11 13 15 16;). I've tried the second set of macros and have not figured out a way to separate the numbers in a single cell for excel to recognise the 2 characters a whole - 1 integer (eg 12 not 1 AND THEN 2). Is this doable by adjusting the second set of macros above or can this be accomplished at all with excel? Thank you. Graham
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments