This Excel macro is the inverse of Copy Multiple Workbooks into One where separate Workbooks are being combined into one MASTER Workbook. The Update Multiple Workbooks from One macro instead takes the current information from the MASTER Workbook and updates separate Workbooks. If you desire one source of information that can be easily distributed across multiple parties this macro is for you! If you want to secure the MASTER Workbook further refer to our Password Encryption Tutorial to setup additional security to protect the data source.
When this Excel macro runs it will loop through each Worksheet in the MASTER Workbook referencing the Workbook mapping indicated in the VBA code. By Default, the first Worksheet of the separate Workbook will be updated. You can customize this in the code to update a different Worksheet. If no Workbook mapping is present then the Active Workbook Path and Worksheet Name will be used to find a Workbook to update. If nothing is found a MsgBox will appear informing you no update will be made before moving onto the next Worksheet.
I have another Excel macro Save Worksheets as Workbooks that gives the impression that it is updating multiple workbooks from one. What this macro is doing is creating a new workbook overwriting the old one. This can be a problem if worksheets within these separate workbooks are being updated because this macro will delete this information. The Excel Update Multiple Workbooks from One macro is different because it is updating an existing Workbook not overwriting it.
21 through 37 ‘Use the Worksheet Name to set Workbook Mapping Update the WB Mapping and WSMapping
39 through 48 If WBMapping = “” Then ‘If no Workbook Mapping loop through FilePath for Active Workbook Remove if you don’t want this macro to look for a separate Workbook in the same Folder as the Active Workbook
62. MsgBox “No Workbook Mapping is setup for Worksheet-” & WS.Name & ” Nothing will be updated.” Remove if you don’t want to see a MsgBox if no WBMapping is found
73. MsgBox “The Mapped Workbooks have been updated!” Remove if you don’t want a MsgBox when this macro finishes
When this Excel macro runs it will loop through each Worksheet in the MASTER Workbook referencing the Workbook mapping indicated in the VBA code. By Default, the first Worksheet of the separate Workbook will be updated. You can customize this in the code to update a different Worksheet. If no Workbook mapping is present then the Active Workbook Path and Worksheet Name will be used to find a Workbook to update. If nothing is found a MsgBox will appear informing you no update will be made before moving onto the next Worksheet.
I have another Excel macro Save Worksheets as Workbooks that gives the impression that it is updating multiple workbooks from one. What this macro is doing is creating a new workbook overwriting the old one. This can be a problem if worksheets within these separate workbooks are being updated because this macro will delete this information. The Excel Update Multiple Workbooks from One macro is different because it is updating an existing Workbook not overwriting it.
See it in Action!
Watch this video to see this macro in action and checkout our Macro Design presentation!The Code
Here is the code for this macro. Make sure the following References are setup before running it: Visual Basic For Applications, Microsoft Excel 16.0 Object Library'Leverage & Lean "Less Clicks, More Results" Sub UpdateMultipleWorkbooksfromOne() ' Means variable is in use Dim FilePath As String ' Dim oFile As Object ' Dim oFolder As Object ' Dim oFSO As Object ' Dim WBMapping As String ' Dim WSMapping As Integer ' Dim WS As Worksheet ' On Error GoTo LeverageLean 'Hide ScreenUpdating and Display Alerts Application.ScreenUpdating = False Application.DisplayAlerts = False MASTERWB = ActiveWorkbook.Name 'This is the MASTER Workbook everything will be copied from For Each WS In ActiveWorkbook.Sheets 'Use the Worksheet Name to set Workbook Mapping If WS.Name = "Sheet1" Then WBMapping = "" WSMapping = 1 ElseIf WS.Name = "Sheet2" Then WBMapping = "" WSMapping = 1 ElseIf WS.Name = "Sheet3" Then WBMapping = "" WSMapping = 1 ElseIf WS.Name = "Sheet4" Then WBMapping = "" WSMapping = 1 ElseIf WS.Name = "Sheet5" Then WBMapping = "" WSMapping = 1 End If If WBMapping = "" Then 'If no Workbook Mapping loop through FilePath for Active Workbook FilePath = Left(ActiveWorkbook.FullName, Len(ActiveWorkbook.FullName) - Len(ActiveWorkbook.Name)) 'Active Workbook File Path Set oFSO = CreateObject("Scripting.FileSystemObject") Set oFolder = oFSO.GetFolder(FilePath) For Each oFile In oFolder.Files 'Loop through every File in FilePath If oFile.Name = WS.Name & Right(oFile.Name, (Len(oFile.Name) + 1) - InStrRev(oFile.Name, ".")) Then 'If the File Name equals the Worksheet Name WBMapping = FilePath & "\" & oFile.Name 'Set Workbook Mapping End If Next oFile End If If WBMapping <> "" Then Worksheets(WS.Name).Activate ActiveSheet.Cells.Select Selection.Copy 'Copy all contents in Active Worksheet Range("A1").Select Application.Workbooks.Open WBMapping, Editable:=True ActiveWorkbook.Worksheets(WSMapping).Activate Range("A1").PasteSpecial Paste:=xlPasteValues 'Paste into Separate Workbook Range("A1").Select ActiveWorkbook.Close SaveChanges:=True 'Close Separate Workbook Workbooks(MASTERWB).Activate ElseIf WBMapping = "" Then 'If no Workbook Mapping and no Workbook found MsgBox "No Workbook Mapping is setup for Worksheet-" & WS.Name & " Nothing will be updated." End If WBMapping = "" 'Set WBMapping to Nothing for next Worksheet Next Set oFile = Nothing Set oFolder = Nothing Set oFSO = Nothing MsgBox "The Mapped Workbooks have been updated!" Exit Sub LeverageLean: MsgBox (Err.Number & " - " & Err.Description & vbNewLine & vbNewLine & "Don't hesitate to email me: brentschneider@leveragelean.com") End Sub 'Stay Awesome
Macro Monday
Here is the Macro Monday video this macro was featured in. Watch this video to learn how to get the most out of this macro and start using it today!Customization
These lines of code can be customized to personalize this macro.21 through 37 ‘Use the Worksheet Name to set Workbook Mapping Update the WB Mapping and WSMapping
39 through 48 If WBMapping = “” Then ‘If no Workbook Mapping loop through FilePath for Active Workbook Remove if you don’t want this macro to look for a separate Workbook in the same Folder as the Active Workbook
62. MsgBox “No Workbook Mapping is setup for Worksheet-” & WS.Name & ” Nothing will be updated.” Remove if you don’t want to see a MsgBox if no WBMapping is found
73. MsgBox “The Mapped Workbooks have been updated!” Remove if you don’t want a MsgBox when this macro finishes