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 Unique, Sequential Names.
Written by Allen Wyatt (last updated October 20, 2018)
This tip applies to Excel 97, 2000, 2002, and 2003
Steven is testing some software and he needs to feed into the program a bunch of "fake" names. He would like these names to be patterned such as Nameaaa, Nameaab, Nameaac, and so on through Namezzz. This would require creating 17,576 names (26 x 26 x 26). He wonders if there is an easy way to generate all these names in Excel.
This sort of repetitive task just cries out for a macro. (They are great for doing boring, dull, repetitive tasks that you don't want to do manually.) Here is a simple macro that can do the required grunt work:
Sub CreateNames() Dim i As Integer Dim x As Integer Dim y As Integer Dim z As Integer i = 1 For x = 97 To 122 For y = 97 To 122 For z = 97 To 122 Cells(i, 1) = "Name" & Chr(x) _ & Chr(y) & Chr(z) i = i + 1 Next Next Next End Sub
The macro uses three counter variables (x, y, and z) to serve as "counter variables" that control which letter of the alphabet is appended to the "name" stuffed into a cell. Notice that the For ... Next loops range from 97 to 122, which are the ASCII codes for lowercase a through z.
If you don't want to use a macro for some reason, type the following formula into cell A1 of a blank worksheet:
="Name" & CHAR((ROW()-1)/676+97)&CHAR(MOD( (ROW()-1)/26,26)+97)&CHAR(MOD(ROW()-1,26)+97)
This is a single formula, and it results in "Nameaaa" being displayed. Copy the formula down through row 17,576 and you'll have your fake names.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12128) 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 Unique, Sequential Names.
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!
Troubleshooting an Excel macro when it causes the entire computer to freeze can be a tedious affair. This tip provides ...
Discover MoreClick a button on a toolbar and Excel will go so far as to open a another workbook in order to run a macro associated ...
Discover MoreWhen you have a macro that processes a huge amount of data, it can seem like it takes forever to finish up. These ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-10-20 11:27:56
Rick Rothstein
Actually, since we are working with fixed ranges, we can use the square bracket shorthand notation for the Evaluate function and shorten up that code line slightly...
'========START CODE========
Sub CreateNames()
Range("A1:A17576") = [IF({1},"Name"&CHAR((ROW(A1:A17576)-1)/676+97)&CHAR(MOD((ROW(A1:A17576)-1)/26,26)+97)&CHAR(MOD(ROW(A1:A17576)-1,26)+97))]
End Sub'========END CODE========
2018-10-20 11:22:30
Rick Rothstein
Since you know of a formula that will work, why not use it in the macro and eliminate all of that looping? The following one-liner (albeit a rather long one) macro will produce the same output as your macro does...
'========START CODE========
Sub CreateNames()
Range("A1:A17576") = Evaluate("IF({1},""Name""&CHAR((ROW(A1:A17576)-1)/676+97)&CHAR(MOD((ROW(A1:A17576)-1)/26,26)+97)&CHAR(MOD(ROW(A1:A17576)-1,26)+97))")
End Sub
'========END CODE========
Note: If you only want to create a partial list, say 5000 names instead of the entire list of 17576 total names, simply change the range you are assigning to from Range(*A1:A17576") to Range("A1:A5000")... nothing else has to change.
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