User verification-VBA code

Sunnygreet

New Member
Joined
Apr 4, 2023
Messages
14
Office Version
  1. 365
Platform
  1. Windows
In the attached VBA code below, how do I add an user verification (''FullName'') where the user list (master list) is managed through a different excel file? Only users in the separate master list should be able to access the workbook with the below VBA code when they enter their FullName.

VBA Code:
Private Sub Workbook_BeforeClose(Cancel As Boolean)
On Error Resume Next
Application.OnTime NextBackup, "AutoBackup", , False    'Stops the auto backup
On Error GoTo 0
End Sub

Private Sub Workbook_Open()
AutoBackup      'Starts the auto backup
End Sub

Private Sub Workbook_SheetChange(ByVal Sh As Object, ByVal Target As Range)
'Date    Time    User ID User Name   Worksheet   Cell    Action  Old Value   New Value
Dim nRow As Long
Dim bCompliant As Boolean
Dim wsAudit As Worksheet
Dim ChangeDate As String, ChangeTime As String, FullName As String, UserID As String
Dim oldValue(1 To 4) As Variant     '1 to 4 non-contiguous blocks of cells may be changed at a time. This limit is arbitrary.
Dim newValue(1 To 4) As Variant     'Should be same as oldValue
Dim ar As Range, cel As Range, rg As Range, cellHome As Range
Dim i As Long, n As Long, j As Long, cols As Long, k As Long, nAreas As Long
Dim ans

Set wsAudit = Worksheets("Audit Trail")     'The Audit Trail worksheet must be named Audit Trail
Set rg = Target
Set cellHome = ActiveCell
nAreas = rg.Areas.Count

If Sh.Name = wsAudit.Name Then              'Don't trap changes on Audit Trail worksheet
ElseIf rg.Cells.Count > 20 Then             'Too many cells changed. Don't trap changes, as might have been row or column insertion/deletion
ElseIf nAreas > UBound(oldValue) Then       'Too many non-contiguous cell ranges being changed. Don't accept or trap changes.

    MsgBox "Please change " & UBound(oldValue) & " or fewer non-contiguous blocks of cells"
    Application.EnableEvents = False
    Application.Undo
    Application.EnableEvents = True
Else
    Application.EnableEvents = False
    For k = 1 To nAreas
        newValue(k) = rg.Areas(k).Value
    Next
    
    Application.Undo
    For k = 1 To nAreas
        oldValue(k) = rg.Areas(k).Value
    Next
    Application.Undo
    
    nRow = wsAudit.Cells(wsAudit.Rows.Count, 1).End(xlUp).Row + 1
    FullName = InputBox("Scan your full name")
    If FullName <> "" Then
        bCompliant = True
        'LastName = InputBox("What is your last name?")
        'If LastName <> "" Then
            'FullName = FirstName & " " & LastName
        'Else
            'bCompliant = False
        'End If
    End If
    
    If bCompliant = False Then
        ans = MsgBox("This workbook is being closed because you didn't enter your name.", vbQuestion + vbOKCancel)
    End If
If ans = vbOK Then
    Application.Quit
    ThisWorkbook.Close SaveChanges:=False
ElseIf ans = vbCancel Then
    Application.Quit
    ThisWorkbook.Close SaveChanges:=False
End If
    
    Application.EnableEvents = False
    Application.ScreenUpdating = False
    'If wsAudit.Visible <> xlSheetHidden Then wsAudit.Visible = xlSheetVeryHidden
    
    ChangeDate = Format(Date, "m/d/yyyy")
    ChangeTime = Format(Now(), "h:mm")
    If rg.Cells.Count > 1 Then
        For k = 1 To nAreas
            Set ar = rg.Areas(k)
            
            If ar.Cells.Count = 1 Then
                wsAudit.Cells(nRow, 1).Resize(1, 9).Value = _
                    Array(ChangeDate, ChangeTime, , FullName, Sh.Name, cel.Address, "Change", oldValue(k), newValue(k))
                nRow = nRow + 1
            Else
                n = ar.Rows.Count
                cols = ar.Columns.Count
                For i = 1 To n
                    For j = 1 To cols
                        Set cel = ar.Cells(i, j)
                        wsAudit.Cells(nRow, 1).Resize(1, 9).Value = _
                            Array(ChangeDate, ChangeTime, , FullName, Sh.Name, cel.Address, "Change", oldValue(k)(i, j), newValue(k)(i, j))
                        nRow = nRow + 1
                    Next
                Next
            End If
        Next
    Else
        wsAudit.Cells(nRow, 1).Resize(1, 9).Value = Array(ChangeDate, ChangeTime, , FullName, Sh.Name, rg.Address, "Change", oldValue, rg.Value)
    End If
    
    Application.EnableEvents = True
