This Power Monday trick is about random sample with Power Query. This is based on my experience of working with large volumes of data.
The other day I have been building a hotel dashboard (more on this later). As part of the dashboard, I wanted to show a random sample of user reviews. Reviews database had quite a few rows, so I wanted to extract a randomized sample of 100 reviews and show them in the report. When you refresh the report (Data > Refresh), then a new set of reviews will be fetched and shown.

Let’s learn how to generate a random sample with Power Query in this article.
This tutorial works in Power Query for Excel or Power BI. In case of Excel, the output sample will be either loaded as table or to data model. In case of Power BI, output goes to your data model.
If you want to get random sample with Excel formulas, read this.
5 Steps to create random sample with Power Query
Step 1: Get your data to Power Query
Simple. Grab the data you want to sample and bring it to PQ. At this point, you will get something like this:

Step 2: Add Random Numbers as a column
Go to “Add Column” > Custom Column and add this formula.
=Number.Random()
Remember: Power Query formulas are case-sensitive. So type exactly. Name this column “Random”
But Power Query gives same random number in all rows …
That is right. As Power Query is a parallel language, each row gets same random number (unlike Excel’s RAND() filled down a column).
Note: your experience with Number.Random() could be different, but as you build transformations, at some point PQ will replace all numbers with same value.
So how to get different numbers per row? Simple, we force PQ to evaluate something per row. A simple thing like index number column will do. This will force PQ to run random formula for all rows.
Hat tip to Gil Raviv for suggesting this technique in a forum post.
Step 3: Add Index Number column & Sort the random numbers
Go to “Add column” > Index number. Now that we have index numbers in a column, this will force PQ to regenerate the random number per row.

Select the random number column and sort it.
Note: You may need to switch Steps 2 & 3 if the random numbers are same all the way thru.
Step 4: Keep top 100 rows
Go to Home > Keep Rows > Keep Top Rows. Enter the sample size you want (100) and Click OK. Your sample is ready.

Step 5: Remove the Random & Index columns
Now that our sample is ready, let’s remove the random & index number columns. We do not need them in the final output (or model). Click on Save & Load (or Close & Apply).
Enjoy the sample.
How to get random sample with repetitions?
The above technique gives a sample without repetitions. What if you need a sample with repetitions (ie memory-less sampling). For example, a series of dice throws or coin tosses?
We can use Power Query to get such samples too. This is slightly complicated compared to first technique, but fun to try.
- Load your source to PQ
- Group the data so you can get row count (while still keeping the data). Like this:

- Add a custom column with a list of 100 numbers =List.Numbers(1,100)
- Expand the list to new rows
- Add a column with random number between 0 & row count-1 =Number.RandomBetween(0,[Count]-1))
- Add index column
- Change random number to whole number
- Extract the random row number from [Data] to a new column =[Data]{[Random]}
- Remove all other columns except this new column in #8
- Expand the column
- Your sample with possible repetitions is ready.
Here is the full M code for you to customize.
let Source = Excel.CurrentWorkbook(){[Name="myData"]}[Content], #"Grouped Rows" = Table.Group(Source, {}, {{"Count", each Table.RowCount(_), type number}, {"Data", each _, type table}}), #"Added Custom" = Table.AddColumn(#"Grouped Rows", "List", each List.Numbers(1,100)), #"Expanded List" = Table.ExpandListColumn(#"Added Custom", "List"), #"Added Custom1" = Table.AddColumn(#"Expanded List", "Random", each Number.RandomBetween(0,[Count]-1)), #"Added Index" = Table.AddIndexColumn(#"Added Custom1", "Index", 0, 1), #"Changed Type" = Table.TransformColumnTypes(#"Added Index",{{"Random", Int64.Type}}), #"Added Custom2" = Table.AddColumn(#"Changed Type", "Custom", each [Data]{[Random]}), #"Removed Columns" = Table.RemoveColumns(#"Added Custom2",{"Data"}), #"Removed Columns1" = Table.RemoveColumns(#"Removed Columns",{"Count", "List", "Random", "Index"}), #"Expanded Custom" = Table.ExpandRecordColumn(#"Removed Columns1", "Custom", {"Review Text", "Rating"}, {"Review Text", "Rating"}) in #"Expanded Custom"
Answers to your questions about sampling…
How to get another sample?
Simple. Just refresh your Power Query connection. You will get another sample.
How to change the sample size?
In the M code, where it says 100 replace with another number or parameter.
Use Excel Cell to tell Power Query how big a sample you want…
You can even use an Excel named cell to tell PQ what sample size you want. Assuming named cell sample.size has the size, use this M code =Excel.CurrentWorkbook(){[Name=”sample.size“]}[Content][Column1]{0} to get the value in your query. Use it as part of other steps and bingo, your sample size changes.
Other questions…?
Struggle sampling some sensible set? Post your sample problem in comments so I or one of our excellent readers can help you.
Download sample file and get your samples…
Excuse the pun, but here is a sample file with all the M code for making your own samples. Examine the queries to learn how this is done.
How do you sample?
Excel’s Rand() is my favorite way to sample. But now that I am spending more time with Power Query & Power BI, I needed another way to sample the data. This post outlines my preferred approach (unless I am dealing with very large volumes of data) For large volumes of data, I suggest sampling at server-side thru SQL.
What about you? How do you sample? Share your approach or troubles in the comments.














