Password / Filter workbook by user

  • Thread starter Thread starter SDamico
  • Start date Start date
S

SDamico

I have a workbook that contains information that I would like to use as a
shareable workbook for 4 other people but I don't want each user to see the
information that relates to the other users. I don't want to separate the
workbook and consolidate every time that users make changes. Is it possible
to open the workbook with a password (by user) and have the user only see the
information that shows the information for that specific user? The user's
name appears in one of the columns.
Thanks
 
Can be done with the caveat that Excel internal protection is quite weak and
it is very difficult to keep a determined user from gaining access to data
on hidden sheets.

Sample code.......................

Note: the following is contingent upon users enabling macros.

If they don't only the "Dummy" sheet will be visible with a large message
stating "By disabling macros you have rendered this workbook unusuable.
Please close and re-open with macros enabled"

I assume you are on a network(LAN) with users logging into the system.

I would set it up so that whichever user's login name is flagged, all sheets
except that user would be hidden.

No password to open the workbook or sheet protection, just code to make a
user's sheet visible.

In Thisworkbook Module....................

Private Sub Workbook_Open()
Dim pword As String
On Error GoTo endit
Select Case Environ("Username")

'if a login is not used change to
'pword = InputBox("Enter Your Password")
'Select Case pword

Case Is = "Gord": Sheets("Gordsheet").Visible = True
Case Is = "Pete": Sheets("Petesheet").Visible = True
'add more Cases for other users
End Select
Sheets("Dummy").Visible = False
Exit Sub
endit:
'MsgBox "Incorrect Password"
End Sub

Private Sub Workbook_BeforeClose(Cancel As Boolean)
Dim sht As Worksheet
Application.ScreenUpdating = False
Sheets("Dummy").Visible = xlSheetVisible
For Each sht In ActiveWorkbook.Sheets
If sht.Name <> "Dummy" Then
sht.Visible = xlSheetVeryHidden
End If
Next sht
Application.ScreenUpdating = True
ThisWorkbook.Save
End Sub

To allow you to see all sheets and edit them.

In a general module...............

Sub UnHideAllSheets()
Application.ScreenUpdating = False
Dim n As Single
For n = 1 To Sheets.Count
Sheets(n).Visible = True
Next n
Application.ScreenUpdating = True
End Sub

Naturally you want all this code invisible to the users.

Right-click on the workbook/project in VBE and select VBAProject Properties
and "Lock project for viewing"

Enter a password.


Gord Dibben MS Excel MVP
 
Back
Top