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: Generating Random Strings of Characters.
Written by Allen Wyatt (last updated July 2, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Nancy is trying to get Excel to pick 50 "numbers" that each contain eight random characters. The characters can be either digits or letters (uppercase or lowercase).
If your random numbers were to really be numbers (digits only), then generating them would be easy. All you would need to do is use the RANDBETWEEN function in this manner:
=RANDBETWEEN(10000000,99999999)
This is not what Nancy wants, however. Her random "numbers" can contain upper- and lowercase letters, as well. This becomes a bit stickier. There are, however, several approaches you can use.
One approach is to put all your possible characters into an individual cell, such as B7:
ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789
Name this cell something snazzy, such as MySource. You could then use a formula such as the following to return the random string of characters:
=MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1) & MID(MySource,RANDBETWEEN(1,LEN(MySource)),1)
The formula is long; it has been broken into individual lines for clarity, but it is still a single formula. It concatenates eight characters pulled from the source you entered into cell B7.
Another approach is to create a table that contains all the characters you would want in your random text string. Start by placing the numbers 1 through 62 in a column, one number in each row. To the left of these numbers place your characters—A, B, C, D, etc. (This should be the same characters you placed in cell B7 in the previous technique.) Select both columns of the 62 rows and give it a name, such as MyTable. You can then use the following formula to generate the random characters:
=VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2) & VLOOKUP(RANDBETWEEN(1,62),MyTable,2)
Again, remember that this is a single formula, although it is a bit shorter than the previous formula.
Still another approach relies on defining names using the Name Manager. I won't go into exactly how to define names in this tip, but you should use the Name Manager to define the names a, U, n, and x, as follows:
a =CHAR(RANDBETWEEN(97,122)) U =UPPER(a) n =CHAR(RANDBETWEEN(48,57)) x =CHOOSE(RANDBETWEEN(1,3),a,U,n)
The name "a" returns a random lowercase letter, the name "U" returns a random uppercase letter, and the name "n" returns a random digit. The name "x" then selects one of these three at random. Once these are defined, you can place the following in any cell:
=x & x & x & x & x & x & x & x
This can be copied to as many cells as desired, and you'll end up with your random string of characters.
Each of the approaches presented so far has one drawback: they are regenerated each time your worksheet is recalculated. Thus, it is hard to have a single generated random string that won't change on a regular basis. The best way around this is to use a macro, but you don't necessarily want to use a user-defined function. Why? Because it, too, would change its result every time the worksheet was recalculated. Instead, you need a macro that will put the random strings into your workbook starting at a specific cell location. The following is an example of such a macro:
Sub MakeRandom() Dim J As Integer Dim K As Integer Dim iTemp As Integer Dim sNumber As String Dim bOK As Boolean Range("D4").Activate Randomize For J = 1 To 50 sNumber = "" For K = 1 To 8 Do iTemp = Int((122 - 48 + 1) * Rnd + 48) Select Case iTemp Case 48 To 57, 65 To 90, 97 To 122 bOK = True Case Else bOK = False End Select Loop Until bOK bOK = False sNumber = sNumber & Chr(iTemp) Next K ActiveCell.Value = sNumber ActiveCell.Offset(1, 0).Select Next J End Sub
Run the macro, and whatever is in cells D4:D53 is overwritten by the random values. If you want the values written into a different location, change the Range statement near the beginning of the macro.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11707) 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: Generating Random Strings of Characters.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
If you have a special need to find cell values that meet two different criteria, where to start can be daunting. This tip ...
Discover MoreWhen you copy a formula from one cell to another, Excel normally adjusts the cell references within the formula so they ...
Discover MoreExcel includes a built-in tool that will remove duplicate rows from a worksheet. If you want to remove non-duplicate ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-07-02 11:06:06
Rick Rothstein
You might consider simplying your Do..Loop by replacing it with this...
Do
iTemp = Int((122 - 48 + 1) * Rnd + 48)
bOK = Chr(iTemp) Like "[A-Za-z0-9]"
Loop Until bOK
But in actuality, I would replace your entire macro with this more compact one...
Sub MakeRandom()
Dim N As Long, sNumber As String, Cell As Range
Const Valid = "ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz0123456789"
Randomize
For Each Cell In Range("D4").Resize(50)
sNumber = ""
For N = 1 To 8
sNumber = sNumber & Mid(Valid, Int(62 * Rnd + 1), 1)
Next
Cell.Value = sNumber
Next
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