Written by Allen Wyatt (last updated April 26, 2025)
This tip applies to Excel 97, 2000, 2002, and 2003
How's that for a tip title? The title refers to the fact that you may have a need to populate a range of cells with a series of numbers in random order. For instance, you might want to populate 52 cells with the numbers 1 through 52, in random order. (This would be similar to drawing cards from a shuffled deck, thus the tip title.)
There obviously is no built-in Excel function to provide this capability, so you are left to work with macros. Fortunately, such a macro is not terribly difficult to create. The following macro will do the trick nicely:
Sub FillRand() Dim nums() As Integer Dim maxval As Integer Dim nrows As Integer, ncols As Integer Dim j As Integer, k As Integer Dim Ptr As Integer Randomize Set s = Selection maxval = s.Cells.Count nrows = s.Rows.Count ncols = s.Columns.Count ReDim nums(maxval, 2) 'Fill the initial array For j = 1 To maxval nums(j, 1) = j nums(j, 2) = Int((Rnd * maxval) + 1) Next j 'Sort the array based on the random numbers For j = 1 To maxval - 1 Ptr = j For k = j + 1 To maxval If nums(Ptr, 2) > nums(k, 2) Then Ptr = k Next k If Ptr <> j Then k = nums(Ptr, 1) nums(Ptr, 1) = nums(j, 1) nums(j, 1) = k k = nums(Ptr, 2) nums(Ptr, 2) = nums(j, 2) nums(j, 2) = k End If Next j 'Fill in the cells Ptr = 0 For j = 1 To nrows For k = 1 To ncols Ptr = Ptr + 1 s.Cells(j, k) = nums(Ptr, 1) Next k Next j End Sub
This macro uses a two-dimensional array (nums) to figure out which numbers to use and the order in which they should be used. Near the beginning of the macro the array is filled with a static number (1 through the number of cells) and a random number between 1 and the number of cells. This second number is then used to sort the array. Once the array is stored, it is a simple matter to place the original numbers in the cells.
By the way, the reason a two-dimensional array is used is because the Rnd function that VBA uses to generate random numbers can return duplicate values. Thus, even through the second dimension of the array can have duplicates in it, when the array is finally sorted, the first dimension will not have duplicates.
To use the macro, start by selecting the cells you want to have filled with sequential values in a random order. When you run the macro, that range is filled. For instance, if you select ten cells and then run the macro, then those cells are filled with the numbers 1 through 10, in random order.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2280) 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: Playing with a Full Deck.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2019 For Dummies today!
Normally you use the RAND and RANDBETWEEN functions to generate random numbers. What if you want to generate random ...
Discover MoreExcel provides several different functions that you can use to generate random numbers. One of the most useful is the ...
Discover MoreWhen entering data into a worksheet, you may have a need to fill a range of cells with a group of random numbers. This ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments