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
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 positionUbound(arr)Ubound(arr)
Last positionLBound(arr)LBound(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 but array
must be two dimensional
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.

 
 

Quick Notes

Sometimes Collections are a better option than arrays. You may want to check out my post The Ultimate Guide To Collections in Excel VBA.

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

    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

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

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

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

 
 

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

 
 

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.

 
 

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 it’s contents will be deleted.

In the following example, the second ReDim statement will create a completely new array. The original array and it’s 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 be bigger and start at the same dimension e.g.

We cannot Preserve from (0 to 2) to (1 to 3) or (2 to 10) as they are different starting dimensions.
We cannot Preserve from (0 to 2) to (0 to 1) or (0) as they are smaller than original array.

 
 
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.

 
 

 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: It is not possible to pass an array using ByVal.

' 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 column 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.

 
 
The following image shows two groups of data. The first is a one dimensional layout and the second is two dimensional.

 
 
dimensions

 
 
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(2 dimensional) you need to give the row AND the column. So you can think of 1 dimensional being rows only and 2 dimensional as being rows and columns.

Note: It is possible to have more 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 it’s 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.

 
 
I hope you enjoyed this post and found it beneficial. You may want to check out one of our most popular posts The Ultimate Guide to the VBA String

 
 

Arrays Cheat Sheet

 
 
Need Help Using Arrays? Click here to get your FREE Cheat Sheet

 
 
Note: I periodically archive comments to maintain the page speed.

104 comments

  1. Hello,

    Is it possible to have an array that will have different sizes of “columns” per “row”?
    Thanks.

    Ken

    1. Hi Ken,

      What you are looking for is called a Jagged array.
      You can have an array of arrays where the inner arrays are of different sizes. It can get messy. The following code shows how to do it.

      Sub JaggedArray()
      
          ' Declare main array
          Dim Class() As Variant
          ' Declare sub arrays
          Dim Students1() As String
          Dim Students2() As String
          Dim Students3() As String
          
          
          ReDim Class(0 To 2)
          ' Set the different sizes
          ReDim Students1(0 To 15)
          ReDim Students2(0 To 6)
          ReDim Students3(0 To 12)
          
          Class(0) = Students1
          Class(1) = Students2
          Class(2) = Students3
          
          ' Put row and column number into array
          Dim i As Long, j As Long
          For i = LBound(Class) To UBound(Class)
              For j = LBound(Class(i)) To UBound(Class(i))
                  Class(i)(j) = CStr(i) & ":" & CStr(j)
              Next j
          Next i
          
          ' Print out to worksheet called "Sheet1"
          For i = LBound(Class) To UBound(Class)
              For j = LBound(Class(i)) To UBound(Class(i))
                  Sheet1.Cells(i + 1, j + 2) = Class(i)(j)
              Next j
          Next i
      
      End Sub
      

      An alternative(easier) way is to put a value like -9999 in the cells you don’t need. When you read through the array add code to ignore any cells with this value.

      Regards
      Paul

  2. Hai
    i need help for vba code

    in module1 I declare the function with two arguments. for example in excel form, from a1:d1 I have data, at e3 to h3 i want to dispaly the conent of a1:d1. so I declare the function in module1. Now my question is how to declare the input argument as the range of cells. i.e., when executing the function at e3 cell, when i will type the funiction i.e., =DISPLAY(A1:D1)

    1. Hi Shankar,

      To declare the input argument you can use the Range type. See the following example

      Sub Test()
          ' Call the Display function with a range argument
          Display ActiveSheet.Range("A1:D1")
      End Sub
      
      Sub Display(rg As Range)
          
      End Sub
      

      For more on passing arguments see Sub and Functions: Passing arguments

  3. Thank you Paul,
    I can’t tell you how much this article alone has helped me in my VBA development skill level. 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

  4. Hi Paul,

    I have multidimensional array with thousands of elements. I need to go through this array many times and each time calculate sum of some of its elements (each time different obviously). I did it with a loop but my question is is this possible to use some kind of “select * from table” just like with SQL and save some time not using loops?

    Regards
    SPK

    1. Hi Spk,

      There’s nothing like that for VBA. However, you can use the worksheet functions on values in cells. So you could use Sum or SumIf. for example
      [sourcecode language=””]
      WorksheetFunction.Sum (Range("A1:A5"))
      [/sourcecode]

      There is a Filter function for arrays but it only works on one dimensional arrays.

      Regards
      Paul

  5. I would like to fill a twodimensional array with values.
    Please explain to me what I am doing wrong.

    Dim Translate(3,2)

    TransLate(1) = Array(“Dog”,”Perro”)
    TransLate(2) = Array(“Cat”,”Cato”)

    Thank you very much.

    1. Hi Johannes,

      You declare Translate as a one dimensional array. The Array function then creates a new array at each position.

      Dim Translate(1 To 2) As Variant
      
      Translate(1) = Array("Dog", "Perro")
      Translate(2) = Array("Cat", "Cato")
      

      Regards
      Paul

  6. Hi Paul,

    Excellent post. Kindly provide more info about the book, I couldn’t find the table of contents.
    Thank you

  7. Hi Paul!

    Congratulations on your work, the content of your website is very helpful for the ones who want to learn vba like myself.

    My question is about arrays vs collections, which i’m very new at. Let’s say that i have two workbooks: one containing lots of data, and another one that will function as a display of that info. Considering your posts on arrays and collections, it would be best to use collections on this particular case?

    Thanks.

    1. Hi Eduardo,

      Thanks for your comment. If you are dealing with a large amount of data then arrays are the way to go. They are also best if you are moving a range of values from one area to another.

      Collections are useful when you don’t know the number of items in advance. In other words, when you will be adding one item at a time.

      Regards
      Paul

  8. Hi Paul,

    I want to replace data of 10,000 cells in a column. Currently data is in format “30/01/2015 12:00:00 a.m.”, i want to keep dates in format “30/11/2015”. Currently i am using for loop & it is taking lot of time.

    Kindly help me with array.

    Imran

    1. Hi Imran,

      You can use an array to change the data as follows.

      Dim arr As Variant
      ' Range range values to array
      arr = Sheet1.Range("A1:A10000")
          
      Dim i As Long, j As Long
      ' Change values in array
      For i = LBound(arr) To UBound(arr)
          arr(i, 1) = Left(arr(i, 1), 10)
      Next i
      
      ' Writte array values to range
      Sheet1.Range("A1:A10000") = arr
      
  9. Hi Paul,

    Excellent tutorial, thanks!

    Is there any way to populate an array in just one line, rather than going item by item? I’m trying the following:

    Dim numbers(3) As Integer
    numbers = {1,2,4,5}

  10. Hi Paul,

    Thanks for the solution. The contents are very nice & helpful for beginners like me.

    I have written a macro using loop to calculate total sales based on multiple conditions, as the volume of data is very large it takes more than 15-20 minutes to get the desire output.

    Can we do it using arrays. I have complete data of customer invoices with the following fields (Invoice number, Customer number, date, amount, category, purchase order number etc..)

    I wan to get total sales by customer & category (for eg, customer x cagtegory A & so on…)

    Your help is really appreciated.

    1. You can use sumif like this

      Dim rg As Range
      Set rg = Sheet2.Range("a1:f20")
      With Sheet2
          Debug.Print WorksheetFunction.SumIf(rg, "John", rg.Columns(2))
      End With
      
  11. hi Paul, can i ask the reason why you use 2 here but not worry about 1? so for a 2 dimensional, the 2nd loop only use the 2nd dimension?

    can i also ask: i have seens a spreadsheet which is used to import annual accounting value, and each time before importing it will clear all historical database, but it seems it has vba codes storing the previous value in array before clearing so it becomes a data warehouse. is that the way array always can be used? and it also overwrite previous data after importing the new values.

    thanks so much

    Jane

    1. Hi Jane,

      1 is the default so you don’t need to use it. The following two lines are equivalent

      UBound(arr)
      UBound(arr, 1)

      I’m not 100% clear about your second question. Storing data in a array means having it in memory while the macro runs. Once the Macro finishes the array data will be gone.
      So it sounds like the Macro will be using the data for something.

  12. hi Paul,just a finding: i find we need to add.value after the range for array to be set up if no.value is inserted there is a type mismatch. also i tested found if we have sheets…range.. then we need to have .value to set the array, but when we only have range(ie no sheets before that) we can set array= without putting.value. is that correct?

    Jane

    1. You only need value when assigning between ranges with more than one cell.

      Range(“D1:D7”) = Range(“A1:A7”).Value

      If you no sheets before range it is referring to the ActiveSheet i.e. ActiveSheet.Range

  13. Many thanks, Paul.
    Everything is working when comparing the macro with the built in function in excel I get the same results. 🙂
    This worked out absolutly perfect, you are the best.

  14. Paul

    interested to know if there are any techniques for applying math to a whole array or doing the same by using other structures instead of arrays

    eg:
    ‘very simple example
    Dim arr As Variant, arr2 as variant
    arr = Sheet1.Range(“A1:A10000”)
    arr2=int(arr+0.5)

    1. Hi Hui,

      You can use evaluate like this

      Dim arr As Variant
      arr = Evaluate(Sheet1.Range(“A1:A10000”).Address & “+0.5”)

      Regards
      Paul

      1. Thanx Paul

        That is 3 times slower than loading the range into an Array, looping through the array and writing it back, but worth the try
        0.12 seconds using Evaluate compared to 0.04 seconds load/loop/write which for 95,000 records, I should be happy with anyway

        Hui…

  15. Hi Paul,

    I am new to VBA and looking to create a dynamic array. This array will contain a text string with 13 digits. I need to pass the first two digits to one column in a different sheet and the last 11 to another column. Any help will be greatly appreciated. I realize this should be easy.

    Thanks

    1. Hi Jason,

      You can use the code in the Sections above to create a dynamic array.

      To parse the string is pretty easy – you can use Left, Mid and Right
      see more about them here

      sLeftSide = Left(sText,2)
      sRightSide = Right(sText,11)

      Hope this helps.
      Paul

  16. Hi Paul

    In your article, you said For Each loop will not change array’s value. But in your “super speed” part, you used For Each loop to update array’s values. Could you explain it a little bit more? Or i can only use double loop to update array?
    Thanks.

    1. Hi Marcus,

      The first piece of code in the “Super Speed” should be a for loop rather than a for each loop. I’ve updated the code. You can use a For or nested For(double loop) depending on your requirements.

      A For Each loop is read-only because the For Each variable is a pointer to the array item. You cannot change the value of the variable but you can change a property.

      Dim c As Variant
      For Each c In Sheet1.Range("A1:A10")
          ' DOES NOT change the value
          c = 6
          ' CHANGES the value
          c.Value = 6
      Next c
      
  17. Hi Paul, this is an excellent post about arrays.
    I have a question for you in regards to arrays. When passing an array from a function to the main sub, is there a limitation on the number of element that the array can have? I’m using Excel 2010 and 2013.

    Thanks.

    1. When you’re passing an there should be no issue once the original is under the limitations. This limits are: “about 500MB for 32-bit VBA and about 4GB for 64-bit VBA (Excel 2010-64).” – source.

    2. When you’re passing an there should be no issue once the original is under the limitations. This limits are: “about 500MB for 32-bit VBA and about 4GB for 64-bit VBA (Excel 2010-64).” – source.

  18. Hi!
    Can you help me to resolve such an issue: could I copy the cell BACK COLOR (not value) from worksheet to array and vice versa by range (not by single cell, wich is toooo slow)? Thanx!

  19. Hi Paul,

    what is the simplest way to find out my last column with data (not empty) ..lets say in the first row.
    Thanks!

  20. I have a query related with Sort in Asc order.

    Lets say Column A contains some number. I want the sorting of this Column A in Column D?

    Do not want to change the Value of column A.

    Please suggest and Thanks in Advance

    1. Hi Ricky,

      This will sort the values in column A and write the result to column D.

      Sub SortArray()
      
          Dim arr As Variant, val As Variant
          arr = Sheet1.Range("A1:A20").Value
      
          Dim i As Long, j As Long
          For i = LBound(arr, 1) To UBound(arr, 1) - 1
              For j = i + 1 To UBound(arr, 1)
                     If arr(i, 1) > arr(j, 1) Then
                          val = arr(i, 1)
                          arr(i, 1) = arr(j, 1)
                          arr(j, 1) = val
                     End If
              Next j
          Next i
          
          Sheet1.Range("D1:D20").Value = arr
          
      End Sub
      
  21. Write a program that automatically sums the rows, columns, and diagonals of a 5 × 5 magic square.

    Can you help please?

    Thanks in Advance

    1. Hi Ritmic,

      I’ve calculated the rows and columns in the example below. You just need to add the calculation for the diagonals.

      Dim rg As Range
      Set rg = Sheet1.Range("A1:E5")
      
      Dim rgLine As Range
      ' Calculate columns
      For Each rgLine In rg.Columns
          Debug.Print WorksheetFunction.Sum(rgLine)
      Next
      
      ' Calculate rows
      For Each rgLine In rg.Rows
          Debug.Print WorksheetFunction.Sum(rgLine)
      Next
      
  22. Hi,

    First, thanks for the great tutorial.

    Quick question on the final example, you are dealing with a range a1:z20000, but in your array calc you seem to just edit the first column, is this is deliberate?
    In reality would we map in the whole range if only wanting to multiply the numbers in the first column of the range?

    thanks

    1. Hi Jack,

      Yes, it’s just an example. In real world code you would only take the range you were going to update.

      Paul

  23. Hello Paul,

    Thanks for the tutorial.

    Please suggest.

    VBA Command To Import XML File from Website to Text file (Create new text file(.txt) on local system) with some format like comma(,)?

    Many Thanks in Advance

    1. Hi Nick,

      There isn’t a simple answer to this. If the data is on a webpage you need to connect to the page and read the data. If you have a connection to the website then copy the file first and then convert on the local machine.

  24. Dear Paul,

    Thank you for making this very informative guide; it has been very helpful. I am struggling with the syntax of a bit of coding at the moment and was wondering if you could help me at all.

    For each account number (Column A), I want to add up all their quantities purchased (Column B) to give me the total amount owned, by account, in another column (Column C). Basically, a SumIf function is perfect for this. However when used over 100,000 rows, it is pretty slow. I am hoping to speed it up by using arrays and nested functions. Would you have any advice on how to structure such a sub in VBA?

    Thank you so much,

    Stephen

    1. Hi Stephen,

      For this particular application a Dictionary would be better. Each time you read an account number you need to see if you have already read it and it not then you want to add it. If you check out this example you will see it is similar to what you are trying to do.

  25. Hi, Paul

    Excellent work with your guide – congratulations. I appreciate the most the fact that it’s structured in a very readable way – for example the “task table” at the beginning of your posts is pure gold, it tells you everything you need to know in just a few lines. Many thanks for this!

    I have a question though: I’m trying to decide whether to use a collection or an array for storing the sheet names for further use in my code. Now I’ve experienced the power and the speed of arrays in VBA, so my question is … is storing the sheet names as a collection comparable in speed with storing it as an array? Or the array wins this “battle” too?

    1. Hi Yin,

      Glad you like the blog posts and the Task tables. To answer your question – An array is normally used when you know the number of items in advance e.g. 100 rows of data. A collection is better when you don’t know the size is advance e.g. Add only rows where customer city is New York.

      Speed is only an issue when you have a very large number of items and possibly if you have a slow pc/network.

  26. Hello Nick

    I have an array of data (allergens) and want to make bold any text that is in the array in a number of different spreadsheets. I am fine with doing this a sheet at a time, so have no need to loop through sheets. However, I seem to be going round in circles!

    This is how I start:

    Dim allArray As Varient
    Dim i As Long
    allArray = Array(“Wheat”, “Celery”, Wheat Gluten”, “Oats”)
    ‘ currently 23 items in this array
    For i =LBound(allArray) To UBound(allArray)

    and now all I want to do is make bold any string in an active worksheet bold if it is in the array.

    Hopefully someone can point me in the right direction!!!

    Many thanks

    1. Hi Gary,

      I would loop through the worksheet and then check the array(a Dictionary would be better for this).

      Sub MakeBold()
      
          Dim dict As Object
          Set dict = CreateObject("Scripting.Dictionary")
          dict("A") = 1
          
          Dim sItem As String, i As Long
          ' Go through sheet
          For i = 1 To 100
              sItem = Sheet1.Range("A" & i)
              ' Check exists in a dictionary
              If dict.Exists(sItem) Then
                  Sheet1.Range("A" & i).Font.Bold = True
              End If
          Next
      
      End Sub
      
  27. Hi Paul,

    I’ve got following problem:

    I have an array1(2,6) filled with some values.

    I need to rearrange it and copy it to array2(6,2)…

    Can I copy first 2 elements of array1 and paste it to array2 starting at first elements.
    After that copy next 3 elements of array1 and past it to array2 starting at first empty location (in this case 2nd element of array2) and son on as showed below:

    array1
    1 2 3 4 5 6
    7 8 9 10 11 12

    array2

    1 2
    3 4 5
    6 7 8
    9 10
    11 12

    Thanks in advance.

    1. Hi Lukasz,

      Your new array needs to be (6,3). If you were doing a simple transpose you could do this

      Dim arr As Variant
      arr = Sheet1.Range("A1:F2")
      
      Dim arr2 As Variant
      arr2 = WorksheetFunction.Transpose(arr)
      

       
      As your new array can have two or three elements you need to copy them one at a time.

  28. Hi,
    Thank you for your replay….

    Actually my real initial array is (4500, 170) and I have to transpose it to (18000,50)
    I have already done sth like this but using two ranges in worksheets.
    For that reason I have created a For Loop in which I call 7 times copy procedure which looks sth like this:
    z = z + 1
    RangeNameSource = “DL” & k & “:EG” & k
    Worksheets(“Dest”).Range(RangeNameSource).Copy _
    Destination:=Worksheets(“Dest”).Range(“C” & z & “:X” & z)
    as you can see at this location I am copying 22 Elements at once. I do so 7 time with different number of elements and so I am able to rearrange single row from my SourceArray (170 Elements) with only 7 copy procedures.

    And it’s working fine but it takes up to 3 minutes to finish its job. So little bit too slow : )
    So you mean in case of arrays I cannot copy twenty elements and copy it at once but have to copy every single element separately, right? This is 4500 x 170 = 765000 times, right? However I’m sure it still will be much faster as my previous idea.
    Thanks.

  29. Hi Paul K.

    Use of the idea in the example below works great for a column range (i.e. “A1:A3”) but is not working as expected for a row range (“A1:C1”). Instead it reads only the first cell into the array, and indeed, LBOUND=UBOUND=1. Perplexed.

    :::my code snippet follows yours
    Paul P.

    >>>>your sample code>>>>
    Public Sub ReadToArray()

    ‘ Create 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

    >>>>my non-working code>>>>

    Dim src As Excel.Workbook
    Dim searchRange As Excel.Range

    Set src = Workbooks.Open(“C:VisioDataTestArrayBook.xlsx”, True, True)

    Set searchRange = src.Worksheets(1).Range(“A1:C1”) ‘this does not
    ‘ work – but “A1:A3” does?

    Dim strArray() As Variant
    strArray = searchRange.Value

    Debug.Print LBound(strArray)
    Debug.Print UBound(strArray)

    For i = 1 To UBound(strArray)
    Debug.Print strArray(i, i), i
    Next i

    1. Hi Mr. Paul Kelly, could you help me please with my problem how can I write this excel formula “=If(C4=E4,”YES”,”NO”) and so on “=If(C170397=E170397,”YES”,”NO”) in VBA code.

      Thanks.

          1. For i = 2 To 7
            Range(“C” & i) = IIf(Range(“A” & i) = Range(“B” & i), “Yes”, “No”)
            Next

  30. I have a question about passing filtered area to an array, which means I only want visible cells to be put into an array.
    How I solve it is adding worksheet on the fly, using SpecialCells property to copy visible cells to the worksheet and putting them into my array again (and deleting the worksheet afterwards of course).
    Do you know a way of doing this without creating additional worksheet?

    1. Hi Tomek,

      There is no simple way. You can read the range areas into arrays and then create a function to merge the arrays

      Dim rg As Range
      Set rg = Sheet1.Range("D5:e9").SpecialCells(xlCellTypeVisible)
      
      Dim mainarr As Variant, arr As Variant
      
      ' Go through the range areas
      For Each rgCur In rg.Areas
          ' Put current area in array
          arr = rgCur.Value
          ' Merge array to new array
          mainarr = MergeArrays(mainarr, arr)
      Next
      
      Function MargeArrays(mainarr As varaiant, arr As variant) As Variant
          ' create merge array code here
      End Function
      
      1. Hi Paul
        Thanks for publishing this tutorial. I found and modified the sub below that I think addresses Tomek’s question. I put a timer on it to test it’s speed, but it’s obviously not needed.
        ‘###############
        Sub ToArray()
        ‘puts non-contiguous range into array, then back to defined range

        Dim arr() As Variant, R As Long, nr As Long
        Dim ar As Range, C As Range, cnum As Long, rnum As Long
        Dim col As Range

        starttime = Timer
        Set rng = Range(“A1:H199”).SpecialCells(xlCellTypeVisible)
        ‘ nr = Rng.Areas(1).Rows.Count
        ‘ ReDim arr(1 To nr, 1 To Rng.Cells.Count / nr)
        nr = 199
        ReDim arr(1 To nr, 1 To 5)
        cnum = 0
        For Each ar In rng.Areas
        For Each col In ar.Columns
        cnum = cnum + 1
        rnum = 1
        For Each C In col.Cells
        arr(rnum, cnum) = C.Value
        rnum = rnum + 1
        Next C
        Next col
        Next ar
        Range(“J1:N199”) = arr
        endtime = Timer
        MsgBox Format(endtime – starttime, “0.000000” & ” secs”)
        End Sub
        ‘##################
        Also, I have been searching for a solution to the ability to rearrange data once inside the array. For example, if I read a range into an array:
        ‘########
        Dim x As Variant
        X = Range(“A1:D20”).Value
        ‘########
        It’s pretty easy to read the array back to a specified range and I suppose I could build arrays for each column in order to read them back in a different columnar order. But what I would really like to be able to do is to rearrange the data in the columns WITHIN the X ARRAY so that when it is read back to the range, it might look like: Range(“B1:B20, A1:A20, D1:D20, C1:C20”) = NewX, where NewX was populated by X. Hope the marco helps and any suggestion on my desire to rearrange the array before printing back to the range is appreciated.

  31. Hi Paul,
    I have some problem to standardize data to each category,
    the example listed as below,
    row 1 column A, data 6
    row 2 column B, data 9
    how can I get each cell z-score{(x-average(AA))/stdev(AA)} by using array?
    A B C
    1 6 7 AA
    2 3 9 AA
    3 4 10 BB
    4 5 8 CC
    5 6 7 AA
    6 7 6 BB
    7 8 3 AA
    8 7 4 CC

    Many thanks.

    1. Hi Leo,

      There isn’t a simple way to do this. You need to read through the rows and add the values to an array.
      You can then pass this array to WorksheetFunction.StDev to calculate the stdev.

    1. Hi Patrick,

      For what he is doing the code is pretty okay.

      I think a better approach would be to delete the table and recreate it from the array. Then you don’t need to delete any rows from the table or create and fill a second array.

      If you have further questions you can email me at Paul at ExcelMacroMastery.com

  32. Hi Poul is it possible to assign a range e.g. A1:A10 to a collection just like a array
    and is it possible to write a collection right back to sheet/range like ve do with array’s
    Cus i wander if this is faster than do it in a loop/ maby if collection was converted to a array first ?

    1. Hi Poul,

      You can only Assign a range to and from an array. You cannot do it with a Collection.
      You to convert to an array from a collection to do either of these tasks.

      Paul

  33. I’m in the current situation:

    Sheet1 is a survey that I am going to print out hundreds of time.
    Each survey needs to have a “SurveyID” in Cell B28.
    I have a list of random SurveyID numbers I created in column A on Sheet2.

    Is there any way to reference my list of random numbers as I print (sort of like a mail merge) so I do not have to physically change the number for each survey I print?

    1. Hi Thomas,

      You could use a loop that copies the number to the surveyid and then prints the sheet. Then moves onto the next one etc.

      If you want to do a mail merge you’ll need to have the survey in Word but you can read data from excel.

      Paul

  34. Hi Paul,
    Great post very helpful howeever I can’t seem to find the solution to my problem. Basically I have an array of 2*207, first row goes from 1 to 207 , each number representing a stock. The second row are all zeros except for the stock I use to calculate the standard deviation of a portoflio. For example I want to pick 30 random stock number (I can do that without problem) but I want them to auto fill in my second column of my array in order to automate my formula. If I choose randomly stock 1 to 30 for example, the weight is 1/30 for each stock so I want that weight to be fill in in my array by itself without having to change the weight of each stock manually every time. Hope my text is clear,

    Thank you for your time,

  35. This is so readable and easy to understand! I use macros for engineering and personal excel tasks but don’t do it full-time so I stumble a lot. You would probably cringe at some of my code that I brute-forced because it’s all I knew how to do. I love using Excel macros to make life/work easier and more efficient and your posts are such an incredible help. Thank you!!

  36. Hi Paul

    I have 3 arrays , each has one dimension : Arr1(5) , Arr2(8), Arr3(7) , i am looking to merge them as one Arr4(20) , how to do that ?

    Thank you

      1. I am sorry but i am not understanding, would you show me an example , please !

        Hi Paul
        I have 3 arrays , each has one dimension : Arr1(5) , Arr2(8), Arr3(7) , i am looking to merge them as one Arr4(20) , how to do that ?

        Hi Dominique,
        You need to use three for loops. One for each array.
        Add first array to Arr4 positions 1 to 5.
        Paul
        Thank you

  37. Hi Paul,

    Let’s say I have a workbook “Tender.xlsm” with a worksheet named “source”
    In Column A (starting in A3) there are integers from 1 to 120, but with some omissions.
    In Column AW there are decimal values for each position.

    I want to transfer all these values to another workbook named “Customer.xlsx” with a worksheet named “target”. Here I have also integers from 1 to 120 in column A, but with no omissions.
    My values should be written to column K.

    How can I create a dynamic two dimensional array and write back my values in the propriate cells in my “target” sheet?

  38. Hi Paul,

    I am trying to store the values from certain range in an array and trying to read it. Below is the code
    Sub ArrayCountry()
    Dim i As Byte
    Dim LastRow As Byte

    With Sheet5
    LastRow = .Cells(Rows.Count, 1).End(xlUp).Row

    Dim arr(1 To LastRow) As String

    For i = 1 To LastRow
    arr(i) = .Range(“A1”).Offset(i)
    Next i

    For i = LBound(arr) To UBound(arr)
    Debug.Print arr(i)
    Next i

    End With

    End Sub

    But it throws an error “Constant Expression Required.” when I am trying to get the number of last row.

    Thank you.

  39. Greetings,

    As a beginner, this Article is really helpful.

    I have a problem though, if you can give me any clarity towards understanding it, that would be deeply appreciated.
    I have a number of workbooks (each representing a day) with variable number of items (rows) and fixed number of criteria (columns), and I am trying to get all that information to an output workbook, each column (criteria) would be a worksheet (tab), and in each of them I would have the items as rows and the days as columns.
    My current code does everything with cells directly, using vlookup, and that takes a large amount of time, so I am trying to use arrays. Can I get the information of each workbook, assign it to an array, retrieve the first column (item identifier) and then create a new array with those items? Can I do that in a loop, adding to the end of this array as new items appear?
    If that is the case, after I get this second array with the item (identifiers), can I use it to vlookup or match with the information in the original arrays, to get the column info (and output it to excel)? Is there a better way than vlookup?

    Regards, and thanks in advance.

  40. hello,
    i have a question
    how can i cheak if one veriable is bigger than all the array:for example
    dim x(1 to 3) as single
    dim y as single
    x(1)=2
    X(2)=3
    x(3)=5
    y=12
    how can i cheak that y is bigger than 2,3,5

    1. Hi Philip,

      You can do this using a for loop

          Dim bBigger As Boolean
          bBigger = True
          
          Dim i As Long
          For i = LBound(x) To UBound(x)
              If x(i) >= y Then
                  bBigger = False
                  Exit For
              End If
          Next i
      
          Debug.Print "Is y bigger? :" & bBigger
      

      Paul

  41. I want to vlookup data from different sheet for a particular set of 4000 variables using array function and do a pivort table for a comparison.

  42. Hi Paul,
    It would be great if you have an idea how to make my code go faster. Problem: I need to write a 2D array to a worksheet, but only the array values that are not empty (empty array values should not overwrite existing data on the sheet). I did not find any quicker solution than using a loop and an if. Run time is unfortunately extremely bad. Any idea how to solve that? Thank you, Andy

    For iWritebackR = 2 To LRowDeliv
    For iWritebackC = 1 To 53
    If arrDataTableSheet(iWritebackR – 1, iWritebackC) “” Then
    Cells(iWritebackR, iWritebackC).Value = arrDataTableSheet(iWritebackR – 1, iWritebackC)
    End If
    Next iWritebackC
    Next iWritebackR

    1. somehow the unequal sign got lost when I posted the comment:
      code should read:
      If arrDataTableSheet(iWritebackR – 1, iWritebackC) “” Then Cells(iWritebackR, iWritebackC).Value = arrDataTableSheet(iWritebackR – 1, iWritebackC)
      ……. with a smaller than plus a bigger than sign before the empty value

  43. Hi Paul,

    I want to vlookup data from different sheet for a particular set of 4000 variables using array function and do a pivort table for a comparison. can you please provide a code for that

  44. Hi Paul,

    I have a checklist a2:c6 that contains blank cells or cells marked with “V” for example. In cells a1 , b1, c1 there are 3 names Tom, Tim , Maria. I need the cells in range d2:d6 to concatenate the names present in a1, b1 and c1 only if they are marked with V in the previous cells of the same row. Can this be done with an array and loop?

    Regards and thanks in advance!

  45. Paul,
    I have two arrays A=1r4c & B=20r, 4c where i want to use worksheetfunction.sumproduct(A,Bx) in some VBA code, where Bx refers to row x, a single row from matrix B, including all 4 columns.
    I got this to work fine using a named range for A and the address of the row Bx. I cannot get the reference correct so I can use a named range for all of B, then get the code to select row x.
    I want to use a named range to make it easier to move array B around without affecting the code.
    Thanks,

Leave a Reply

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