Gary has two lists in a worksheet. One of them, in column A, contains a list of surplus items in our company and the other, in column G, contains a list of names. There is nothing in columns B:F. Gary would like to assign names, randomly, to the list of items. Each name from column G should be assigned only once. If there are more names than items, then some names won't get used. If there are fewer names than items, then some items won't have associated names.
There are a couple of ways that this can be done. Perhaps the easiest, though, is to simply assign a random number to each item in column A. Assuming that the first item is in cell A1, put the following in cell B1:
=RAND()
Double-click the fill handle in cell B1, and you should end up with a random number (between 0 and 1) to the right of each item in column A.
Now, select all the cells in column B and press Ctrl+C to copy them to the Clipboard. Use Paste Special to paste values right back into those cells in column B. (This converts the cells from formulas to actual static values.)
Sort columns A and B in ascending order based on the values in column B. If you look across the rows, you'll now have items (column A) associated randomly with a name (column G).
Even though it is not necessary, you could also follow these same steps to add a random number to the right of each name and then sort the names. (I say it isn't necessary because randomizing the items should be enough to assure that there are random items associated with each name.)
The technique discussed so far works great if you have to do the random pairing only once in a while. If you need to do it quite often, then a macro may be a better approach. There are, of course, many different macro-based approaches you could use. The following approach assumes the item list is in column A and the name list in column G. It also assumes that there are header cells in row 1 for each column.
Sub AssignNames() Set srItems = Range("A2").CurrentRegion Set srNames = Range("G2").CurrentRegion NameCount = srItems.Rows.Count - 1 ItemCount = srNames.Rows.Count - 1 'Randomize Names ReDim tempArray(NameCount, 2) For x = 0 To NameCount - 1 tempArray(x, 0) = Range("G2").Offset(x, 0) tempArray(x, 1) = Rnd() Next x 'Bubble Sort For i = 0 To NameCount - 2 For j = i To NameCount - 1 If tempArray(i, 1) > tempArray(j, 1) Then tempItem = tempArray(j, 0) tempName = tempArray(j, 1) tempArray(j, 0) = tempArray(i, 0) tempArray(j, 1) = tempArray(i, 1) tempArray(i, 0) = tempItem tempArray(i, 1) = tempName End If Next j Next i 'AssignNames Range("B2") = "Assigned" AssignCount = NameCount If NameCount > ItemCount Then AssignCount = ItemCount For x = 0 To AssignCount Range("B2").Offset(x, 0) = tempArray(x, 0) Next x End Sub
If there are more names than items the macro randomly assigns names to items. If there are more items than names it randomly assigns some items to names and randomly leaves "holes" (items without names). It stores them in column B, overwriting whatever was there.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (5682) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
When using an Excel worksheet to store data (such as names and phone numbers), you may need a way to easily look up a ...
Discover MoreWhen you are working with large data sets, you may want to filter the information in those data sets according to various ...
Discover MoreNeed to find out how many times a certain letter appears in a text string? It's easy to do if you rely on the SUBSTITUTE ...
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 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 © 2022 Sharon Parq Associates, Inc.
Comments