Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Picking Different Random Numbers from a Range.
Written by Allen Wyatt (last updated May 28, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Let's say that you have a list of employees (or products, or widgets, or whatever) and that you want to pick two items from this list, at random. There are a few of different worksheet functions you can use to pick items from the list, such as RAND, RANDBETWEEN, and RANDARRAY.
Many people use the RANDBETWEEN function because it is very easy and provides a random number within a range. Thus, if you have 25 items in your list, RANDBETWEEN can return a number between 1 and 25, which can then correspond to items in the list.
For example, let's say that your list of items is in the range A2:A26, and that you give this range the name Items. You could then put the following formula in cell C2 to return a number between 1 and the number of Items:
=RANDBETWEEN(1,ROWS(Items))
Copy this formula to cell C3, and you now have two random numbers that represent items from the list. In cell D2 and D3 you could put formulas like this to get the actual names from the list:
=INDEX(Items,C2)
The only problem with this approach is that it is possible for both instances of RANDBETWEEN (cells C2 and C3) to return the same value, and thus you end up with the same item selected twice from your list.
An approach that uses RANDARRAY (which is available only in the Office 365 version of Excel) is subject to the same issue. In cell C2 you could use the following formula:
=RANDARRAY(2,1,1,ROWS(Items),TRUE)
The results of the formula spill into cell C3, and you end up with two random numbers that represent items from the list. Again, these returned values could be the same as each other.
One way to work around this potential problem with RANDBETWEEN and RANDARRAY is to actually select three items from the list instead of two. If the first two items are the same, then the third can be used as a "fallback" item to provide the unique second. (To accomplish this with RANDARRAY, just change the first parameter from 2 to 3.) The method is not foolproof, as it is possible—but quite improbable—that all three will be the same.
A different approach to selecting items from the list would be to assign each item its own random value, and then select based on the highest number in the series. The RANDOM function returns a random value between 0 and 1. In each cell of column B, just to the right of each item in column A, put this formula:
=RAND()
Select the range of cells (B2:B26) and name the range, using a name such as ItemNums. You can then determine the first random name from the list by using the following array formula:
=OFFSET(A$1,SUM((LARGE(ItemNums,1)=(ItemNums))*ROW(ItemNums))-1,0)
In order to signify that this is an array formula, enter it by pressing Shift+Ctrl+Enter. (This is necessary only in versions of Excel before the version with Office 365. In the Office 365 version, just press Enter.) The formula should return a single name. You can then use the following array formula to return the second name:
=OFFSET(A$1,SUM((LARGE(ItemNums,2)=(ItemNums))*ROW(ItemNums))-1,0)
The reason that using the RAND function approach works better than using RANDBETWEEN and RANDARRAY is because the chance that RAND will return two identical values is infinitesimally small, whereas the chances of RANDBETWEEN and RANDARRAY doing so is much higher.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12082) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel here: Picking Different Random Numbers from a Range.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Want to use a formula to check if there is an error in your formula? (Sounds confusing, but it's not that bad.) You'll ...
Discover MoreIf you need to evaluate a row of values to meet specific criteria, then you'll appreciate the discussion in this tip. It ...
Discover MoreOne of the areas in which Excel provides worksheet functions is in the arena of statistical analysis. You may want to ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-05-30 05:00:49
Dave S
You could perhaps reduce the infinitesimally small chance of a duplicate second item even further by using something like
=OFFSET(A$1,SUM((SMALL(ItemNums,1)=(ItemNums))*ROW(ItemNums))-1,0)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments