Written by Allen Wyatt (last updated March 29, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365
Bill has a set of multiple workbooks that he frequently uses as a suite. To prevent prying eyes from the contents of these workbooks, he has set a password for each of them. Bill uses a menu workbook as a gateway to the other workbooks in the suite. The workbook contains hyperlinks to the individual workbooks, providing him with quick access to the workbooks in his suite.
Since Excel protects, via password, each workbook on a file-level basis, whenever Bill clicks a hyperlink, he needs to enter the password for the workbook he is trying to access. He wonders if there is a way to simply enter the password once (it is the same password for all of the workbooks in his suite) and have access to all the workbooks without the necessity of repeatedly entering the password.
The short answer is that this cannot be done since Excel treats each file separately. Switch to a separate file via your hyperlink, and Excel once again asks for the password. There are only two possible ways to avoid the annoyance. The first is to combine all the separate workbooks into a single workbook. This may not be an optimal solution, for any number of reasons. (For instance, you may need to distribute individual workbooks to other users. If you combine all the workbooks into one, you remove this capability.)
The other solution is to use a macro to handle switching between workbooks, rather than using hyperlinks. There are many ways that such a macro system could be set up, but one simple way that mimics the hyperlink method is to create a new worksheet that will act as your "gateway." In the cells where you would have added hyperlinks, instead place the full path and filename of each workbook you want to link to. You should end up with a list of file specifications for your workbooks.
Now, right-click the sheet tab of this new worksheet. Excel displays a Context menu from which you should select View Code. This displays the VBA Editor, with the code pane displayed for the worksheet. Enter the following macro into the code pane:
Private Sub Worksheet_BeforeDoubleClick _ (ByVal Target As Excel.Range, Cancel As Boolean) Dim sPW As String Dim sFile As String sPW = "password" 'Change to your password sFile = Target.Value If sFile <> "" Then If Dir(sFile) <> "" Then Workbooks.Open _ FileName:=sFile, _ password:=sPW Cancel = True End If End If End Sub
The only thing you should have to change in the code is the password you want used for the workbooks you are accessing. (The code assumes that the same password is used for all of the workbooks.)
Press Alt+Q to exit the VBA Editor, and you are back at your worksheet. Save the workbook, and then double-click any of the cells containing the path and filenames. What Excel does is to then pass control to the macro which grabs the path and filename and then opens that workbook.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8109) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Using a Single Password for Multiple Workbooks.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Sometimes it is helpful to copy worksheets from one workbook to another. If you have dozens of such worksheets to copy, ...
Discover MoreDo you need to compare two workbooks to each other? While you can use specialized third-party software to do the ...
Discover MoreThere are two ways you can load a workbook in Excel, and each approach should result in the workbook being loaded ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-03-29 17:36:16
Tomek
Correction:
the dim statement "sPW As String" in the Sub Worksheet_BeforeDoubleClick should be removed as it may interfere with the public statement in the main module. below is the corrected procedure:
Private Sub Worksheet_BeforeDoubleClick _
(ByVal Target As Excel.Range, Cancel As Boolean)
Dim sFile As String
' sPW = "xxxxx" this line is removed (commented out)
sFile = Target.Value
If sFile <> "" Then
If Dir(sFile) <> "" Then
Workbooks.Open _
Filename:=sFile, _
Password:=sPW
Cancel = True
End If
End If
End Sub
2025-03-29 17:29:27
Tomek
The macro solution from this tip makes me worried that the password may be exposed as it is hard coded into the Sub Worksheet_BeforeDoubleClick.
While the gateway workbook can be also password protected, such approach generally weakens the security of such project.
I suggest that a public variable sPW be declared in the main module of the gateway workbook, and then assigned the password using InputBox function or method. This can be done by a regular macro or the macro that runs on opening the gateway workbook.
The sPW variable will remember the password as long as the gateway workbook is open or until it is assigned another value or the running code is reset, so you can keep opening other workbooks without having to re-enter the password.
I would add another macro to clear the password from memory, so even with the gateway workbook open other users could not open the ones that are password protected.
Example macros:
'In Module1:
Public sPW As String
'in ThisWorkbook:
'------------------------------------
Public Sub Workbook_Open()
tmp = InputBox("password to open all other workbooks", "Type")
sPW = tmp
End Sub
'in Sheet1 or whatever contains the list of files
'--------------------------------------
Private Sub Worksheet_BeforeDoubleClick _
(ByVal Target As Excel.Range, Cancel As Boolean)
Dim sFile As String, sPW As String
' sPW = "xxxxx" this line is removed (commented out)
sFile = Target.Value
If sFile <> "" Then
If Dir(sFile) <> "" Then
Workbooks.Open _
Filename:=sFile, _
Password:=sPW
Cancel = True
End If
End If
End Sub
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments