The Complete Guide to Using Arrays in Excel VBA

VBA Arrays

“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.

 

A Quick Guide to VBA Arrays

TaskStatic ArrayDynamic Array
DeclareDim arr(0 To 5) As Long Dim arr() As Long
Dim arr As Variant
Set SizeSee Declare aboveReDim arr(0 To 5)As Variant
Get Size(number of items)See ArraySize function below.See ArraySize function below.
Increase size (keep existing data)Dynamic OnlyReDim Preserve arr(0 To 6)
Set valuesarr(1) = 22arr(1) = 22
Receive valuestotal = arr(1)total = arr(1)
First positionLBound(arr)LBound(arr)
Last positionUbound(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 itemsDim item As Variant
For Each item In arr
Next item
Dim item As Variant
For Each item In arr
Next item
Pass to SubSub MySub(ByRef arr() As String)Sub MySub(ByRef arr() As String)
Return from FunctionFunction 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 FunctionDynamic onlyDim arr() As Long
Arr = GetArray()
Erase arrayErase arr
*Resets all values to default
Erase arr
*Deletes array
String to arrayDynamic onlyDim arr As Variant
arr = Split("James:Earl:Jones",":")
Array to stringDim sName As String
sName = Join(arr, ":")
Dim sName As String
sName = Join(arr, ":")
Fill with valuesDynamic onlyDim arr As Variant
arr = Array("John", "Hazel", "Fred")
Range to ArrayDynamic onlyDim arr As Variant
arr = Range("A1:D2")
Array to RangeSame 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.)

 
 

Download the Source Code and Data

Please click on the button below to get the fully documented source code for this article.
 
 


 
 

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

VBa Arrays

Student Marks

 
 
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)

ImmediateWindow

 
 
ImmediateSampeText

 
 
As you can see in the following example we are writing the same code five times – once for each student

Public Sub StudentMarks()

    ' Get the worksheet called "Marks"
    Dim sh As Worksheet
    Set sh = ThisWorkbook.Worksheets("Marks")
    
    ' 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 = sh.Range("C" & 3)
    Student2 = sh.Range("C" & 4)
    Student3 = sh.Range("C" & 5)
    Student4 = sh.Range("C" & 6)
    Student5 = sh.Range("C" & 7)

    ' Print student marks
    Debug.Print "Students Marks"
    Debug.Print Student1
    Debug.Print Student2
    Debug.Print Student3
    Debug.Print Student4
    Debug.Print Student5

End Sub

 
 
The following is the output from the example

VBA Arrays

Output

 
 
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

' ExcelMacroMastery.com
' https://excelmacromastery.com/excel-vba-array/
' Author: Paul Kelly
' Description: Reads marks to an Array and write
' the array to the Immediate Window(Ctrl + G)
' TO RUN: Click in the sub and press F5
Public Sub StudentMarksArr()

    ' Get the worksheet called "Marks"
    Dim sh As Worksheet
    Set sh = ThisWorkbook.Worksheets("Marks")

    ' Declare an array to hold marks for 5 students
    Dim Students(1 To 5) As Long

    ' Read student marks from cells C3:C7 into array
    ' Offset counts rows from cell C2.
    ' e.g. i=1 is C2 plus 1 row which is C3
    '      i=2 is C2 plus 2 rows which is C4
    Dim i As Integer
    For i = 1 To 5
        Students(i) = sh.Range("C2").Offset(i).Value
    Next i

    ' Print student marks from the array to the Immediate Window
    Debug.Print "Students Marks"
    For i = LBound(Students) To UBound(Students)
        Debug.Print Students(i)
    Next i

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

  1. Static – an array of fixed size.
  2. 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 arrMarks3(1 To 5) As Long

    ' Create array with locations 2,3,4 ' This is rarely used
    Dim arrMarks4(2 To 4) As Long

End Sub

 
 

VBA Arrays

An Array of 0 to 3

 
 
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 the 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

 
 

VBA Array 2

The array with values assigned

 
 
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.

 

Get the Array Size

There is no native function for getting the number of items in an array. I created the ArraySize function below to return the number of item in any array no matter how many dimensions:

' Name: ArraySize()
' Author: Paul Kelly, ExcelMacroMastery.com
' Description: Returns the number of items in an array (includes
'               multi-dimensional arrays)
' The function raises an error if the argument is not an array
Function ArraySize(arr As Variant) As Long

    On Error Goto eh
    
    Dim i As Long
    ' Loop is used for multidimensional arrays
    Do While True
        i = i + 1
        ArraySize = IIf(ArraySize = 0, 1, ArraySize) _
                        * (UBound(arr, i) - LBound(arr, i) + 1)
    Loop

