Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. 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.

Generating Random Strings of Characters

by Allen Wyatt
(last updated August 27, 2016)

4

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11707) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Generating Random Strings of Characters.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Spell Checking Your Document

One of the final touches that many people perform is to check the spelling of their document. This can help improve the ...

Discover More

Deleting Table Columns with Track Changes Turned On

If you are editing a document with Track Changes turned on, Word won't let you delete a column in a table and have it ...

Discover More

Finding the Nth Root of a Number

Finding a square root is easy because Excel provides a worksheet function for that purpose. Finding a different root may ...

Discover More

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!

More ExcelTips (ribbon)

Counting Names Based on Two Criteria

Need to figure out how many rows in a worksheet meet two criteria that you specify? Here's how to get the info you desire.

Discover More

Incrementing References by Multiples when Copying Formulas

You can easily set up a formula to perform some calculation on a range of cells. When you copy that formula, the copied ...

Discover More

Ignoring N/A Values in a Sum

You can use some of Excel's worksheet functions across a range or worksheets, but not all of them. One that has problems ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is nine more than 3?

2018-12-16 12:46:11

Willy Vanhaelen

@Rick
You can do it even 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:35:11

Rick Rothstein

Here is another way to write the 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


2016-08-30 04:22:24

David Robinson

The second method can be simplified by using INDEX instead of VLOOKUP. You don't need the first column with the numbers in, just a single named range with the possible characters.

=INDEX(MyTable,RANDBETWEEN(1,62))
&INDEX(MyTable,RANDBETWEEN(1,62))
... etc.


2016-08-28 23:42:45

Brian Canes

Here is a way with formulas
Define the following four names
a =CHAR(RANDBETWEEN(97,122))
U =UPPER(a)
n =CHAR(RANDBETWEEN(48,57))
x =CHOOSE(RANDBETWEEN(1,3),a,U,n)

In A1=CONCATENATE(x,x,x,x,x,x,x,x)
and fill down 50 rows of captchas
Regards
Brian



This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.