Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Generating Random Strings of Characters.
Written by Allen Wyatt (last updated December 15, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
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 the Analysis ToolPak) 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.
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 (3872) 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: Generating Random Strings of Characters.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Need to know the directory (folder) in which a workbook was saved? You can create a formula that will return this ...
Discover MoreReference a cell in a macro, and if that cell is blank Excel normally equates that to a zero value. What if you don't ...
Discover MoreNeed to get at the last value in a column, regardless of how many cells are used within that column? You can apply the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-12-16 12:49:08
Willy Vanhaelen
@Rick
You can even do it with one loop (2 lines less):
Sub MakeRandom()
Dim X As Long, MaxRows As Long, CharsPerCell As Long
Dim Nums As String, Result As Variant
MaxRows = 50
CharsPerCell = 8
Nums = "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz"
Randomize
For X = 1 To MaxRows * CharsPerCell
Result = Result & Mid(Nums, Int(Len(Nums) * Rnd + 1), 1)
If X Mod CharsPerCell = 0 Then Result = Result & " "
Next
Range("D4").Resize(MaxRows) = Application.Transpose(Split(Result))
End Sub
2018-12-15 15:33:41
Rick Rothstein
Here is another way to write your MakeRandom macro...
Sub MakeRandom()
Dim R As Long, C As Long, MaxRows As Long, CharsPerCell As Long
Dim Nums As String, Result As Variant
MaxRows = 50
CharsPerCell = 8
Nums = "0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZabcdefghijklmnopqrstuvwxyz"
ReDim Result(1 To MaxRows, 1 To 1)
Randomize
For R = 1 To MaxRows
For C = 1 To CharsPerCell
Result(R, 1) = Result(R, 1) & Mid(Nums, Int(Len(Nums) * Rnd + 1), 1)
Next
Next
Range("D4").Resize(MaxRows) = Result
End Sub
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 © 2024 Sharon Parq Associates, Inc.
Comments