Done:
    Exit Function
eh:
    If Err.Number = 13 Then ' Type Mismatch Error
        Err.Raise vbObjectError, "ArraySize" _
            , "The argument passed to the ArraySize function is not an array."
    End If
End Function

 
You can use it like this:

' Name: TEST_ArraySize
' Author: Paul Kelly, ExcelMacroMastery.com
' Description: Tests the ArraySize functions and writes
'              the results to the Immediate Window(Ctrl + G)
Sub TEST_ArraySize()
    
    ' 0 items
    Dim arr1() As Long
    Debug.Print ArraySize(arr1)
    
    ' 10 items
    Dim arr2(0 To 9) As Long
    Debug.Print ArraySize(arr2)
    
    ' 18 items
    Dim arr3(0 To 5, 1 To 3) As Long
    Debug.Print ArraySize(arr3)
    
    ' Option base 0: 144 items
    ' Option base 1: 50 items
    Dim arr4(1, 5, 5, 0 To 1) As Long
    Debug.Print ArraySize(arr4)
    
End Sub

 

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)

 
 

Arrays VBA

Contents of arr1 after using the Array function

 
 
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, ",")

 
 

Arrays VBA

The array after using Split


 
 

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”.

VBA Preserve

Before ReDim Preserve


 
 
VBA 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.

 
 
VBA Array Dimension

 
 
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:

VBA Arrays

 
 
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

 
 

VBA 2D Array

Sample Student data

 
 

VBA 2D Array Output

Output from sample data

 
 
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

  1. Arrays are an efficient way of storing a list of items of the same type.
  2. You can access an array item directly using the number of the location which is known as the subscript or index.
  3. The common error “Subscript out of Range” is caused by accessing a location that does not exist.
  4. There are two types of arrays: Static and Dynamic.
  5. Static is used when the size of the array is always the same.
  6. Dynamic arrays allow you to determine the size of an array at run time.
  7. LBound and UBound provide a safe way of find the smallest and largest subscripts of the array.
  8. The basic array is one dimensional. You can also have multi dimensional arrays.
  9. You can only pass an array to a procedure using ByRef. You do this like this: ByRef arr() as long.
  10. You can return an array from a function but the array, it is assigned to, must not be currently allocated.
  11. A worksheet with its rows and columns is essentially a two dimensional array.
  12. You can read directly from a worksheet range into a two dimensional array in just one line of code.
  13. 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

 
 

