Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Listing Combinations.

Listing Combinations

Written by Allen Wyatt (last updated October 26, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003


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. For instance, if you put 26 letters (A through Z) in cell A1 and the value 5 in cell A2, the macro will crash. Why? Because there are 65,780 possible five-character combinations and only 65,536 rows in which to place them.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (6766) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Listing Combinations.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Creating a Table of Contents from Heading Levels

If your document is any length at all, adding a table of contents is a nice touch. This tip demonstrates how easy it is ...

Discover More

Summing a Table Column

Need to add a sum to a column of figures in a table? Word makes it relatively easy to provide the sum you need.

Discover More

Removing Duplicates in Word

If you have information in Word such as e-mail addresses or part numbers, your document might include duplicates. This ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (menu)

Deriving High and Low Non-Zero Values

When analyzing your numeric data, you may need to figure out the largest and smallest numbers in a set of values. If you ...

Discover More

Starting Out Formulas

When you enter a formula from the keyboard, Excel only knows it is a formula if you start it with an equal sign. You can ...

Discover More

Solving Simultaneous Equations

One branch of mathematics allows you to work with what are called "simultaneous equations." Working with this type of ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is two more than 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.