Random generator help

benwork

Board Regular
Joined
Oct 8, 2010
Messages
69
Hi all,

I'm looking for some help with the random generator function.

I have a value in B1 which will change depending on the date. For this example, say the value is 3

I then have a possible 3 streams that this number could go into

Stream 1 (B2)
Stream 2 (B3)
Stream 3 (B4)

I would like to be able to randomly distribute the value in B1 across the three streams. For example if could be,

Stream 1 (B2) - 1
Stream 2 (B3) - 1
Stream 3 (B4) - 1

or

Stream 1 (B2) - 0
Stream 2 (B3) - 2
Stream 3 (B4) - 1

or

Stream 1 (B2) - 0
Stream 2 (B3) - 0
Stream 3 (B4) - 3

etc

They would need to be randomly generated and the sum of the three streams would need to equal B1

Can anyone assist with this ?

Regards

Ben
 

Some videos you may like

Excel Facts

How to change case of text in Excel?
Use =UPPER() for upper case, =LOWER() for lower case, and =PROPER() for proper case. PROPER won't capitalize second c in Mccartney

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,916
I'm wondering what the rules are for this distribution.

One way would be to put

=RANDBETWEEN(0, A1) in B2
=RANDBETWEEN(0, A1-B2) in B3
=A1-B1-B2 in B4
 

benwork

Board Regular
Joined
Oct 8, 2010
Messages
69
I'm wondering what the rules are for this distribution.

One way would be to put

=RANDBETWEEN(0, A1) in B2
=RANDBETWEEN(0, A1-B2) in B3
=A1-B1-B2 in B4

Thanks for the reply,

I tried that before, but it puts a bias on stream 1

It does need to be random across the three streams

Cheers

Ben
 

mikerickson

MrExcel MVP
Joined
Jan 15, 2007
Messages
23,916
Then I wouldn't use formulas. I'd use VBA to 1) get three numbers as above that sum to what you want 2) randomly re-order those numbers.
Here's a UDF that you could use.
Select B2:B4 and enter the array formula =TRANSPOSE(RandomSumTo(A1))
Code:
Function RandomSumTo(SoughtTotal As Long) As Variant
    Dim Numbers(1 To 3) As Long
    Dim randIndex As Long, temp As Long, i As Long
    
    Numbers(1) = WorksheetFunction.RandBetween(0, SoughtTotal)
    Numbers(2) = WorksheetFunction.RandBetween(0, SoughtTotal - Numbers(1))
    Numbers(3) = SoughtTotal - Numbers(1) - Numbers(2)
    For i = 1 To 3
        randIndex = WorksheetFunction.RandBetween(1, 3)
        temp = Numbers(randIndex)
        Numbers(randIndex) = Numbers(i)
        Numbers(i) = temp
    Next i
    RandomSumTo = Numbers
End Function
 

Watch MrExcel Video

Forum statistics

Threads
1,123,076
Messages
5,599,627
Members
414,326
Latest member
kfg1287

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
Top