20 Responses to “Simulating Dice throws – the correct way to do it in excel”
You have an interesting point, but the bell curve theory is nonsense. Certainly it is not what you would want, even if it were true.
Alpha Bravo - Although not a distribution curve in the strict sense, is does reflect the actual results of throwing two physical dice.
And reflects the following . .
There is 1 way of throwing a total of 2
There are 2 ways of throwing a total of 3
There are 3 ways of throwing a total of 4
There are 4 ways of throwing a total of 5
There are 5 ways of throwing a total of 6
There are 6 ways of throwing a total of 7
There are 5 ways of throwing a total of 8
There are 4 ways of throwing a total of 9
There are 3 ways of throwing a total of 10
There are 2 ways of throwing a total of 11
There is 1 way of throwing a total of 12
@alpha bravo ... welcome... 🙂
either your comment or your dice is loaded 😉
I am afraid the distribution shown in the right graph is what you get when you throw a pair of dice in real world. As Karl already explained, it is not random behavior you see when you try to combine 2 random events (individual dice throws), but more of order due to how things work.
@Karl, thanks 🙂
When simulating a coin toss, the ROUND function you used is appropriate. However, your die simulation formula should use INT instead of ROUND:
=INT(RAND()*6)+1
Otherwise, the rounding causes half of each number's predictions to be applied to the next higher number. Also, you'd get a count for 7, which isn't possible in a die.
To illustrate, I set up 1200 trials of each formula in a worksheet and counted the results. The image here shows the table and a histogram of results:
http://peltiertech.com/WordPress/wp-content/img200808/RandonDieTrials.png
@Jon: thanks for pointing this out. You are absolutely right. INT() is what I should I have used instead of ROUND() as it reduces the possibility of having either 1 or 6 by almost half that of having other numbers.
this is such a good thing to learn, helps me a lot in my future simulations.
Btw, the actual graphs I have shown were plotted based on randbetween() and not from rand()*6, so they still hold good.
Updating the post to include your comments as it helps everyone to know this.
By the way, the distribution is not a Gaussian distribution, as Karl points out. However, when you add the simulations of many dice together (i.e., ten throws), the overall results will approximate a Gaussian distribution. If my feeble memory serves me, this is the Central Limit Theorem.
@Jon, that is right, you have to nearly throw infinite number of dice and add their face counts to get a perfect bell curve or Gaussian distribution, but as the central limit theorem suggests, our curve should roughly look like a bell curve... 🙂
[...] posts on games & excel that you may enjoy: Simulating Dice throws in Excel Generate and Print Bingo / Housie tickets using this excel Understanding Monopoly Board [...]
[...] Correct way to simulate dice throws in excel [...]
[...] Simulate dice throws in excel [...]
I'm afraid to say that this is a badly stated and ambiguous post, which is likely to cause errors and misunderstanding.
Aside from the initial use of round() instead of int(),.. (you've since corrected), you made several crucial mistakes by not accurately and unambiguously stating the details.
Firstly, you said:
"this little function generates a random fraction between 0 and 1"
Correctly stated this should be:
"this little function generates a random fraction F where 0 <= F < 1".
Secondly, I guess because you were a little fuzzy about the exact range of values returned by rand(), you have then been just as ambiguous in stating:
"I usually write int(rand()*12)+1 if I need a random number between 0 to 12".
(that implies 13 integers, not 12)
Your formula, does not return 13 integers between 0 to 12.
It returns 12 integers between 1 and 12 (inclusive).
-- As rand() returns a random fraction F where 0 <= F < 1, you can obviously can only get integers between 1 and 12 (inclusive) from your formula as stated above, but clearly not zero.
If you had said either:
"I usually write int(rand()*12) if I need a random number between 0 to 11 (inclusive)",
or:
"I usually write int(rand()*12)+1 if I need a random number between 1 to 12 (inclusive)"
then you would have been correct.
Unfortunately, you FAIL! -- repeat 5th grade please!
Your Fifth Grade Maths Teacher
Idk if I'm on the right forum for this or how soon one can reply, but I'm working on a test using Excel and I have a table set up to get all my answers from BUT I need to generate 10,000 answers from this one table. Every time, I try to do this I get 10,000 duplicate answers. I know there has to be some simple command I have left out or not used at all, any help would be extremely helpful! (And I already have the dice figured out lol)
Roll 4Dice with 20Sides (4D20) if the total < 20 add the sum of a rerolled 2D20. What is the average total over 10,000 turns? (Short and sweet)
Like I said when I try to simulate 10,000turns I just get "67" 10,000times -_- help please! 😀
@Justin
This is a good example to use for basic simulation
have a look at the file I have posted at:
https://rapidshare.com/files/1257689536/4_Dice.xlsx
It uses a variable size dice which you set
Has 4 Dice
Throws them 10,000 times
If Total per roll < 20 uses the sum of 2 extra dice Adds up the scores Averages the results You can read more about how it was constructed by reading this post: http://chandoo.org/wp/2010/05/06/data-tables-monte-carlo-simulations-in-excel-a-comprehensive-guide/
Oh derp, i fell for this trap too, thinking i was makeing a good dice roll simulation.. instead of just got an average of everything 😛
Noteably This dice trow simulate page is kinda important, as most roleplay dice games were hard.. i mean, a crit failure or crit hit (rolling double 1's or double 6's) in a a game for example dungeons and dragons, if you dont do the roll each induvidual dice, then theres a higher chance of scoreing a crit hit or a crit failure on attacking..
I've been working on this for awhile. So here's a few issues I've come across and solved.
#1. round() does work, but you add 0.5 as the constant, not 1.
trunc() and int() give you the same distributions as round() when you use the constant 1, so among the three functions they are all equally fair as long as you remember what you're doing when you use one rather than the other. I've proven it with a rough mathematical proof -- I say rough only because I'm not a proper mathematician.
In short, depending on the function (s is the number of sides, and R stands in for RAND() ):
round(f), where f = sR + 0.5
trunc(f), where f = sR + 1
int(f), where f = sR + 1
will all give you the same distribution, meaning that between the three functions they are fair and none favors something more than the others. However...
#2. None of the above gets you around the uneven distribution of possible outcomes of primes not found in the factorization of the base being used (base-10, since we're using decimal; and the prime factorization of 10 is 2 and 5).
With a 10-sided die, where your equation would be
=ROUND(6*RAND()+0.5)
Your distribution of possible values is even across all ten possibilities.
However, if you use the most basic die, a 6-sided die, the distributions favor some rolls over others. Let's assume your random number can only generate down to the thousandths (0.000 ? R ? 0.999). The distribution of possible outcomes of your function are:
1: 167
2: 167
3: 166
4: 167
5: 167
6: 166
So 4 and 6 are always under-represented in the distribution by 1 less than their compatriots. This is true no matter how many decimals you allow, though the distribution gets closer and closer to equal the further towards infinite decimal places you go.
This carries over to all die whose numbers of sides do not factor down to a prime factorization of some exponential values of 2 and 5.
So, then, how can we fix this one, tiny issue in a practical manner that doesn't make our heads hurt or put unnecessary strain on the computer?
Real quick addendum to the above:
Obviously when I put the equation after the example of the 10-sided die, I meant to put a 10*RAND() instead of a 6*RAND(). Oops!
Also, where I have 0.000 ? R ? 0.999, the ?'s are supposed to be less-than-or-equal-to signs but the comments didn't like that. Oh well.
How do you keep adding up the total? I would like to have a cell which keeps adding up the total sum of the two dices, even after a new number is generated in the cells when you refresh or generate new numbers.
So, how do you simulate rolling 12 dice? Do you write int(rand()*6) 12 times?
Is there a simpler way of simulating n dice in Excel?
I've run this code in VBA
Sub generate()
Application.ScreenUpdating = False
Application.Calculation = False
Dim app, i As Long
Set app = Application.WorksheetFunction
For i = 3 To 10002
Cells(i, 3).Value = i - 2
Cells(i, 4).Value = app.RandBetween(2, 12)
Cells(i, 5).Value = app.RandBetween(1, 6) + app.RandBetween(1, 6)
Next
Application.ScreenUpdating = True
Application.Calculation = True
End Sub
But I get the same distribution for both columns 4 and 5
Why ?
@Mohammed
I would expect to get the same distribution as you have effectively used the same function