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.

Generating Random Strings of Characters

by Allen Wyatt
(last updated May 12, 2012)

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.

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.

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

Generating Double-Digit Random Numbers

Normally you use the RAND and RANDBETWEEN functions to generate random numbers. What if you want to generate random numbers ...

Discover More

Deleting a Macro

ScreenTips can appear with or without shortcut keys displayed in them. Here's how to control whether they appear or not.

Discover More

The Last Business Day

Many businesses need to know when the last business day of the month occurs. This tip discusses several ways you can ...

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 (MENU)

Maintaining Text Formatting in a Lookup

Want to maintain the formatting used in one cell when you use formulas to reference that text in another cell? The answer is ...

Discover More

Deriving Monthly Median Values

When processing huge amounts of data, it can be a challenge to figure out how to derive the aggregate values you need. This ...

Discover More

Calculating Statistical Values on Different-Sized Subsets of Data

Discovering different ways to analyze your data can be a challenge. Here's how to work with arbitrary subsets of a large ...

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 for this tip:

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)

This Site

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.

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.

Links and Sharing
Share