Loop-through Macro

ryansm05

Board Regular
Joined
Sep 14, 2016
Messages
148
Office Version
  1. 365
Platform
  1. Windows
Hi,

I'm wondering if anyone can help me with the below?

I have 2 files (Client X & Client B). They are saved in the following folder: I:\Content & Creative\Design Admin\_Revenue

Additionally, I have my summary file (which does not yet have a macro - but this is where I'm wanting the macro to work). I'm needing specific cells to be copied from the files in the above location, and then pasted into the summary file. This summary file location is: I:\Content & Creative\Design Admin\_Revenue\Summary

Data to be copied from each client file (Client X & Client B)

Cell D3
Cell D6
Cell E10
Cell E11
Cell E12
Cell E14

Data to be pasted to the summary file:
(D3) to D6
(D6) to E6
(E10) to G6
(E11) to H6
(E12) to I6
(E13) to J6


If this is possible, it would be good to then sort this data in the summary file by column E (client). In addition, when I re-run the macro, data may have been updated or files even removed. Therefore, I will need it to clear the summary sheet each time and start afresh.

I have uploaded the 3 files mentioned to dropbox:
Client X: https://www.dropbox.com/s/4nqla0mjrxlzwe3/Client X.xlsx?dl=0
Client B: https://www.dropbox.com/s/6k3sfdu56j1uurp/Client B.xlsx?dl=0
Summary: https://www.dropbox.com/s/3lxeum7mvf7bpd0/Summary Macro.xlsx?dl=0


If anyone could help me, it would be much appreciated!!!!! :)


Thanks
Ryan
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Let's see if I understood correctly.
Do the following:
- Put the macro in the summary book.
- Open the 3 books.
- Change the data in red for your information.


Cell D3 of book "x" goes in cell D6 of summary book, but cell D3 of book "B" where it goes? I put it in cell D7.


Make tests and tell me.


Code:
Sub Macro()
    Dim w1 As Workbook, w2 As Workbook, w3 As Workbook
    Dim s1 As Worksheet, s2 As Worksheet, s3 As Worksheet
    
    Set w1 = ThisWorkbook
    Set w2 = Workbooks("[COLOR=#ff0000]Client X.xlsx[/COLOR]")
    Set w3 = Workbooks("[COLOR=#ff0000]Client B.xlsx[/COLOR]")
    
    Set h1 = w1.Sheets("[COLOR=#ff0000]Summary[/COLOR]")
    Set h2 = w1.Sheets(1)
    Set h3 = w1.Sheets(1)


    'Pass "X" values to the summary sheet
    h1.Range("D6").Value = h2.Range("D3")
    h1.Range("E6").Value = h2.Range("D6")
    h1.Range("G6").Value = h2.Range("E10")
    h1.Range("H6").Value = h2.Range("E11")
    h1.Range("I6").Value = h2.Range("E12")
    h1.Range("J6").Value = h2.Range("E13")


    'Pass "B" values to the summary sheet
    h1.Range("[COLOR=#ff0000]D7[/COLOR]").Value = h3.Range("D3")
    h1.Range("[COLOR=#ff0000]E7[/COLOR]").Value = h3.Range("D6")
    h1.Range("[COLOR=#ff0000]G7[/COLOR]").Value = h3.Range("E10")
    h1.Range("[COLOR=#ff0000]H7[/COLOR]").Value = h3.Range("E11")
    h1.Range("[COLOR=#ff0000]I7[/COLOR]").Value = h3.Range("E12")
    h1.Range("[COLOR=#ff0000]J7[/COLOR]").Value = h3.Range("E13")


End Sub
 
Upvote 0
Hi Dante,

I should have made a few points much clearer -

1) Although I have included the files Client X and client B ...... there will be many other files such as Project 200 etc. Therefore, I need the macro to look in this location: I:\Content & Creative\Design Admin\_Revenuesh and then copy and paste the above data into the summary sheet for every file saved in this location.

2) Cell D3 of book "x" goes in cell D6 of summary book, but cell D3 of book "B" where it goes? I put it in cell D7. - yes this is correct.

Do you think this is possible?

Thanks
Ryan
 
Upvote 0
Hi Dante,
I should have made a few points much clearer -
1) Although I have included the files Client X and client B ...... there will be many other files such as Project 200 etc. Therefore, I need the macro to look in this location: I:\Content & Creative\Design Admin\_Revenuesh and then copy and paste the above data into the summary sheet for every file saved in this location.
2) Cell D3 of book "x" goes in cell D6 of summary book, but cell D3 of book "B" where it goes? I put it in cell D7. - yes this is correct.Do you think this is possible?
Thanks
Ryan

In your original request you said this:
I have 2 files (Client X & Client B)