End If
Application.Goto cellHome

End Sub
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
Try this. Put it just under "Private Sub Workbook_Open()" in place of the "AutoBackup 'Starts the auto backup" line. It will check an excel sheet for a list of users on sheet1. If it doesn't find the user list, it puts up an error and shuts down the main file unsaved.
If it doesn't find the name the user is logged in with in the user list, it will write their name to Sheet2 of the users list and put up an error and then shut down the main file unsaved.

VBA Code:
'https://www.mrexcel.com/board/threads/user-verification-vba-code.1235875/
Dim src As Workbook
Dim i As Long
Dim y As String
Dim UserName As String
Dim checkSheetName As String
Dim DirFile As String

'get the system username
UserName = VBA.Environ("USERNAME")
DirFile = "C:\allowedusers.xlsx" 'change as necessary

'if userlist is not there...
If Len(Dir(DirFile)) = 0 Then
    'pop message box.  The 4096 indicates "all EXCEL applications are suspended until the user responds to the message box."
    y = MsgBox("User List missing. No access allowed." & vbNewLine & "Contact *Sunnygreet for assistance.", 16 + 4096, "Unauthorized User")
    GoTo getout
End If

'don't let any events or show any screen updates
Application.EnableEvents = False
Application.ScreenUpdating = False

' OPEN THE SOURCE EXCEL WORKBOOK IN "READ ONLY MODE".
Set src = Workbooks.Open(DirFile)
'activate the open user list workbook
src.Activate
'find the last row in the user list
LastRow = src.Sheets("Sheet1").Range("A" & Rows.Count).End(xlUp).Row
'loop through all the rows
For i = 2 To LastRow
    'if you find a match...
    If src.Sheets("Sheet1").Cells(i, 1) = UserName Then
        'close the userlist with no changes
        src.Close False
        'enable events and screen updates
        Application.EnableEvents = True
        Application.ScreenUpdating = True
        AutoBackup      'Start the auto backup
        'go on with life
        End
    End If
Next i

'if you've gotten this far, they're not on the list
On Error Resume Next
'check for Sheet2 on the user list
checkSheetName = src.Worksheets("Sheet2").Name
'if it doesn't exist
If checkSheetName = "" Then
    'create it at the end
    src.Sheets.Add(After:=Sheets("Sheet1")).Name = "Sheet2"
    'set back to Sheet1 just to look pretty
    src.Worksheets("Sheet1").Activate
End If
On Error GoTo 0
'find the last row on sheet 2 of the users list
LastRow = src.Sheets("Sheet2").Range("A" & Rows.Count).End(xlUp).Row
'put unautorized users name on list on sheet2
src.Sheets("Sheet2").Cells(LastRow + 1, 1) = UserName
' save and CLOSE THE SOURCE FILE.
src.Close SaveChanges:=True
'pop message box.  The 4096 indicates "all applications are suspended until the user responds to the message box."
y = MsgBox("You are not allowed access to this Workbook." & vbNewLine & "Contact *Sunnygreet for assistance.", 16 + 4096, "Unauthorized User")
'trick the program that the workbook has been saved so it won't bug you to.

getout:
Application.EnableEvents = True
Application.ScreenUpdating = True
ThisWorkbook.Saved = True
'quit the application without saving
Application.Quit

)
 
Upvote 0

Forum statistics

Threads
1,214,651
Messages
6,120,744
Members
448,989
Latest member
mariah3

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