VBA For each Loop - select dropdown and call another macro

Melimob

Active Member
Joined
Oct 16, 2011
Messages
395
Office Version
  1. 365
Hi there,

I have the below code which *should* select a dropdown for all in list and call another macro (which creates a PDF and email) but it keeps staying on the same selection producing 20 emails for the one customer?

Any ideas on what I am doing wrong?

VBA Code:
Sub All_Intro_emailPDFLoop()
    Dim c As Range
    Dim Rng As Range
    Set Rng = Range("nDataVal_Introducers_Act_COMBO")
    For Each c In Rng
        Range("G6").Select
        Call emailsavePDF_Intro
    Next
End Sub
 

Excel Facts

Waterfall charts in Excel?
Office 365 customers have access to Waterfall charts since late 2016. They were added to Excel 2019.
Best guess is change Range("G6").Select to c.Select
 
Upvote 0
thanks Fluff but I get error "select method of range class failed'?
it's in a combobox active x where the dropdown is and when something in that is selected, it updates the formulas on the page.
macro then creates pdf and email.
 
Upvote 0
Is the sheet protected?
no it's not.

I saw this code which I'm trying to adapt which my be better as user would hit a command button when they want to run it but getting an error also with this..
Error 'Variable not defined'

VBA Code:
Option Explicit

Private Sub CommandButton1_Click()

  For rep = 0 To (Sheet21.ComboBox1.ListCount - 1)
      .Select
      Call emailsavePDF_Intro
  Next rep
    
End Sub
 
Upvote 0
You need to declare the variable rep
 
Upvote 0
You need to declare the variable rep
Hi Fluff

Apologies I'm really not sure what I'm doing I tried this and it produced 20 emails the same without changing the combobox value each time?

VBA Code:
Option Explicit

Private Sub CommandButton1_Click()

Dim rep As Long

  For rep = 0 To (Sheet21.ComboBox1.ListCount - 1)
      ComboBox1.Select
      Call emailsavePDF_Intro
  Next rep
    
End Sub

Essentially, instead of a user changing the drop down (in the combo box) and then clicking a button to send as PDF, I want it to loop through and create the email for each client in the list (comobox active x).

It has to be selected as the name is on the PDF and the lookups change from the combobox value (linked cell).

Many thanks
 
Upvote 0
Maybe
VBA Code:
Private Sub CommandButton1_Click()

   Dim rep As Long
   With Sheet21.ComboBox1
      For rep = 0 To .ListCount - 1
          .Value = .List(rep)
          Call emailsavePDF_Intro
      Next rep
   End With
End Sub
 
Upvote 0
Solution
Maybe
VBA Code:
Private Sub CommandButton1_Click()

   Dim rep As Long
   With Sheet21.ComboBox1
      For rep = 0 To .ListCount - 1
          .Value = .List(rep)
          Call emailsavePDF_Intro
      Next rep
   End With
End Sub
THANK YOU THANK YOU THANK YOU!

That worked however as some of the clients don't have any data to report, 'the item cannot be found in the OLAP cube' error comes up. I feel I need to include an 'On Error Resume Next' but unsure where to place this line?
Also, I only want the report to run on the clients which are active. There is a cell which returns 'Active'/'Inactive' when the dropdown changes via a lookup however I tried to add this but got an error?:

VBA Code:
Private Sub CommandButton1_Click()

   Dim rep As Long
  
    With Sheet21.ComboBox1
      For rep = 0 To .ListCount - 1
           .Value = .List(rep)
        If .Range("S1").Value = "Active" Then
          Call emailsavePDF_Intro
       End If
      
    On Error Resume Next
      
      Next rep
        
        
   End With
End Sub
 
Upvote 0
As this is now a significantly question, it needs a new thread. Thanks
 
Upvote 0

Forum statistics

Threads
1,214,975
Messages
6,122,537
Members
449,088
Latest member
RandomExceller01

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top