BY CATEGORY▼
VBA CATEGORIES▼
EXCEL VBA - BASICS VIDEOS▼
- Excel VBA Part 1 - The VB Editor
- Excel VBA Part 2 - Writing Your First Macro
- Excel VBA Part 3 - What To Do When Things Go Wrong
- Excel VBA Part 4 - Buttons, Toolbars and Keyboard Shortcuts
- Excel VBA Part 5 - Selecting Cells
- Excel VBA Part 6 - Worksheets, Charts and Sheets
- Excel VBA Part 7 - Working with Workbooks
- Excel VBA Part 8 - Variables in VBA
- Excel VBA Part 9 - Object Variables
- Excel VBA Part 10 - Message Boxes
- Excel VBA Part 11 - Input Boxes
- Excel VBA Part 11a - Application.InputBox
- Excel VBA Part 12 - With Statements
- Excel VBA Part 13.1 - If Statements in VBA
- Excel VBA Part 14.1- Select Case Statements
- Excel VBA Part 15.1 - Do Until and Do While Loops
- Excel VBA Part 16 - For Next Loops
- Excel VBA Part 17 - For Each Loops
- Excel VBA Part 18 - Creating Functions
- Excel VBA Part 19 - Error Handling
- Excel VBA Part 20 - Event Procedures
- Excel VBA Part 21 - User Forms
Excel VBA - Basics videos | Excel VBA Part 17 - For Each Loops
Posted by Andrew Gould on 10 February 2014
A For Each Loop is used to loop over a collection of objects and there are lots of good reasons for wanting to do that in Excel VBA! This video takes you from the basics of the For Each Next statement and using object variables through several examples of looping over worksheets, workbooks, chartobjects and cells and, finally, into writing nested loops for even more power.
You can increase the size of the video:

You can view the video in full screen mode as shown on the left, using the icon at the bottom right of the frame.
You can also increase the quality of the video:

You can improve the resolution of the video using another icon at the bottom right of the frame. This will slow down the connection speed, but increase the display and sound quality. This icon only becomes visible when you start playing the video.
Finally, if nothing happens when you play the video, check that you're not using IE in compatibility view.
Can you tell me what is the syntax in a For Each Loop?
My understanding is For Each x In y, x has to be either: 1. Variant, 2. Generic Object or 3. Specific Object
Does x also have to be of the same type as y?
Hi duggie,
If you're ever in doubt with syntax you can check the Microsoft documentation https://docs.microsoft.com/en-us/office/vba/language/reference/user-interface-help/for-eachnext-statement
If x is a Specific Object, its type should match the type of the items in y.
Andrew,
Thanks for the clarification. The reason for asking is I am puzzled by the more complicated example as follows:
This is in a standard module:
Option Explicit
Sub TestCollectionObject()
Dim rg As Range
Dim objLoans As Collection
Dim objLoan As Loan
Set rg = ThisWorkbook.Worksheets("Loans").Range("LoanListStart").Offset(1, 0)
' get the collection of loan objects
Set objLoans = CollectLoanObjects(rg)
Debug.Print "There are " & objLoans.Count & " loans."
' iterate through each loan
For Each objLoan In objLoans
Debug.Print "Loan Number " & objLoan.LoanNumber & " has a payment of " & Format(objLoan.Payment, "Currency")
Next
Set objLoans = Nothing
Set objLoan = Nothing
Set rg = Nothing
End Sub
Function CollectLoanObjects(rg As Range) As Collection
Dim objLoan As Loan
Dim objLoans As Collection
Set objLoans = New Collection
' loop until we find an empty row
Do Until IsEmpty(rg)
Set objLoan = New Loan
With objLoan
.LoanNumber = rg.Value
.Term = rg.Offset(0, 1).Value
.InterestRate = rg.Offset(0, 2).Value
.PrincipalAmount = rg.Offset(0, 3).Value
End With
' add the current loan to the collection
objLoans.Add objLoan, CStr(objLoan.LoanNumber)
' move to next row
Set rg = rg.Offset(1, 0)
Loop
Set objLoan = Nothing
Set CollectLoanObjects = objLoans
Set objLoans = Nothing
End Function
This is in a class called Loan:
Option Explicit
' private class variables to hold property values
Dim mvPrincipalAmount As Variant
Dim mvInterestRate As Variant
Dim mvLoanNumber As Variant
Dim mvTerm As Variant
Private Sub Class_Initialize()
' set default principal amount to 0
mvPrincipalAmount = 0
' set default interest rate to 8% annually
mvInterestRate = 0.08
' set loan number to 0
mvLoanNumber = 0
' set term to 0
mvLoanNumber = 0
End Sub
Public Property Get PrincipalAmount() As Variant
PrincipalAmount = mvPrincipalAmount
End Property
Public Property Let PrincipalAmount(ByVal vNewValue As Variant)
mvPrincipalAmount = vNewValue
End Property
Public Property Get InterestRate() As Variant
InterestRate = mvInterestRate
End Property
Public Property Let InterestRate(ByVal vNewValue As Variant)
mvInterestRate = vNewValue
End Property
Public Property Get LoanNumber() As Variant
LoanNumber = mvLoanNumber
End Property
Public Property Let LoanNumber(ByVal vNewValue As Variant)
mvLoanNumber = vNewValue
End Property
Public Property Get Term() As Variant
Term = mvTerm
End Property
Public Property Let Term(ByVal vNewValue As Variant)
mvTerm = vNewValue
End Property
Public Property Get Payment() As Variant
Payment = Application.WorksheetFunction.Pmt(mvInterestRate / 12, mvTerm, -mvPrincipalAmount)
End Property
The line that troubles me is this:
For Each objLoan In objLoans
because objLoan is declared As Loan but objLoans is declared As Collection.
Am I correct in saying because objLoans is a Collection where the Collection is a collection of the object Loans, therefore it is as you put it "of the same type"?
The CollectObjectLoans function adds objects of the type Loan to a Collection and returns this collection to the calling code.
This means that the type of x is Loan and the type of each object in y is also Loan.
Hi,
Since I am new in VBA, I would appreciate your assistance. As in your video example, I am trying to loop through each worksheet and each cell in a range of cells by using nested For Each....Next loops. What is wrong with the "SingleWorksheet.ListOfCells" line in the code below?
Sub ForEachSelect()
Dim SingleWorksheet As Worksheet
Dim SingleCell As Range
Dim ListOfCells As Range
Set ListOfCells = Range("a1", Range("a1").End(xlDown))
For Each SingleWorksheet In Worksheets
For Each SingleCell In SingleWorksheet.ListOfCells
SingleCell.Select
Next SingleCell
Next SingleWorksheet
End Sub
Thanks in advance for the help.
Hi, the problem is that ListOfCells isn't a property of a worksheet, it's an object variable which contains a reference to a specific block of cells. As you set the reference to the range before beginning the loop, it will refer to the cells on whichever worksheet is active when you begin running the procedure. One other small problem is that you can't successfully select a cell unless the worksheet to which the cell belongs is active. You can restructure your code in a variety of ways to solve this. Here's one possibility:
Sub ForEachSelect()
Dim SingleWorksheet As Worksheet
Dim SingleCell As Range
Dim ListOfCells As Range
For Each SingleWorksheet In Worksheets
SingleWorksheet.Select
Set ListOfCells = Range("A1", Range("A1").End(xlDown))
For Each SingleCell In ListOfCells
SingleCell.Select
Next SingleCell
Next SingleWorksheet
End Sub
I hope that helps!