“A list is only as strong as its weakest link” – Donald Knuth.
The following table provides a quick reference to using arrays in VBA. The remainder of the post provides the most complete guide you will find on the VBA arrays.
Contents
- 1 A Quick Guide to VBA Arrays
- 2 Introduction
- 3 Arrays Webinar
- 4 Quick Notes
- 5 What are Arrays and Why do You Need Them?
- 6 Types of VBA Arrays
- 7 Declaring an Array
- 8 Assigning Values to an Array
- 9 Using the Array and Split function
- 10 Using Loops With Arrays
- 11 Using Erase
- 12 ReDim with Preserve
- 13 Sorting an Array
- 14 Passing an Array to a Sub or Function
- 15 Returning an Array from a Function
- 16 Two Dimensional Arrays
- 17 Reading from a Range of Cells to an Array
- 18 How To Make Your Macros Run at Super Speed
- 19 Conclusion
- 20 What’s Next?
- 21 Arrays Cheat Sheet
A Quick Guide to VBA Arrays
Task | Static Array | Dynamic Array |
---|---|---|
Declare | Dim arr(0 To 5) As Long | Dim arr() As Long Dim arr As Variant |
Set Size | See Declare above | ReDim arr(0 To 5)As Variant |
Increase size (keep existing data) | Dynamic Only | ReDim Preserve arr(0 To 6) |
Set values | arr(1) = 22 | arr(1) = 22 |
Receive values | total = arr(1) | total = arr(1) |
First position | LBound(arr) | LBound(arr) |
Last position | Ubound(arr) | Ubound(arr) |
Read all items(1D) | For i = LBound(arr) To UBound(arr) Next i Or For i = LBound(arr,1) To UBound(arr,1) Next i | For i = LBound(arr) To UBound(arr) Next i Or For i = LBound(arr,1) To UBound(arr,1) Next i |
Read all items(2D) | For i = LBound(arr,1) To UBound(arr,1) For j = LBound(arr,2) To UBound(arr,2) Next j Next i | For i = LBound(arr,1) To UBound(arr,1) For j = LBound(arr,2) To UBound(arr,2) Next j Next i |
Read all items | Dim item As Variant For Each item In arr Next item | Dim item As Variant For Each item In arr Next item |
Pass to Sub | Sub MySub(ByRef arr() As String) | Sub MySub(ByRef arr() As String) |
Return from Function | Function GetArray() As Long() Dim arr(0 To 5) As Long GetArray = arr End Function | Function GetArray() As Long() Dim arr() As Long GetArray = arr End Function |
Receive from Function | Dynamic only | Dim arr() As Long Arr = GetArray() |
Erase array | Erase arr *Resets all values to default | Erase arr *Deletes array |
String to array | Dynamic only | Dim arr As Variant arr = Split("James:Earl:Jones",":") |
Array to string | Dim sName As String sName = Join(arr, ":") | Dim sName As String sName = Join(arr, ":") |
Fill with values | Dynamic only | Dim arr As Variant arr = Array("John", "Hazel", "Fred") |
Range to Array | Dynamic only | Dim arr As Variant arr = Range("A1:D2") |
Array to Range | Same as dynamic | Dim arr As Variant Range("A5:D6") = arr |
Introduction
This post provides an in-depth look at arrays in the Excel VBA programming language. It covers the important points such as
- Why you need arrays
- When should you use them
- The two types of arrays
- Using more than one dimension
- Declaring arrays
- Adding values
- Viewing all the items
- A super efficient way to read a Range to an array
In the first section we will look at is what are arrays and why you need them. You may not understand some of the code in the first section. This is fine. I will be breaking it all down into simple terms in the following sections of the post.
Arrays Webinar
If you are a member of the website, click on the image below to access the webinar.
(Note: Website members have access to the full webinar archive.)
Quick Notes
Sometimes Collections are a better option than arrays. You can read about collections here.
Arrays and Loops go hand in hand. The most common loops you use with arrays are the For Loop and the For Each Loop(read-only).
What are Arrays and Why do You Need Them?
A VBA array is a type of variable. It is used to store lists of data of the same type. An example would be storing a list of countries or a list of weekly totals.
In VBA a normal variable can store only one value at a time.
The following example shows a variable being used to store the marks of a student.
' Can only store 1 value at a time Dim Student1 As Integer Student1 = 55
If we wish to store the marks of another student then we need to create a second variable.
In the following example we have the marks of five students
We are going to read these marks and write them to the Immediate Window.
Note: The function Debug.Print writes values to the Immediate Window. To view this window select View->Immediate Window from the menu( Shortcut is Ctrl + G)
As you can see in the following example we are writing the same code five times – once for each student
Public Sub StudentMarks() With ThisWorkbook.Worksheets("Sheet1") ' Declare variable for each student Dim Student1 As Integer Dim Student2 As Integer Dim Student3 As Integer Dim Student4 As Integer Dim Student5 As Integer ' Read student marks from cell Student1 = .Range("C2").Offset(1) Student2 = .Range("C2").Offset(2) Student3 = .Range("C2").Offset(3) Student4 = .Range("C2").Offset(4) Student5 = .Range("C2").Offset(5) ' Print student marks Debug.Print "Students Marks" Debug.Print Student1 Debug.Print Student2 Debug.Print Student3 Debug.Print Student4 Debug.Print Student5 End With End Sub
The following is the output from the example
The problem with using one variable per student is that you need to add code for each student. Therefore if you had a thousand students in the above example you would need three thousand lines of code!
Luckily we have arrays to make our life easier. Arrays allow us to store a list of data items in one structure.
The following code shows the above student example using an array
Public Sub StudentMarksArr() With ThisWorkbook.Worksheets("Sheet1") ' Declare an array to hold marks for 5 students Dim Students(1 To 5) As Integer ' Read student marks from cells C3:C7 into array Dim i As Integer For i = 1 To 5 Students(i) = .Range("C2").Offset(i) Next i ' Print student marks from the array Debug.Print "Students Marks" For i = LBound(Students) To UBound(Students) Debug.Print Students(i) Next i End With End Sub
The advantage of this code is that it will work for any number of students. If we have to change this code to deal with 1000 students we only need to change the (1 To 5) to (1 To 1000) in the declaration. In the prior example we would need to add approximately five thousand lines of code.
Let’s have a quick comparison of variables and arrays. First we compare the declaration
' Variable Dim Student As Integer Dim Country As String ' Array Dim Students(1 To 3) As Integer Dim Countries(1 To 3) As String
Next we compare assigning a value
' assign value to variable Student1 = .Cells(1, 1) ' assign value to first item in array Students(1) = .Cells(1, 1)
Lastly we look at writing the values
' Print variable value Debug.Print Student1 ' Print value of first student in array Debug.Print Students(1)
As you can see, using variables and arrays is quite similar.
The fact that arrays use an index(also called a subscript) to access each item is important. It means we can easily access all the items in an array using a For Loop.
Now that you have some background on why arrays are useful lets go through them step by step.
Types of VBA Arrays
There are two types of arrays in VBA
- Static – an array of fixed size.
- Dynamic – an array where the size is set at run time.
The difference between these arrays mainly in how they are created. Accessing values in both array types is exactly the same. In the following sections we will cover both types.
Declaring an Array
A static array is declared as follows
Public Sub DecArrayStatic() ' Create array with locations 0,1,2,3 Dim arrMarks1(0 To 3) As Long ' Defaults as 0 to 3 i.e. locations 0,1,2,3 Dim arrMarks2(3) As Long ' Create array with locations 1,2,3,4,5 Dim arrMarks1(1 To 5) As Long ' Create array with locations 2,3,4 ' This is rarely used Dim arrMarks3(2 To 4) As Long End Sub
As you can see the size is specified when you declare a static array. The problem with this is that you can never be sure in advance the size you need. Each time you run the Macro you may have different size requirements.
If you do not use all the array locations then the resources are being wasted. If you need more locations you can use ReDim but this is essentially creating a new static array.
The dynamic array does not have such problems. You do not specify the size when you declare it. Therefore you can then grow and shrink as required
Public Sub DecArrayDynamic() ' Declare dynamic array Dim arrMarks() As Long ' Set the size of the array when you are ready ReDim arrMarks(0 To 5) End Sub
The dynamic array is not allocated until you use the ReDim statement. The advantage is you can wait until you know the number of items before setting the array size. With a static array you have to give the size up front.
To give an example. Imagine you were reading worksheets of student marks. With a dynamic array you can count the students on the worksheet and set an array to that size. With a static array you must set the size to the largest possible number of students.
Need Help Using Arrays? Click here to get your FREE Cheat Sheet
Assigning Values to an Array
To assign values to an array you use the number of the location. You assign value for both array types the same way.
Public Sub AssignValue() ' Declare array with locations 0,1,2,3 Dim arrMarks(0 To 3) As Long ' Set the value of position 0 arrMarks(0) = 5 ' Set the value of position 3 arrMarks(3) = 46 ' This is an error as there is no location 4 arrMarks(4) = 99 End Sub
The number of the location is called the subscript or index. The last line in the example will give a “Subscript out of Range” error as there is no location 4 in the array example.
Using the Array and Split function
You can use the Array function to populate an array with a list of items. You must declare the array as a type Variant. The following code shows you how to use this function.
Dim arr1 As Variant arr1 = Array("Orange", "Peach","Pear") Dim arr2 As Variant arr2 = Array(5, 6, 7, 8, 12)
The array created by the Array Function will start at index zero unless you use Option Base 1 at the top of your module. Then it will start at index one. In programming it is generally considered poor practice to have your actual data in the code. However sometimes it is useful when you need to test some code quickly. The Split function is used to split a string into an array based on a delimiter. A delimiter is a character such as a comma or space that separates the items.
The following code will split the string into an array of three elements.
Dim s As String s = "Red,Yellow,Green,Blue" Dim arr() As String arr = Split(s, ",")
The Split function is normally used when you read from a comma separated file or another source that provides a list of items separated by the same character.
Using Loops With Arrays
Using a For Loop allows quick access to all items in an array. This is where the power of using arrays becomes apparent. We can read arrays with ten values or ten thousand values using the same few lines of code. There are two functions in VBA called LBound and UBound. These functions return the smallest and largest subscript in an array. In an array arrMarks(0 to 3) the LBound will return 0 and UBound will return 3.
The following example assigns random numbers to an array using a loop. It then prints out these numbers using a second loop.
Public Sub ArrayLoops() ' Declare array Dim arrMarks(0 To 5) As Long ' Fill the array with random numbers Dim i As Long For i = LBound(arrMarks) To UBound(arrMarks) arrMarks(i) = 5 * Rnd Next i ' Print out the values in the array Debug.Print "Location", "Value" For i = LBound(arrMarks) To UBound(arrMarks) Debug.Print i, arrMarks(i) Next i End Sub
The functions LBound and UBound are very useful. Using them means our loops will work correctly with any array size. The real benefit is that if the size of the array changes we do not have to change the code for printing the values. A loop will work for an array of any size as long as you use these functions.
Using the For Each Loop
You can use the For Each loop with arrays. The important thing to keep in mind is that it is Read-Only. This means that you cannot change the value in the array.
In the following code the value of mark changes but it does not change the value in the array.
For Each mark In arrMarks ' Will not change the array value mark = 5 * Rnd Next mark
The For Each is loop is fine to use for reading an array. It is neater to write especially for a Two-Dimensional array as we will see.
Dim mark As Variant For Each mark In arrMarks Debug.Print mark Next mark
Using Erase
The Erase function can be used on arrays but performs differently depending on the array type.
For a static Array the Erase function resets all the values to the default. If the array is of integers then all the values are set to zero. If the array is of strings then all the strings are set to “” and so on.
For a Dynamic Array the Erase function DeAllocates memory. That is, it deletes the array. If you want to use it again you must use ReDim to Allocate memory.
Lets have a look an example for the static array. This example is the same as the ArrayLoops example in the last section with one difference – we use Erase after setting the values. When the value are printed out they will all be zero.
Public Sub EraseStatic() ' Declare array Dim arrMarks(0 To 3) As Long ' Fill the array with random numbers Dim i As Long For i = LBound(arrMarks) To UBound(arrMarks) arrMarks(i) = 5 * Rnd Next i ' ALL VALUES SET TO ZERO Erase arrMarks ' Print out the values - there are all now zero Debug.Print "Location", "Value" For i = LBound(arrMarks) To UBound(arrMarks) Debug.Print i, arrMarks(i) Next i End Sub
We will now try the same example with a dynamic. After we use Erase all the locations in the array have been deleted. We need to use ReDim if we wish to use the array again.
If we try to access members of this array we will get a “Subscript out of Range” error.
Public Sub EraseDynamic() ' Declare array Dim arrMarks() As Long ReDim arrMarks(0 To 3) ' Fill the array with random numbers Dim i As Long For i = LBound(arrMarks) To UBound(arrMarks) arrMarks(i) = 5 * Rnd Next i ' arrMarks is now deallocated. No locations exist. Erase arrMarks End Sub
ReDim with Preserve
If we use ReDim on an existing array, then the array and its contents will be deleted.
In the following example, the second ReDim statement will create a completely new array. The original array and its contents will be deleted.
Sub UsingRedim() Dim arr() As String ' Set array to be slots 0 to 2 ReDim arr(0 To 2) arr(0) = "Apple" ' Array with apple is now deleted ReDim arr(0 To 3) End Sub
If we want to extend the size of an array without losing the contents, we can use the Preserve keyword.
When we use Redim Preserve the new array must start at the same starting dimension e.g.
We cannot Preserve from (0 to 2) to (1 to 3) or to (2 to 10) as they are different starting dimensions.
In the following code we create an array using ReDim and then fill the array with types of fruit.
We then use Preserve to extend the size of the array so we don’t lose the original contents.
Sub UsingRedimPreserve() Dim arr() As String ' Set array to be slots 0 to 1 ReDim arr(0 To 2) arr(0) = "Apple" arr(1) = "Orange" arr(2) = "Pear" ' Resize and keep original contents ReDim Preserve arr(0 To 5) End Sub
You can see from the screenshots below, that the original contents of the array have been “Preserved”.