It is difficult to guess that you require the macro for more files!

Then, put the following macro in your summary file. The macro will review all the files in the folder.

Code:
Sub Macro()
    Dim w1 As Workbook, w2 As Workbook, s1 As Worksheet, s2 As Worksheet
    Dim wPath As String, wFile As Variant, i As Long
    
    Application.ScreenUpdating = False
    Set w1 = ThisWorkbook
    Set h1 = w1.Sheets("Summary")   'summary sheet
    h1.Cells.ClearContents          'clear the summary sheet
    i = 6                           'start on row 6
    wPath = "I:\Content & Creative\Design Admin\_Revenue\"
    wFile = Dir(wPath & "*.xls*")
    Do While wFile <> ""
        Set w2 = Workbooks.Open(wPath & wFile)
        Set h2 = w2.Sheets(1)
        h1.Range("D" & i).Value = h2.Range("D3")
        h1.Range("E" & i).Value = h2.Range("D6")
        h1.Range("G" & i).Value = h2.Range("E10")
        h1.Range("H" & i).Value = h2.Range("E11")
        h1.Range("I" & i).Value = h2.Range("E12")
        h1.Range("J" & i).Value = h2.Range("E13")
        i = i + 1
        w2.Close False
        wFile = Dir()
    Loop
    Application.ScreenUpdating = True
    MsgBox "Done  "
End Sub
 
Upvote 0
Yes - apologies, I should have been much clearer.

Right, I've run the macro, and updated to reflect the actual file locations that I'm using. The macro runs through, and I get a 'Done' message. However, no data pulls through. I've checked the obvious e.g text is all black and that no cells are populated.

Do you have any idea why this wouldn't have worked?

Code:
Sub Macro() Dim w1 As Workbook, w2 As Workbook, s1 As Worksheet, s2 As Worksheet
Dim wPath As String, wFile As Variant, i As Long

Application.ScreenUpdating = False
Set w1 = ThisWorkbook
Set h1 = w1.Sheets("Budgeted Hours") 'summary sheet
h1.Cells.ClearContents 'clear the summary sheet
i = 6 'start on row 6
wPath = "I:\Content & Creative\Design Admin\_Revenue\JP Confirmed"
wFile = Dir(wPath & "*.xls*")
Do While wFile <> ""
Set w2 = Workbooks.Open(wPath & wFile)
Set h2 = w2.Sheets(1)
h1.Range("D" & i).Value = h2.Range("D3")
h1.Range("E" & i).Value = h2.Range("D6")
h1.Range("G" & i).Value = h2.Range("E10")
h1.Range("H" & i).Value = h2.Range("E11")
h1.Range("I" & i).Value = h2.Range("E12")
h1.Range("J" & i).Value = h2.Range("E13")
i = i + 1
w2.Close False
wFile = Dir()
Loop
Application.ScreenUpdating = True
MsgBox "Done "
End Sub
 
Upvote 0
Yes - apologies, I should have been much clearer.

Right, I've run the macro, and updated to reflect the actual file locations that I'm using. The macro runs through, and I get a 'Done' message. However, no data pulls through. I've checked the obvious e.g text is all black and that no cells are populated.

Do you have any idea why this wouldn't have worked?

Code:

Do you have xlsx files in the folder?
For example, open a file and tell me what you have in the first sheet in cell D3
 
Upvote 0
Nope - they're all macro files (.xlsm)...

Does this make a difference?
 
Upvote 0
Nope - they're all macro files (.xlsm)...

Does this make a difference?


No, the macro reads all the xls files:
Code:
wFile = Dir(wPath & "*.xls*")

Then
For example, open a file and tell me what you have in the first sheet in cell D3

Check that you have the backslash:
Code:
[/COLOR][COLOR=#333333]wPath = "I:\Content & Creative\Design Admin\_Revenue[/COLOR][SIZE=3][COLOR=#ff0000][B]\[/B][/COLOR][/SIZE][COLOR=#333333]"[/COLOR][COLOR=#333333]
 
Last edited:
Upvote 0
It works!!! I had missed part of the code.

Thank you so much for this.

I guess the only thing I've now realised, instead of this:
h1.Cells.ClearContents 'clear the summary sheet

Can I just ClearCotnents D6:Q1000 ?

Thanks
Ryan
 
Upvote 0
It works!!! I had missed part of the code.

Thank you so much for this.

I guess the only thing I've now realised, instead of this:


Can I just ClearCotnents D6:Q1000 ?

Thanks
Ryan


Use this

Code:
h1.Range("D6:Q1000").ClearContents          'clear the summary sheet
 
Upvote 0

Forum statistics

Threads
1,224,818
Messages
6,181,151
Members
453,021
Latest member
Justyna P

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