VBA Generate random 10 Group of 5 numbers

motilulla

Well-known Member
Joined
Feb 13, 2008
Messages
2,422
Office Version
  1. 2010
Hello,

Looking VBA solution which generate random 10 group of 5 numbers using all 50 numbers in cells D2:H11
List of numbers is in cells A2:A51.
If all numbers are used in to cross check C1 will show sum of 50 numbers = 1275
Example…


Book1
ABCDEFGH
1Numbers1275n1n2n3n4n5
21Group1344192023
32Group221155057
43Group3191118308
54Group43213481231
65Group5143463938
76Group63649162633
87Group71044352737
98Group8251734524
109Group9404221429
1110Group1042822476
1211
1312
1413
1514
1615
1716
1817
1918
2019
2120
2221
2322
2423
2524
2625
2726
2827
2928
3029
3130
3231
3332
3433
3534
3635
3736
3837
3938
4039
4140
4241
4342
4443
4544
4645
4746
4847
4948
5049
5150
Random-50
Cell Formulas
RangeFormula
C1=SUM(D2:H11)


Thanks In Advance
Using version 2000

Regards,
Moti
 
Try this with different sort code.
Code:
[COLOR=Navy]Sub[/COLOR] MG26Jun00
[COLOR=Navy]Dim[/COLOR] Rng [COLOR=Navy]As[/COLOR] Range, Dn [COLOR=Navy]As[/COLOR] Range, R [COLOR=Navy]As[/COLOR] Variant
[COLOR=Navy]Dim[/COLOR] Ray [COLOR=Navy]As[/COLOR] Variant, nRay() [COLOR=Navy]As[/COLOR] Variant
[COLOR=Navy]Dim[/COLOR] c [COLOR=Navy]As[/COLOR] [COLOR=Navy]Integer,[/COLOR] nRdn [COLOR=Navy]As[/COLOR] [COLOR=Navy]Integer,[/COLOR] Ac [COLOR=Navy]As[/COLOR] [COLOR=Navy]Integer[/COLOR]
Ac = 1
[COLOR=Navy]Set[/COLOR] Rng = Range(Range("A2"), Range("A" & Rows.Count).End(xlUp))
 Ray = Application.Transpose(Rng)
  ReDim nRay(1 To 10, 1 To 5)
                Randomize
    [COLOR=Navy]Do[/COLOR] Until c * Ac = 50
        nRdn = Int(Rnd * Rng.Count) + 1
        [COLOR=Navy]If[/COLOR] Not Ray(nRdn) = vbNullString [COLOR=Navy]Then[/COLOR]
            [COLOR=Navy]If[/COLOR] c = 10 [COLOR=Navy]Then[/COLOR]
                c = 0: Ac = Ac + 1
            [COLOR=Navy]End[/COLOR] If
            c = c + 1
            nRay(c, Ac) = Ray(nRdn)
            Ray(nRdn) = vbNullString
        [COLOR=Navy]End[/COLOR] If
    [COLOR=Navy]Loop[/COLOR]
Range("D2").Resize(10, 5) = nRay
[COLOR=Navy]Set[/COLOR] Rng = Range("D2:D11")
[COLOR=Navy]For[/COLOR] [COLOR=Navy]Each[/COLOR] Dn [COLOR=Navy]In[/COLOR] Rng
  R = Dn.Resize(, 5).Value
    [COLOR=Navy]For[/COLOR] Ac = 1 To 5
        Dn(, Ac) = Application.Small(R, Ac)
    [COLOR=Navy]Next[/COLOR] Ac
[COLOR=Navy]Next[/COLOR] Dn
[COLOR=Navy]End[/COLOR] [COLOR=Navy]Sub[/COLOR]
Regards Mick
Wow! Thumbs up!! MickG, I am amazed this version is sorting ascending perfectly!!

Thank you I appreciate a lot your kind help and patience.


Regards,
Moti
:)
 