Before ReDim Preserve

After ReDim Preserve
Word of Caution: In most cases you shouldn’t need to resize an array like we have done in this section. If you are resizing an array multiple times then you many want to considering using a Collection.
Using Preserve with 2 Dimensional Arrays
Preserve only works with the upper bound of an array.
For example, if you have a 2 dimensional array you can only preserve the second dimension as this example shows:
Sub Preserve2D() Dim arr() As Long ' Set the starting size ReDim arr(1 To 2, 1 To 5) ' Resize the upper dimension ReDim Preserve arr(1 To 2, 1 To 10) End Sub
If we try to use Preserve on a lower bound we will get the “Subscript out of range” error.
In the following code we use Preserve on the first dimension. Running this code will give the “Subscript out of range” error:
Sub Preserve2DError() Dim arr() As Long ' Set the starting size ReDim arr(1 To 2, 1 To 5) ' "Subscript out of Range" error ReDim Preserve arr(1 To 5, 1 To 5) End Sub
When we read from a range to an array, it automatically creates a two dimensional array, even if we have only one column.
The same Preserve rules apply. We can only use Preserve on the upper bound as this example shows:
Sub Preserve2DRange() Dim arr As Variant ' Assign a range to an array arr = Sheet1.Range("A1:A5").Value ' Preserve will work on the upper bound only ReDim Preserve arr(1 To 5, 1 To 7) End Sub
Sorting an Array
There is no function in VBA for sorting an array. We can sort the worksheet cells but this could be slow if there is a lot of data.
The QuickSort function below can be used to sort an array.
Sub QuickSort(arr As Variant, first As Long, last As Long) Dim vCentreVal As Variant, vTemp As Variant Dim lTempLow As Long Dim lTempHi As Long lTempLow = first lTempHi = last vCentreVal = arr((first + last) \ 2) Do While lTempLow <= lTempHi Do While arr(lTempLow) < vCentreVal And lTempLow < last lTempLow = lTempLow + 1 Loop Do While vCentreVal < arr(lTempHi) And lTempHi > first lTempHi = lTempHi - 1 Loop If lTempLow <= lTempHi Then ' Swap values vTemp = arr(lTempLow) arr(lTempLow) = arr(lTempHi) arr(lTempHi) = vTemp ' Move to next positions lTempLow = lTempLow + 1 lTempHi = lTempHi - 1 End If Loop If first < lTempHi Then QuickSort arr, first, lTempHi If lTempLow < last Then QuickSort arr, lTempLow, last End Sub
You can use this function like this
Sub TestSort() ' Create temp array Dim arr() As Variant arr = Array("Banana", "Melon", "Peach", "Plum", "Apple") ' Sort array QuickSort arr, LBound(arr), UBound(arr) ' Print arr to Immediate Window(Ctrl + G) Dim i As Long For i = LBound(arr) To UBound(arr) Debug.Print arr(i) Next i End Sub
Passing an Array to a Sub or Function
Sometimes you will need to pass an array to a procedure. You declare the parameter using parenthesis similar to how you declare a dynamic array.
Passing to the procedure using ByRef means you are passing a reference of the array. So if you change the array in the procedure it will be changed when you return.
Note: When you use an array as a parameter it cannot use ByVal, it must use ByRef. You can pass the array using ByVal making the parameter a variant.
' Passes array to a Function Public Sub PassToProc() Dim arr(0 To 5) As String ' Pass the array to function UseArray arr End Sub Public Function UseArray(ByRef arr() As String) ' Use array Debug.Print UBound(arr) End Function
Returning an Array from a Function
It is important to keep the following in mind. If you want to change an existing array in a procedure then you should pass it as a parameter using ByRef(see last section). You do not need to return the array from the procedure.
The main reason for returning an array is when you use the procedure to create a new one. In this case you assign the return array to an array in the caller. This array cannot be already allocated. In other words you must use a dynamic array that has not been allocated.
The following examples show this
Public Sub TestArray() ' Declare dynamic array - not allocated Dim arr() As String ' Return new array arr = GetArray End Sub Public Function GetArray() As String() ' Create and allocate new array Dim arr(0 To 5) As String ' Return array GetArray = arr End Function
Two Dimensional Arrays
The arrays we have been looking at so far have been one dimensional arrays. This means the arrays are one list of items.
A two dimensional array is essentially a list of lists. If you think of a single spreadsheet row as a single dimension then more than one column is two dimensional. In fact a spreadsheet is the equivalent of a 2 dimensional array. It has two dimensions – rows and columns.
One small thing to note is that Excel treats a one-dimensional array as a row if you write it to a spreadsheet. In other words, the array arr(1 to 5) is equivalent to arr(1 to 1, 1 to 5) when writing values to the spreadsheet.
The following image shows two groups of data. The first is a one dimensional layout and the second is two dimensional.
To access an item in the first set of data(1 dimensional) all you need to do is give the row e.g. 1,2, 3 or 4.
For the second set of data (two-dimensional) you need to give the row AND the column. So you can think of 1 dimensional being multiple columns and one row and two-dimensional as being multiple rows and multiple columns.
Note: It is possible to have more than two dimensions in an array. It is rarely required. If you are solving a problem using a 3+ dimensional array then there probably is a better way to do it.
You declare a 2 dimensional array as follows
Dim ArrayMarks(0 To 2,0 To 3) As Long
The following example creates a random value for each item in the array and the prints the values to the Immediate Window.
Public Sub TwoDimArray() ' Declare a two dimensional array Dim arrMarks(0 To 3, 0 To 2) As String ' Fill the array with text made up of i and j values Dim i As Long, j As Long For i = LBound(arrMarks) To UBound(arrMarks) For j = LBound(arrMarks, 2) To UBound(arrMarks, 2) arrMarks(i, j) = CStr(i) & ":" & CStr(j) Next j Next i ' Print the values in the array to the Immediate Window Debug.Print "i", "j", "Value" For i = LBound(arrMarks) To UBound(arrMarks) For j = LBound(arrMarks, 2) To UBound(arrMarks, 2) Debug.Print i, j, arrMarks(i, j) Next j Next i End Sub
You can see that we use a second For loop inside the first loop to access all the items.
The output of the example looks like this:
How this Macro works is as follows
- Enters the i loop
- i is set to 0
- Entersj loop
- j is set to 0
- j is set to 1
- j is set to 2
- Exit j loop
- i is set to 1
- j is set to 0
- j is set to 1
- j is set to 2
- And so on until i=3 and j=2
You may notice that LBound and UBound have a second argument of 2. This specifies that it is the upper or lower bound of the second dimension. That is the start and end location for j. The default value 1 which is why we do not need to specify it for the i loop.
Using the For Each Loop
Using a For Each is neater to use when reading from an array.
Let’s take the code from above that writes out the two-dimensional array
' Using For loop needs two loops Debug.Print "i", "j", "Value" For i = LBound(arrMarks) To UBound(arrMarks) For j = LBound(arrMarks, 2) To UBound(arrMarks, 2) Debug.Print i, j, arrMarks(i, j) Next j Next i
Now let’s rewrite it using a For each loop. You can see we only need one loop and so it is much easier to write
' Using For Each requires only one loop Debug.Print "Value" Dim mark As Variant For Each mark In arrMarks Debug.Print mark Next mark
Using the For Each loop gives us the array in one order only – from LBound to UBound. Most of the time this is all you need.
Reading from a Range of Cells to an Array
If you have read my previous post on Cells and Ranges then you will know that VBA has an extremely efficient way of reading from a Range of Cells to an Array and vice versa
Public Sub ReadToArray() ' Declare dynamic array Dim StudentMarks As Variant ' Read values into array from first row StudentMarks = Range("A1:Z1").Value ' Write the values back to the third row Range("A3:Z3").Value = StudentMarks End Sub
The dynamic array created in this example will be a two dimensional array. As you can see we can read from an entire range of cells to an array in just one line.
The next example will read the sample student data below from C3:E6 of Sheet1 and print them to the Immediate Window.
Public Sub ReadAndDisplay() ' Get Range Dim rg As Range Set rg = ThisWorkbook.Worksheets("Sheet1").Range("C3:E6") ' Create dynamic array Dim StudentMarks As Variant ' Read values into array from sheet1 StudentMarks = rg.Value ' Print the array values Debug.Print "i", "j", "Value" Dim i As Long, j As Long For i = LBound(StudentMarks) To UBound(StudentMarks) For j = LBound(StudentMarks, 2) To UBound(StudentMarks, 2) Debug.Print i, j, StudentMarks(i, j) Next j Next i End Sub
As you can see the first dimension(accessed using i) of the array is a row and the second is a column. To demonstrate this take a look at the value 44 in E4 of the sample data. This value is in row 2 column 3 of our data. You can see that 44 is stored in the array at StudentMarks(2,3).
How To Make Your Macros Run at Super Speed
If your macros are running very slow then you may find this section very helpful. Especially if you are dealing with large amounts of data. The following is a well kept secret in VBA
Updating values in arrays is exponentially faster than updating values in cells.
In the last section, you saw how we can easily read from a group of cells to an array and vice versa. If we are updating a lot of values then we can do the following
1. Copy the data from the cells to an array.
2. Change the data in the array.
3. Copy the updated data from the array back to the cells.
For example, the following code would be much faster than the code below it
Public Sub ReadToArray() ' Read values into array from first row Dim StudentMarks As Variant StudentMarks = Range("A1:Z20000").Value Dim i As Long For i = LBound(StudentMarks) To UBound(StudentMarks) ' Update marks here StudentMarks(i, 1) = StudentMarks(i, 1) * 2 '... Next i ' Write the new values back to the worksheet Range("A1:Z20000").Value = StudentMarks End Sub
Sub UsingCellsToUpdate() Dim c As Variant For Each c In Range("A1:Z20000") c.Value = ' Update values here Next c End Sub
Assigning from one set of cells to another is also much faster than using Copy and Paste
' Assigning - this is faster Range("A1:A10").Value = Range("B1:B10").Value ' Copy Paste - this is slower Range("B1:B1").Copy Destination:=Range("A1:A10")
The following comments are from two readers who used arrays to speed up their macros
“A couple of my projects have gone from almost impossible and long to run into almost too easy and a reduction in time to run from 10:1.” – Dane
“One report I did took nearly 3 hours to run when accessing the cells directly — 5 minutes with arrays” – Jim
Conclusion
The following is a summary of the main points of this post
- Arrays are an efficient way of storing a list of items of the same type.
- You can access an array item directly using the number of the location which is known as the subscript or index.
- The common error “Subscript out of Range” is caused by accessing a location that does not exist.
- There are two types of arrays: Static and Dynamic.
- Static is used when the size of the array is always the same.
- Dynamic arrays allow you to determine the size of an array at run time.
- LBound and UBound provide a safe way of find the smallest and largest subscripts of the array.
- The basic array is one dimensional. You can also have multi dimensional arrays.
- You can only pass an array to a procedure using ByRef. You do this like this: ByRef arr() as long.
- You can return an array from a function but the array, it is assigned to, must not be currently allocated.
- A worksheet with its rows and columns is essentially a two dimensional array.
- You can read directly from a worksheet range into a two dimensional array in just one line of code.
- You can also write from a two dimensional array to a range in just one line of code.
What’s Next?
Free VBA Tutorial If you are new to VBA or you want to sharpen your existing VBA skills then why not try out the The Ultimate VBA Tutorial.
Related Training: Get full access to the Excel VBA training webinars and all the tutorials.
(NOTE: Planning to build or manage a VBA Application? Learn how to build 10 Excel VBA applications from scratch.)
Arrays Cheat Sheet
Need Help Using Arrays? Click here to get your FREE Cheat Sheet
Hi Paul,
I need your help. I need to a store a row of excel containing 130 Store i.e STR 1…….STR 130 in a array and then read this array so that I can populate these store number i.e 1, 2,3,4 and so on into another sheet. please suggest me how to do the same.
Thanks
Dear Paul, appreciate if you can help on the below. i got the code form one of the book.
Public Function process(arr() As Integer) As Integer()
Dim j As Integer
ReDim t(UBound(arr))
For j = 1 To UBound(arr)
t(j) = arr(j) + 10
Next j
process = t
End Function
the function however never worked when i pass data directly from excel . May i know what i am missing here. I am well aware of the array function where argument is passed as range type and it works with me fine. but the above code which looks way simpler did not . Looking forward to receiving your commetn
Hi Mark,
When you pass a Range to an array, the array must be declared as type Variant.
So anywhere you have () As Integer, it should be replaced by As Variant.
e.g. Dim arr As Variant
Also, an array from a range is two dimensional so you need to use a for loop within a for loop to read the cells. See the section on two-dimensional arrays above.
Paul
Many thanks Paul, i would assume the above function is meant to work only inside the Vb environment (without output to excel) if i understood correctly.
Many thanks for your valuable feedback
Hi Paul
I think you should mention the fact that ‘REDIM’ statement alone Clears all the contents of an Array, and if you want to keep it – you should use ‘REDIM PRESERVE’
Hi Uri,
It is already covered here.
Thanks
Paul
Hi Paul,
Please help me, How to Copy the below condition to another Sheet?
Action Code Number Status
Create 12345 1 A
Create 12345 1 A
Create 12345 1 A
Create 43215 2 B
Create 43215 2 B
Create 54321 3 C
Create 54321 3 C
The Row with same Code needs to be Copy only one time in another Sheet as below:
Action Code Number Status
Create 12345 1 A
Create 43215 1 B
Create 54321 1 C
I am beginner in Macros. Thanks In advance
Use a Dictionary to store each item.
You need to use a loop to read through the data.
Check the Dictionary each time to see if the item has already been added. If not add.
When the loop is finished, read through the dictionary and write out the data.
Paul
I want to calculate the following:
col_A * col_B * product of col_C from the current row to the last row.
Then, at the next row , col_A * col_B * col_C product to end etc.
Then, find the sum.
In a standard array formula, this could start off as {=sum(a*b*c)} but of course it doesn’t handle the compounding of elements i:n, i+1:n, i+2:n,….,n:n in column C.
I can build it out using extra helper columns but is there a convenient one cell formula to achieve this?
This is great work and I can tell you put a lot of work into this to cover a lot of parameters. Arrays are very underutilized and often misunderstood. Your effort should help combat this!
Thanks Steven.
Hi Paul,
I am trying to write a sub that looks at values in a column (column C) on a sheet called “ref_list” and if values in a D column in a separate sheet (“JE”) equal any of the values in the C column array, I would like the corresponding F column in sheet “JE” to turn red. The values in the D column are derived for a ‘=MID’ formula.
I haven’t written much VBA code before this. I think I have the array set up but the other functionality, I am unsure of how to incorporate that properly in an array. Do you have any suggestions? Thanks for this page, it’s content is very helpful. Here is what I have so far.
Private Sub DeptArray()
Dim Arr() As Variant
Arr = Sheet5.Range(“C1:C20”).Value
Dim C As Long
For C = 1 To UBound(Arr, 1)
Next C
End Sub
Hi Drew,
You would be better off using a Dictionary for this.
The Dictionary allows you to easily check if a value already exists.
Here is an example
Thanks so much, Paul. I have one additional question I was hoping you could answer. Under the For statement, could I add the functionality to turn the F column cell red, clickable, and upon clicking the red colored cell, it calls a macro associated with the value?
Hey Paul,
Sorry for the double comment. Please disregard my first comment. I have refined my question more in my last comment. Sorry again.
Hi Paul,
i have a problem to calculate inverse matrix. i already search and i did’t find yet and also always error. i have matrix (42×42) and i want to inverse it. Do you have any suggestion? Thank You Paul
Hi Paul
I am trying to declare a dynamic array with 3 columns. Within a for loop, I would like to add to the array so it is unknown how many record elements will be in the array.
here is what i have so far which is not working:
‘declare array
Dim final_array() As String
‘add records to the array
ReDim final_array(0 To 2, 0 To UBound(final_array) + 1)
final_array(0, UBound(final_array) – 1) = Current_Sheet
final_array(1, UBound(final_array) – 1) = Current_Ticker
final_array(2, UBound(final_array) – 1) = Current_PCT_Change
‘test array
MsgBox (UBound(final_array))
MsgBox final_array(1, 1)
I never get a message box and watch shows value as “out of context”
Any help is GREATLY appreciated!
Is there an error message? Put a breakpoint(F9( on the line Redim and step through the code(Shift + F8) to see what is happening.
very wonderfull sharing. Thanks…
Hey Paul, Thank you very much.
Awesome website Paul.
I’ve been meaning to learn arrays for years and you’ve helped me just this weekend.
I already have projects at my work that I plan on this knowledge on in the upcoming months.
One thing I can’t quite grasp is when a multidimensional array would be useful. Can you give a real-world example.
Much thanks,
James
A spreadsheet is a two-dimensional array. When you assign a range to array it creates a two-dimensional array to hold the values from the cells.
Dim arr As Variant
arr = Sheet1.Range(“A1:D10”).Value
Dear Sir good day. Very helpful guide. I am excel enthusiast -begginer in VBA and I have a few questions:
– how to form the array of arrays, where the arrays would share same name i.e. arr1, arr2….to arri,
– how to perform assembly / summing of the multiple arrays into one array where each array fits into particular position (needed for my FEM work which I have developed on spreadsheet but would like to be goverened by VBA), i.e. all array are dimension arr(1,6) where we assembly is done by summing of the shared elements as noted on heading row and first column (1 to 6) for instance element at reference position 4,4 is shared with arr1 and arr2, so resulting item would be 2 and would need to fit the new array dimension 12×12 at position R,C 4,4 – for better understanding what I am trying to accomplish below is the manual sum and result of noted arrays – for ease all elements are set to 1:
arr1
1 2 3 4 5 6
1 1 1 1 1 1 1
2 1 1 1 1 1 1
3 1 1 1 1 1 1
4 1 1 1 1 1 1
5 1 1 1 1 1 1
6 1 1 1 1 1 1
arr2
4 5 6 7 8 9
4 1 1 1 1 1 1
5 1 1 1 1 1 1
6 1 1 1 1 1 1
7 1 1 1 1 1 1
8 1 1 1 1 1 1
9 1 1 1 1 1 1
arr3
7 8 9 10 11 12
7 1 1 1 1 1 1
8 1 1 1 1 1 1
9 1 1 1 1 1 1
10 1 1 1 1 1 1
11 1 1 1 1 1 1
12 1 1 1 1 1 1
arr4
Result
1 2 3 4 5 6 7 8 9 10 11 12
1 1 1 1 1 1 1 0 0 0 0 0 0
2 1 1 1 1 1 1 0 0 0 0 0 0
3 1 1 1 1 1 1 0 0 0 0 0 0
4 1 1 1 2 2 2 1 1 1 0 0 0
5 1 1 1 2 2 2 1 1 1 0 0 0
6 1 1 1 2 2 2 1 1 1 0 0 0
7 0 0 0 1 1 1 2 2 2 1 1 1
8 0 0 0 1 1 1 2 2 2 1 1 1
9 0 0 0 1 1 1 2 2 2 1 1 1
10 0 0 0 0 0 0 1 1 1 1 1 1
11 0 0 0 0 0 0 1 1 1 1 1 1
12 0 0 0 0 0 0 1 1 1 1 1 1
I hope you find it interesting and thank you in advance for your assistance.
Frano
On the “Reading from a Range of Cells to an Array” section, isn’t in an error to say that the resulting array is two dimensional? You are selecting columns from a single row.
Thanks
The returned array will have two dimensions even though there is only one row.
to access column 2 would be arr(1,2) as opposed to arr(2) if it was 1 dimensional.
Hi Paul,
I remember that in one of your webinars you talked about an alternative array that you had to activate through an object library reference. I remember this special array had more methods, like sorting and removing items. Do you remember the name of this reference? I would like to give it a try, but I cant find it anymore… Thanks!
Hi Joris,
What you are referring to is the ArrayList. The name is a bit confusing because it is a Collection rather than an Array.
Regards
Paul
Hi Paul,
i want to compare different ranges of data from different workbooks, and i was trying to use arrays in for loops, but the problem is that i couldn’t erase them and reuse the array. Do you think that i should use a collection instead? Or there is a way of reusing arrays for ranges? Thanks in advance.
Hi Eduardo.
You can use Erase.
I’ve tried to use erase but it shows an error that the array is fixed or locked.
I don’t think Erase is the problem. See this link for solutions to the issue.
Thanks Paul,
I found the answer, it seems that when you are using arrays on loops, you cant use goto statement, because it will lock the array temporarily.
I’ve removed it, and erase worked just fine.
Thanks for your help, the content on your website is great!
Regards
Eduardo.
Thanks Eduardo, Glad you got it sorted.
Hi Paul,
I have not seen anything on any upcoming webinars. Any plans for that?
Thanks,
-Tony
Hi Tony,
There will be one on the 25th October.
Sir i want ask you abaut
Dim arr () as range
I want you explain me and give example thank you for attention
Hi Wan,
This is a dynamic array of ranges. It means that it will store a number of range objects.
Dynamic array means that the size will be set using ReDim when the application is running. See Dynamic arrays in the post.
Hi Paul,
I trying to work out the time spend by a bus to pick passengers at stations A to G, at each station the bus will pick 3 to 5 passengers at t times, the bus my go back to x station to pick more passengers, what I’m trying to calculate time spend at each station. Below is an example of data and calculated time at each station (calculated manually) for the first hour or so. Do you have any suggestions? Thank You Paul
STATION PICKUP/TIME Time spend
A 6:38:24 0:01:43
A 6:38:58
A 6:39:32
A 6:40:07
B 6:43:29 0:12:37
B 6:54:23
B 6:54:57
B 6:55:31
B 6:56:06
C 7:00:39 0:01:43
C 7:01:13
C 7:01:47
C 7:02:22
D 7:05:18 0:02:57
D 7:06:32
D 7:07:06
D 7:07:40
D 7:08:15
E 7:10:39 0:03:37
E 7:12:33
E 7:13:07
E 7:13:41
E 7:14:16
A 7:15:25 0:04:37
A 7:18:19
A 7:18:53
A 7:19:27
A 7:20:02
G 7:23:23 0:05:52
G 7:25:25
G 7:29:15
Hi Paul,
I have a set of data that I am putting in a variant array, then reading into a Dictionary so I can sum similar items and so that I can put them back to a spreadsheet in a different order. Since I am changing the order (and also inserting extra rows or removing rows, depending on various criteria ), I can’t put them in the resultsArray during processing. But after processing, I have to loop through each “column” of each “row” array from my dictionary to put it into the resultsArray because “resultsArr (1) = .Item(pos)” like I would do in Javascript gives me an error if resultsArray is 2d and prints #N/A when I try to put it on the worksheet if resultsArr is 1d. Is there a better way to do this?
Thanks!
Paul,
I can get around in vba pretty well but I’ve never really used Arrays before. My current situation I think would be best done with one. Im working on a sub that will take data from a worksheet and create a chart from it. The number and types of data series can change. I dont have any problems with the series if the type is the same but what I want to do is compare the data types and put a differing one on the secondary axis.
Example (seriesname and type are in adjacent cells.) :
Series Type
seriesname1 type1
seriesname2 type1
seriesname3 type2
So basically have it plot the 3 series and then find the odd one out and do something like
ActiveChart.SeriesCollection(x).Select
ActiveChart.SeriesCollection(x).AxisGroup = 2
Hi Paul,
i have to pass 2 arrays and 4 integers to a function . each array hs 40 values.
i have to then do some calculation based on the array values at each index. how do i do it..
I donot know how to give the input and read it inside this function .
Public Function GetMapvalue(s1, in1, map() As Variant, S2, In2, axis() As Variant, INP)
i have to convert the following c code to VBA script.
while (found == FALSE) {
if (inp >= axis[ndx])
{
if (ndx < s2 – 1)
{
if (inp < (float32)axis[ndx + 1])
{
statement1
}
else {
ndx ++;
}
}
else {
val = map[s2 – 1];
found = TRUE;
}
}
now how do i pass the arrays to this function and how to get those values inside the function and perform the calculation.
Hi, I found your array video extremely helpful.
I have loaded a two-dimensional array with values. I need to output the values in the array to another sheet, with the columns in a different order to the order they were read in.
Can I do this? or should I reorder it prior to reading it into the array?
Thanks Luke
I have a vba code, where I’m trying to define a 2D array. I get a run time error 9 saying subscript out of range. Can you help me with this?
Dim x as long
x= cells(1,1).End(xlDown).row
Dim arr() as long
ReDim arr(0 to x, 0 to 13)
dim i as long, j as long
for i =lbound(arr) to ubound(arr)
for j=lbound(arr,13) to ubound(arr,13)
I get my error right there. I would love some help on this. It would be much appreciated.
Thank you
Nate
x comes out to be 67 in my sheet as well. f.y.i
Got it actually, just changed the 13, to a 2 in the lbound and ubound functions and works great now. Thanks!
This is excellent work and a huge help!
Glad you got it sorted.
Awesome article, thanks Paul.
I’m up to the sorting paragraph TestSort and QuickSort. I wish there was more of a gradual guide in here as it gets quite advanced quite quickly.
There’s 2 types of filtering here:
1 – via the strings themselves in alphabetical order;
2 – via the subscript/ index number;
I’ve spent a whole day on this paragraph alone, printed out the article and going through with pen scribbling on the paper the counters for the loops as it happens, whilst stepping through the macro and I’ve made notes in another book on the whole tutorial (thanks by the way it really is a great tutorial).
I just wish there was more explanation on what’s going on with the sorting of the array as there really is a lot to get one’s head around and deciphering how it works really is taking me a lot of time.
That’s my only constructive criticism so far. I knew it’d be hard as understanding the concept of looping inside the arrays and manipulating them as we go was never going to be easy.
Regards
Dal
Hi Dal,
Glad you like the article.
Quicksort is a well-known sort algorithm that has been developed by computer scientists. If have implemented it here for VBA. You don’t need to understand it – you can just use it.
The other parts of the posts are more important to understand.
You can read more about sorting algorithms here and see how they work.
Hi Paul, Can you please help me with this? I am trying to load an array with a spreadsheet data. I dont know the no of rows on this sheet. I know the columns – A,B,C, D, E
My code is
With Worksheets(“Sheet1”).Range(“A”)
arry = Range(.Offset(1,0),.Offset(4,0).End(xlDown))
End WIth
When I print my arry upper and lower bound like this
Debug.Print UBound(arry,1)
its throwing Type Mismatch.
Can you please help me here? Did i access it right. When I hardcode the value as “A1:E4” instead of offset it helps well.Thanks for your help
Hi Paul
You have great sites, thank’s to them.
I have problem with writing arrays in excel sheet: “not enough memory”.
Value reading in ‘jagged array’ works fine.
I can ‘work-around’ this with two simultaneous loop but it works too slow to my needs.
Can you give any tips how to tackle this problem.
-timppa-
Vba code looks like:
Sub WriteBinaryValuesTest()
Dim T() as Variant
Dim A() as Long
Dim fileNo as Integer
Dim F(2) as String
Dim R as Range
F(0)=”C:\BinaryFileA.bin” ‘ size is 8784 long type value
F(1)=”C:\BinaryFileB.bin” ‘ size is 8784 long type value
ReDim T(2)
ReDim A(8784)
fileNo = FreeFile
Open F(0) For Binary Lock Read As #fileNo
Get #fileNo, , A
Close #fileNo
T(0) = A
ReDim A(8784)
fileNo = FreeFile
Open F(1) For Binary Lock Read As #fileNo
Get #fileNo, , A
Close #fileNo
T(1) = A
Workbooks.Add
Set R = Range(cells(1,1),cells(8784,2))
R.Value = T
…..
Arrays are amazing! Just used them and macro which would take 50 mins to run (without arrays) does the job within secs!
That’s a significant difference.
Hello, Professor!
In the text you said “The array created by the Array Function will start at index zero unless you use Option Base 1 at the top of your module. Then it will start at index one.” But in my case it started at index 1 when aplied to a range, and I didnt use option base 1. So maybe the text should be complemented.
My bad. forget what i said. So sorry. I didnt use de Array Function: Dim arr as Variant: arr = Selection. No Array Function at all for sure. Really sorry.