Tracking all combinations

mac_see

Active Member
Joined
Oct 15, 2002
Messages
419
This is a tough one. I hope I will be able to explain the scnerio. Ok.. Let me try.

I have ten workers "A", "B", "C", "D", "E", "F", "G", "H", "I", "J" and "K". I have kept them in the range A1:A11

I want to create groups. Each group will consist of 4 workers. Every worker should get an opportunity to work with all the other workers.

Example:
"A", "B", "C" & "D"
"A", "C", "D" & "E"
"A", "B", "D" & "E"
"A", "B", "C" & "E"

and so on...................

Can this be done by using a formula.... Tracking all combinations would be very difficult to do it manually.

Maxi
 
plettieri said:
Hi:

Just a footnote on how to get the total required

=COMBIN(10,4) equals the 210 required.

plettieri

I'd never used COMBIN before! And it goes above 170!
 
Upvote 0

Excel Facts

Control Word Wrap
Press Alt+Enter to move to a new row in a cell. Lets you control where the words wrap.
Hey plettieri,

One problem,

If I keep the Number of items as 70
and Taken how many at a time as 10

I get Run-time error '1004':
Application-defined or object-defined error (Thats because, its exceeding the row limit in excel)

The formula =COMBIN(70,10) gives a value 3.96705E+11

Is there any way I can find how many combinations it would be if not the actual combinations?

Maxi
 
Upvote 0
Hi mac:

When calculating "=COMBIN(70,10)" , try changing the format of the cell to "number" ....the result I get is "396,704,524,216"...


hope this helps
plettieri
 
Upvote 0
Hi!