Upvote 0

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
Here is a slightly more compact macro that you may also want to consider...
Code:
[table="width: 500"]
[tr]
	[td]Sub FiveGroupsOfTenRandomlyArrangedNumbers()
  Dim Cnt As Long, Index As Long, Tmp As Variant, Nums As Variant
  Randomize
  Nums = [TRANSPOSE(A2:A51)]
  For Cnt = UBound(Nums) To 1 Step -1
    Index = Int(Cnt * Rnd + 1)
    Tmp = Nums(Index)
    Nums(Index) = Nums(Cnt)
    Nums(Cnt) = Tmp
  Next
  For Cnt = 1 To UBound(Nums)
    Range("C1").Offset(1 + ((Cnt - 1) Mod 10), Int(1 + (Cnt - 1) / 10)) = Nums(Cnt)
  Next
  For Cnt = 2 To 11
    Cells(Cnt, "D").Resize(, 5).Sort Cells(Cnt, "D").Resize(, 5), xlAscending, Header:=xlNo, Orientation:=xlLeftToRight
  Next
End Sub[/td]
[/tr]
[/table]
 
Last edited:
Upvote 0
Here is a slightly more compact macro that you may also want to consider...
Hello Rick, Thank you for the giving one another option.

What I was thinking is it any possibility to limit range of numbers by column I mean to say always to be used all 50 numbers no repetitions but for example using in between limits as follow…

For 1st column - n1 numbers to be limits any in between 1 to 16
For 2nd column - n2 numbers to be limits any in between 6 to 26
For 3rd column - n3 numbers to be limits any in between 14 to 35
For 4th column - n4 numbers to be limits any in between 21 to 43
For 5th column - n5 numbers to be limits any in between 36 to 50

Regards,
Moti
 
Upvote 0
Hello Rick, Thank you for the giving one another option.

What I was thinking is it any possibility to limit range of numbers by column I mean to say always to be used all 50 numbers no repetitions but for example using in between limits as follow…
That depends... did you still want to sort the rows from lowest number to highest?
 
Upvote 0
Yes Rick, preferable if it is not a much trouble that makes more easer…
If you think sorting row cause difficulty limiting the numbers in between each column I will be glad with getting unsorted output results.

Thank you

Regards,
Moti
 
Upvote 0
Hello again, any thought about post #14 is it any possibility to limit range of numbers by column

Note: Important must be used all 50 numbers within 10 sets of 5 numbers.

Regards,
Moti
 
Upvote 0
If you think sorting row cause difficulty limiting the numbers in between each column I will be glad with getting unsorted output results.
I have been looking at this for a couple of days now and am now convinced you cannot do what you are now asking for... and here is why. Lets look at the first column and say these are the random numbers between 1 and 16 that are selected... 1 2 5 7 8 9 11 13 14 16... and randomly scattered about in the first column. Now look as the minimum allowed number in that second column... 6. We did not use the numbers 3 or 4 in the first column and both 3 and 4 are less than the minimum allowed number in the second column so they will never be selected for placement in the table. (This missing number problem can occur again and again as we move through the columns). But there are 50 numbers and 50 cells to fill... if we have numbers that do not get selected, then there will not be 50 total numbers available to fill the 50 cells in the table... but you said every number from 1 to 50 must get used, so we have an impossible situation that has no resolution given your restrictions.
 
Upvote 0
I have been looking at this for a couple of days now and am now convinced you cannot do what you are now asking for (This missing number problem can occur again and again as we move through the columns). But there are 50 numbers and 50 cells to fill... if we have numbers that do not get selected, then there will not be 50 total numbers available to fill the 50 cells in the table... but you said every number from 1 to 50 must get used, so we have an impossible situation that has no resolution given your restrictions.
Thank you Rick, I can understand your explanation is logically and make sense I did not thought that in deeply I am sorry I understand perfectly now, ok if I change my question and say no restrictions of usage 50 numbers no problem if used repeated can you think that could be viable, does in this case can we limit the columns?

I appreciate your help

Regards,
Moti
 
Upvote 0

Forum statistics

Threads
1,223,264
Messages
6,171,081
Members
452,377
Latest member
bradfordsam

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