255 comments

  1. Hi Paul. I have been trying unsuccessfully in VBA to declare an array of worksheets, not just the worksheet names, and then use the worksheet.copy function to create a new workbook with the group of worksheets. I’m unable to declare the array of type worksheet instead of variant. I wanted to also populate the array in one go with the array function. The following VBA code does what I want but not in the way I would like it to:
    Option Explicit
    Option Base 1
    Private Sub Workbook_SheetBeforeDoubleClick(ByVal Sh As Object, ByVal Target As Range, Cancel As Boolean)
    Dim wbkThis As Workbook
    Dim wstX As Worksheet
    Dim wstY As Worksheet
    Dim wstZ As Worksheet
    Dim arrWSA As Variant
    Dim arrWSB() As Variant
    Dim arrWSC(1 To 3) As Variant

    Cancel = True

    Set wbkThis = ThisWorkbook
    Set wstX = wbkThis.Worksheets(“SheetX”)
    Set wstY = wbkThis.Worksheets(“SheetY”)
    Set wstZ = wbkThis.Worksheets(“SheetZ”)
    ReDim arrWSA(1 To 3) As Variant
    ReDim arrWSB(1 To 3) As Variant

    arrWSA = Array(wstX, wstY, wstZ)
    arrWSB = Array(wstX.Name, wstY.Name, wstZ.Name)
    arrWSC(1) = wstX.Name
    arrWSC(2) = wstY.Name
    arrWSC(3) = wstZ.Name

    arrWSA(1).Copy
    Worksheets(arrWSB()).Copy
    Worksheets(arrWSC()).Copy
    End Sub

    1. You can create an array of worksheets like this:

      ' create array
      Dim arr(1 To 3) As Worksheet
      ReDim arr(1 To ThisWorkbook.Worksheets.Count)
      
      ' add worksheets
      Dim i As Long
      For i = 1 To ThisWorkbook.Worksheets.Count
          Set arr(i) = ThisWorkbook.Worksheets(i)
      Next i
      
  2. Hi Paul ,
    Appreciate for your hard-work on every aspect of Marco step by step.
    Thank-you is not enough to express how helpful your web pages is for me.

    As a beginner , there is a puzzle in this Array post totally got me stuck for a “big” while.
    And here is the whole story :

    As I ran the code (Sorting Array) by F8 , I found something weird which is when the procedure involved itself into the function and processed it all done (processed until all being out of the conditions , and the highlighted was at the end of line : End Sub).

    Somehow , after I kept clicking the F8 , it went back to the last If line twice and sneakingly increased the values up to meet the if condition entering the sub once again and completed the swap , which should’ve not been finished in this way.

    Why’s that happened ? Is there something I missed ?
    Sincerely seeks a sensible explanation for this headache riddle.
    (Please excuse for my inarticulate typing)

    1. Hi Chuck,

      The QuickSort sub calls itself – this is known as recursion. This is why are seeing the behaviour that you described.

      Paul

      1. That is a completely new term for me !
        No wonder it looks like never-quit chapter playing on at that moment.
        BTW , what kinds of event or some particular codes could trigger this flow (recursion) ?

        P.S. New topic (Select case) of your website has been released recently and I tried my PW of registered account but ended up denial. Is there anything required or I should’ve done to earn the PW ?

        1. Hi Chuck,

          Recursion is when a sub calls itself. It is used for specific types of algorithms like sorting and moving through binary trees.

          Select Case is not available as it is not finished. It will be released this Friday.

          Paul

          1. Thanks for your patient & clear reply !
            What’s left by my side is to dig more into it and familiar with some related practical exercises.

            Got it ! I’m looking forward to your new post !

  3. Hi Paul!

    I’m kind of a novice to VBA and programming and general and I was wondering if an array would be a good solution to the following hypothetical:

    Say you are given an excel sheet with 10,000 lines. Each line has 3 columns, Date, Type of Fruit, and Shipping Location. You don’t know how many fruits there are or what type, but you know the three locations they can come from and chances are you will have lots of repeat fruits. I want to write a code that takes the list and prints out a list/report that looks like this:
    Date:
    6/12/2016
    Location:
    US
    Fruits and Number:
    Orange:100
    Apple:1500
    Peach: 1234
    etc etc

    Would an array be a wise choice? How would start this? In not an array what should I look into?

    Thanks,
    CJ

  4. Hey Paul,

    Thanks for the article! I am having trouble with this code. It compares between another sheets. in the locals it shows all of the correct values. But when it prints out the array to the sheet it just puts out all zeros:
    Sub arrayz()
    Application.ScreenUpdating = False

    Dim RPT004() As Variant
    Dim QOH_Con() As Variant
    Dim QOHtest(1 To 123472) As Variant

    Last_Row_QOH_Con = Application.WorksheetFunction.CountA(Sheets(“QOH_Con”).Range(“A:A”))
    Last_Row_RPT004 = Application.WorksheetFunction.CountA(Sheets(“RPT004”).Range(“A:A”))

    RPT004 = Sheets(“RPT004”).Range(“A1:L” & Last_Row_RPT004).Value
    QOH_Con = Sheets(“QOH_Con”).Range(“A1:C” & Last_Row_QOH_Con).Value

    For j = 2 To 123472
    Part = QOH_Con(j, 1)
    Customer = QOH_Con(j, 3)
    Count = 0
    For x = 2 To 39391 ‘
    If RPT004(x, 1) = Part And RPT004(x, 7) = Customer Then ‘
    Count = Count + RPT004(x, 3) ‘

    End If
    Next x
    QOHtest(j – 1) = Count
    Next j

    Sheets(“QOH_Con”).Range(Cells(2, 4), Cells(123472, 4)).Value = QOHtest
    Application.ScreenUpdating = True

    End Sub

  5. When writing code for macros, can an Array include not only specific worksheets that are spelled out: “Cash Flow”, “Financial Position”, etc., but a range of worksheets that are next to each other? In other words, the Array would include all worksheets between “Sales of AAA” and “Sales of ZZZ”? So the final code would include both specified worksheets and the range of worksheets.

    1. Hi Steve,

      You could do it as a 2D array where the first column is the worksheet and the other columns are the adjacent worksheets.

      It would be better to have a Dictionary where the worksheet is the key and the value is a collection of adjacent worksheets.
      It’s not a simple thing to do if you are a beginner.

      -Paul

  6. Hi Paul,

    I have a question on array. When applying back the result to a filtered range in sheet the array breaks. How can we rectify this.

    Thanks,
    Prabhu Murugan

    1. Hi Prabhu,

      I’m not clear on your question.

      You cannot assign an array to a filtered range. You would need to delete all the records and then assign the array.

      -Paul

  7. Hi Paul,
    I developed this code that opens Master file of (let’s say 20,000 records) and I need to update this file daily with a transaction file of (let’s say 1,000 records). but when I timed it, it takes over 2 hrs to run ?!?! How can I speed this up? I’ve optimized the best I could but it still takes over 2 hrs?
    Sub UpdMstrfromDlyTx()
    ‘same as Tst_ClsdWrkBk() – WORKS!!
    Dim aClm, cClm, aDte, cDte, dDte, fOHAP As String
    Dim aRow, cRow, aLstRow, cLstRow As Integer
    Dim myfile As Variant
    Dim aWB, cWB As Workbook

    ‘ select Daily File MsgBox ActiveWorkbook.FullName ‘get Actve WrkBk you are working on
    fOHAP = Application.GetOpenFilename(“Excel Files (*.xls*),*.xls*”, , “Choose a File to Load”, “Open”, False)

    myfile = MsgBox(“You’ve chosen ” & fOHAP & ” created ” & FileDateTime(fOHAP) & vbCrLf & vbCrLf & “Is this Correct?”, vbYesNo + vbQuestion)
    If myfile = vbNo Then Exit Sub

    ‘START THE CLOCK
    ActiveSheet.Range(“BD2”).Value = Format(Now(), “hh:mm:ss”)

    ‘turn off autoCalcs & screen updates
    Application.Calculation = xlCalculationManual
    Application.ScreenUpdating = False

    ‘ Continue & find the last row of this WorkSheet
    Set aWB = ThisWorkbook
    aLstRow = aWB.ActiveSheet.Cells(Rows.count, “A”).End(xlUp).row

    ‘ find the last row of Closed Sheet
    Set cWB = Workbooks.Open(fOHAP, True, True) ‘ True READ ONLY mode
    cLstRow = cWB.Sheets(1).Cells(Sheets(1).Rows.count, “A”).End(xlUp).row

    For aRow = 2 To aLstRow
    aDte = aWB.ActiveSheet.Range(“O” & aRow).Value ‘Date
    aClm = CStr(aWB.ActiveSheet.Range(“A” & aRow).Value) ‘Claim

    For cRow = 2 To cLstRow
    dDte = cWB.Sheets(1).Range(“F” & cRow).Value ‘Date
    cDte = CDate(dDte)
    cClm = CStr(cWB.Sheets(1).Range(“I” & cRow).Value) ‘Claim

    If Trim(aClm) = Trim(cClm) And aDte = cDte Then
    aWB.ActiveSheet.Range(“BE” & aRow).Value = cWB.Sheets(1).Range(“K” & cRow).Value
    Exit For ‘ exit when found
    Else
    aWB.ActiveSheet.Range(“BE” & aRow).Value = “No Subject”
    End If
    Next cRow

    Next aRow

    ‘ close Closed WrkBk
    cWB.Close False
    Set cWB = Nothing

    ‘ only calc Subject column BE
    ActiveSheet.UsedRange.Columns(“BE”).Calculate

    ‘turn on autoCalcs & screen updates
    Application.Calculation = xlCalculationAutomatic
    Application.ScreenUpdating = True

    ‘Done
    ActiveSheet.Range(“BD4”).Value = Format(Now(), “hh:mm:ss”)
    End Sub

    Hope you can help

  8. Hi Paul!
    Many thanks for your detailled work.
    I’d like to add different range to an array but don’t manage to do it even after a few hour of search.
    I need column B to G and S in the same array.

    It works for B to G but as soon as I had S to the range, the seventh expected row doesn’t appear.

    I imagine the code below with no success. Could you help me to find the solution?

    Dim lastRowRawPlanning
    Dim planningArray As Variant

    lastRowRawPlanning = Worksheets(“rawPlanning”).Cells(Rows.Count, 1).End(xlUp).Row

    planningArray = Worksheets(“rawPlanning”).Range(“B2:G” & lastRowRawPlanning & “,S2:S” & lastRowRawPlanning).Value

      1. Paul,

        So, the best way is to optimize the first range “import” and then loop through array in case of need.

        Many thanks for your answer.

        Sid

  9. Hi Paul Watched one of your youtube videos and was amazed how much I didn’t know.

    I have an Excel file that creates a PDF with 7 sheets but the PDF doesn’t “fit to page” so when you see it on the screen one page is massive the others are small. It all prints well assuming the user selects “fit” not “actual size” when printing but some customers don’t then it’s a nightmare. I use this code

    ActiveSheet.ExportAsFixedFormat Type:=xlTypePDF, Filename:= _
    m_Path & “Contracts\” & “Contract – ” & Range(“J6”) & “.pdf” _
    , Quality:=xlQualityStandard, IncludeDocProperties:=True, IgnorePrintAreas _
    :=False, OpenAfterPublish:=False

    More than happy to email you the file and to get a quote for your services if possible.

    Mike

  10. Thanks for providing this value lectures. Is there a way to assign a new row to array 2D from array 1D?

    arr1D(1) = “101,Jonh,9.0”
    arr1D(2) = “102,Sam,8.7”

    arr2D(9)= arr1D ‘

  11. Paul,

    I’ve successfully used the mass population of ranges into arrays, and back, in previous macros. This time, I created an array as a variant, populated with typical if-then-else logic as arr(I). But when I’m moving the array into the worksheet range, it seems as though only the first value in the array is populating the range: Every cell in range receives “Division”. I’ve “watched” the array and confirmed there are other values in the array. Have you seen this before?

    Public vAPMResLvl As Variant
    Public vAPMGrp As Variant
    Public rAPM As Range
    .
    .
    .
    If iPMDCol = 2 Then ‘ If processing a VP, create 2 APM rows (one for Direct Reports)
    iLoop = 2
    bDiv = True
    Else
    iLoop = 1
    bDiv = False
    End If

    For i = 1 To iLoop ‘ When processing for a VP, create a Div and Area APM row, else just an Area

    ReDim Preserve vAPMResLvl(LBound(vAPMResLvl) To UBound(vAPMResLvl) + 1)
    ReDim Preserve vAPMGrp(LBound(vAPMGrp) To UBound(vAPMGrp) + 1)

    If bDiv = True Then
    bDiv = False
    vAPMResLvl(UBound(vAPMResLvl)) = “DIVISION”
    vAPMGrp(UBound(vAPMGrp)) = Round(vAPMGrp(UBound(vAPMGrp) – 1) + 0.5, 0) ‘ Establish a new whole number for the next Division
    Else
    vAPMResLvl(UBound(vAPMResLvl)) = “AREA”
    vAPMGrp(UBound(vAPMGrp)) = vAPMGrp(UBound(vAPMGrp) – 1) + 0.00001
    End If

    Next i
    .
    .
    .
    ‘Publish the arrays to the XLSX
    Set rAPM = wsAPM.Range(“A4:A” & UBound(vAPMResLvl) + 3)
    rAPM.Value2 = vAPMResLvl

  12. Hi Paul,

    I am trying to read an array to a range. When I run my code directly from my procedure this works fine and the values in the array are written into my range. When I try to call this procedure through a function that is triggered by an event change on my sheet, I get Error 1004 at the point in the procedure where Range = Array. The function takes a range as the trigger, but is not used in the function. The function calls the procedure to copy the Array into the range.

  13. Hi Paul,

    Thanks for the explanation above. I am currently working on a project. I have a question on array.

    I want to convert values from 3 different textbox in VBA. All 3 textbox have same type of data. Which I need to select which one have the highest value and assign that highest value in another textbox.

    I am trying to assign an array to make it but it didn’t work.

    TB1: TextBox1
    TB2: TextBox2
    TB3: TextBox3

    TB_O: TextBox Overall

    The value in textbox that I am trying to assign:
    Dim S (1 to 8) as String
    S(1) = “0”
    S(2) = “a1”
    S(3) = “a2”
    S(4) = “1”
    S(5) = “2”
    S(6) = “3”
    S(7) = “4”
    S(8) = “X”

    I need to compare between the TB1, TB2 and TB3 and find the highest to put in TB_O. How can I make this work. Appreciate your help on this matter.

    Thanks,
    Arif

Leave a Reply

Your email address will not be published. Required fields are marked *