10 combinations of 20 numbers are 184756 (=combin(20,10). But excel only has 65536 rows. Is there anyways to increase them to 184756 or alternatevely can the rest of the numbers be divided into 3 rows. 65536 in one row 65536 in second row and 53684 in the third row?

The UDF that plettieri has given works fine but it shows an error if the results exceeds 65536 rows.

Maxi
 
Upvote 0
I had a similar question recently and used VBA supplied but Tushar very kindly and cleverly produced a formula version which I tested and it worked equally well. Unfortuately it only covered 2 columns, but I'm sure it could be modified if the need was there. Anyway, you seem to have a solution but the dey=tail that was provided to me , for interest is below. I thought it was pretty good.

Start of quotes

You don't need VBA for this. Suppose you have data in Col. A and Col. B, starting with row 1. Then, in D1, enter the formula =OFFSET($A$1,INT((ROW()-1)/COUNTA(B:B)),0,1,1)&OFFSET($B$1,MOD(ROW()-1,COUNTA(B:B)),0,1,1) Copy D1 down column D until you get values that are only from column B.

quote:
--------------------------------------------------------------------------------
Originally posted by GorD:
I have a list of cost codes (partial) in cells A1 to A 56 and dept codes in cells B1 to B183.

To create the full cost code I need to add each of the dept codes on to the cost code i.e 60-320/ (cost code) and dept AA would give 60-320/AA. This needs done for each combination. some 10000 results. I imagine a couple of nested for - nexts but don't know how to do it .

Any help would be appreciated
--------------------------------------------------------------------------------


_________________
Tushar Mehta
Excel & PowerPoint tutorials and add-ins; custom productivity solutions for MS Office
 
Upvote 0
Hi! GorD

I didn't understand your post. Frankly speaking, I don't know anything about UDFs and programming stuff.

Use the code given by plettieri and run that macro. Keep the Number of items as 20 and Taken how many at a time as 10. You will get an error. The reason is, the result is over 65536. Now I want to split it into three columns as I said earlier. Is it possible for you to change that code?

Maxi
 
Upvote 0
Sorry, maybe wasn't to clear. i used a VBA soln because someone gave me that firstand it worked great. Then, tushar came along with a formula based approach which did the exact same thing. I thought that you were originally after a formula based approach so I copied the whole message including the Formula for that soln.
Sorry for the confusion
 
Upvote 0
Maxi,

I appreciate that you want a formula based solution, but the following macro based solution form Myrna Larson (Microsoft MVP) offers a number of advantages.

1. It allows Combinations or Permutations (see note below).
2. The macro handles numbers, text strings, words (e.g. names of people) or symbols.
3. The combinations are written to a new sheet.
4. Results are returned almost instantaneously.

Setup:
In sheet1:
Cell A1, put “C” (Combinations) or “P” (Permutations).
Cell A2, put the number of items in the subset – in your case it’s 4.
Cells A3 down, your list.
Book2
ABCDEFGHIJK
1C
24
3TomSawyer
4SueHarker
5MikeMcHenry
6HarryKewell
7FredSmith
8MarySmith
9KevinRudd
10LorisLane
11JohnHoward
12NicoleBryant
13MaxGallop
14
15
Sheet1


Note that your list, A:K, is actually 11 people. Using the COMBIN function, the combinations are 330.

The macro (standard module):

Code:
Option Explicit

Dim vAllItems As Variant
Dim Buffer() As String
Dim BufferPtr As Long
Dim Results As Worksheet
'
' Myrna Larson,  July 25, 2000,  Microsoft.Public.Excel.Misc

Sub ListPermutationsOrCombinations()
  Dim Rng As Range
  Dim PopSize As Integer
  Dim SetSize As Integer
  Dim Which As String
  Dim n As Double
  Const BufferSize As Long = 4096

    Worksheets("Sheet1").Range("A1").Select
  Set Rng = Selection.Columns(1).Cells
  If Rng.Cells.Count = 1 Then
    Set Rng = Range(Rng, Rng.End(xlDown))
  End If

  PopSize = Rng.Cells.Count - 2
  If PopSize< 2 Then GoTo DataError

  SetSize = Rng.Cells(2).Value
  If SetSize > PopSize Then GoTo DataError

  Which = UCase$(Rng.Cells(1).Value)
  Select Case Which
  Case "C"
    n = Application.WorksheetFunction.Combin(PopSize, SetSize)
  Case "P"
    n = Application.WorksheetFunction.Permut(PopSize, SetSize)
  Case Else
    GoTo DataError
  End Select
  If n > Cells.Count Then GoTo DataError

  Application.ScreenUpdating = False

  Set Results = Worksheets.Add

  vAllItems = Rng.Offset(2, 0).Resize(PopSize).Value
  ReDim Buffer(1 To BufferSize) As String
  BufferPtr = 0

  If Which = "C" Then
    AddCombination PopSize, SetSize
  Else
    AddPermutation PopSize, SetSize
  End If
  vAllItems = 0

  Application.ScreenUpdating = True
  Exit Sub

DataError:
  If n = 0 Then
    Which = "Enter your data in a vertical range of at least 4 cells." _
      & String$(2, 10) _
      & "Top cell must contain the letter C or P, 2nd cell is the Number" _
      & "of items in a subset, the cells below are the values from Which" _
      & "the subset is to be chosen."

  Else
    Which = "This requires " & Format$(n, "#,##0") & _
      " cells, more than are available on the worksheet!"
  End If
  MsgBox Which, vbOKOnly, "DATA ERROR"
  Exit Sub
End Sub

Private Sub AddPermutation(Optional PopSize As Integer = 0, _
  Optional SetSize As Integer = 0, _
  Optional NextMember As Integer = 0)

  Static iPopSize As Integer
  Static iSetSize As Integer
  Static SetMembers() As Integer
  Static Used() As Integer
  Dim i As Integer

  If PopSize<> 0 Then
    iPopSize = PopSize
    iSetSize = SetSize
    ReDim SetMembers(1 To iSetSize) As Integer
    ReDim Used(1 To iPopSize) As Integer
    NextMember = 1
  End If

  For i = 1 To iPopSize
    If Used(i) = 0 Then
      SetMembers(NextMember) = i
      If NextMember<> iSetSize Then
        Used(i) = True
        AddPermutation , , NextMember + 1
        Used(i) = False
      Else
        SavePermutation SetMembers()
      End If
    End If
  Next i

  If NextMember = 1 Then
    SavePermutation SetMembers(), True
    Erase SetMembers
    Erase Used
  End If

End Sub  'AddPermutation

Private Sub AddCombination(Optional PopSize As Integer = 0, _
  Optional SetSize As Integer = 0, _
  Optional NextMember As Integer = 0, _
  Optional NextItem As Integer = 0)

  Static iPopSize As Integer
  Static iSetSize As Integer
  Static SetMembers() As Integer
  Dim i As Integer

  If PopSize<> 0 Then
    iPopSize = PopSize
    iSetSize = SetSize
    ReDim SetMembers(1 To iSetSize) As Integer
    NextMember = 1
    NextItem = 1
  End If

  For i = NextItem To iPopSize
    SetMembers(NextMember) = i
    If NextMember<> iSetSize Then
      AddCombination , , NextMember + 1, i + 1
    Else
      SavePermutation SetMembers()
    End If
  Next i

  If NextMember = 1 Then
    SavePermutation SetMembers(), True
    Erase SetMembers
  End If

End Sub  'AddCombination

Private Sub SavePermutation(ItemsChosen() As Integer, _
  Optional FlushBuffer As Boolean = False)

  Dim i As Integer, sValue As String
  Static RowNum As Long, ColNum As Long

  If RowNum = 0 Then RowNum = 1
  If ColNum = 0 Then ColNum = 1

  If FlushBuffer = True Or BufferPtr = UBound(Buffer()) Then
    If BufferPtr > 0 Then
      If (RowNum + BufferPtr - 1) > Rows.Count Then
        RowNum = 1
        ColNum = ColNum + 1
        If ColNum > 256 Then Exit Sub
      End If

      Results.Cells(RowNum, ColNum).Resize(BufferPtr, 1).Value _
        = Application.WorksheetFunction.Transpose(Buffer())
      RowNum = RowNum + BufferPtr
    End If

    BufferPtr = 0
    If FlushBuffer = True Then
      Erase Buffer
      RowNum = 0
      ColNum = 0
      Exit Sub
    Else
      ReDim Buffer(1 To UBound(Buffer))
    End If

  End If

  'construct the next set
  For i = 1 To UBound(ItemsChosen)
    sValue = sValue & ", " & vAllItems(ItemsChosen(i), 1)
  Next i

  'and save it in the buffer
  BufferPtr = BufferPtr + 1
  Buffer(BufferPtr) = Mid$(sValue, 3)
End Sub  'SavePermutation
Permutations

This does not apply to you but may be useful in some other application. A permutation is any set or subset of objects or events where internal order is significant. For example, take the team consisting of Tom, Sue, and Mike. There are 6 permutations:

Tom , Sue, Mike
Tom , Mike, Sue
Sue , Tom, Mike
Sue , Mike, Tom
Mike , Tom, Sue
Mike , Sue, Tom

Which is confirmed with Excel’s PERMUT function:

=PERMUT(3,3)
= 6

With your 11 names in groups of 4, there are 330 groups but 7,920 permutations.

HTH


Mike
 
Upvote 0
I mentioned in my previous post that combinations are written to a new sheet. This is an example of what you get:
Book2
ABCDEFG
1TomSawyer,SueHarker,MikeMcHenry,HarryKewell
2TomSawyer,SueHarker,MikeMcHenry,FredSmith
3TomSawyer,SueHarker,MikeMcHenry,MarySmith
4TomSawyer,SueHarker,MikeMcHenry,KevinRudd
5TomSawyer,SueHarker,MikeMcHenry,LorisLane
6TomSawyer,SueHarker,MikeMcHenry,JohnHoward
7TomSawyer,SueHarker,MikeMcHenry,NicoleBryant
8TomSawyer,SueHarker,MikeMcHenry,MaxGallop
9TomSawyer,SueHarker,HarryKewell,FredSmith
10TomSawyer,SueHarker,HarryKewell,MarySmith
11TomSawyer,SueHarker,HarryKewell,KevinRudd
12TomSawyer,SueHarker,HarryKewell,LorisLane
13TomSawyer,SueHarker,HarryKewell,JohnHoward
14TomSawyer,SueHarker,HarryKewell,NicoleBryant
15TomSawyer,SueHarker,HarryKewell,MaxGallop
Sheet9


Regards,

Mike
 
Upvote 0

Forum statistics

Threads
1,217,367
Messages
6,136,141
Members
449,994
Latest member
Rocky Mountain High

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