Written by Allen Wyatt (last updated November 16, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
Jonathan is creating a macro and needs to fill a range of cells with values. For instance, if he needs to fill the range A1:C1, it currently takes three statements to fill that range:
Range("A1") = "Test1" Range("B1") = "Test2" Range("C1") = "Test3"
He wonders if there is a way to fill them in a single statement, similar to the following:
Range("A1:C1") = ("Test1","Test2","Test3")
Jonathan's desired syntax is close, but it won't work. Here's how it will work:
Range("A1:C1") = Array("Test1","Test2","Test3")
Note the use of the Array statement, which tells VBA that what follows should be considered a sequence of values to be used in the sequence of cells at the left of the operator. Interestingly enough, you could stuff values into variables and also use the Array statement, as shown here:
sOne = "Apples" sTwo = "Oranges" sThree = "Artichokes" Range("A1:C1") = Array(sOne, sTwo, sThree)
You can also work with straight variables, if you prefer:
Dim sMyStrings(2) As String sMyStrings(0) = "Apples" sMyStrings(1) = "Oranges" sMyStrings(2) = "Artichokes" Range("A1:C1") = sMyStrings
The above code could also be rewritten, as follows:
Dim sMyStrings(2) As String sMyStrings = Array("Apples", "Oranges", "Artichokes") Range("A1:C1") = sMyStrings
Finally, if you wanted to have the values placed into a single column rather than in a row, you would need to use the Transpose function, in this manner:
Range("A1:A3") = Application.Transpose(Array("Test1","Test2","Test3"))
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11701) 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: Filling a Range of Cells with Values.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
When creating macros, you often need to process numbers in various ways. VBA allows you to convert a numeric value to an ...
Discover MoreDo you need to create a number of words or phrases where you only alter a few letters in each one? If the alterations ...
Discover MoreIt is possible to develop macros that update the information in your worksheets automatically. In such instances, you may ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2025 Sharon Parq Associates, Inc.
Comments