Open, Close and Save Multiple Files Using VBA

patrick2980

New Member
Joined
Apr 28, 2020
Messages
2
Office Version
  1. 365
Platform
  1. Windows
Hello,

I am trying to create one macro that will open, close and save files based on file paths specified in a range of cells of the file containing the macro. This is to speed up a weekly process whereby trackers are updated with data from a central master file. I have found the below code which partly works. It opens the files and then saves them. However the issue I have is that it does not save the file in the same folder as where it has opened it from. Instead it saves them in the default local file location in excel. Can anyone advise how I would amend to correct?

Thanks in advance!

Sub Update_Single_Trackers()

Application.ScreenUpdating = False
Application.DisplayAlerts = False
For i = 2 To 5
With Workbooks.Open(Range("A" & i), UpdateLinks:=0)
.Save
.Saved = True
.Close 0
End With
Next
Application.ScreenUpdating = True

End Sub
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
Hi,
welcome to forum

try this update to your code & see if helps you

Rich (BB code):
Sub Update_Single_Trackers()
    Dim i As Integer
    Dim arr As Variant
    Dim wb As Workbook
    
    With Application
        .ScreenUpdating = False: .DisplayAlerts = False
    End With
    
    arr = Worksheets("Sheet1").Range("A2:A5").Value
    
    For i = 1 To UBound(arr, 1)
        If Not Dir(arr(i, 1), vbDirectory) = vbNullString Then
            Set wb = Workbooks.Open(arr(i, 1), UpdateLinks:=0)
            
' do stuff here
            
'close & save
            wb.Close True
            
        End If
        Set wb = Nothing
    Next
    
    With Application
        .ScreenUpdating = True: .DisplayAlerts = True
    End With
    
End Sub

Change sheet name shown in BOLD where file paths are located as required.

Dave
 
Upvote 0
Thanks very much for the reply Dave. Only slight issue is that solution prompts me to save a copy of the files opened as opposed to just saving the opened file in the same location. Any ideas how to correct?

Thanks again,
Patrick
 
Upvote 0
Thanks very much for the reply Dave. Only slight issue is that solution prompts me to save a copy of the files opened as opposed to just saving the opened file in the same location. Any ideas how to correct?

Thanks again,
Patrick

Try changing this line

VBA Code:
Set wb = Workbooks.Open(arr(i, 1), UpdateLinks:=0)

to this

VBA Code:
Set wb = Workbooks.Open(arr(i, 1), False, False)

and see if resolves your issue

Dave
 
Upvote 0

Forum statistics

Threads
1,214,819
Messages
6,121,746
Members
449,050
Latest member
excelknuckles

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