Request Users name when saving workbook

MarkStew

New Member
Joined
Jan 22, 2018
Messages
2
Hi all.
1st foray into Excel and I'm stuck. I have a basic workbook which allows users to enter holiday requests and I need to track the user who is making the changes.
Unfortunately this is done on shared PC's so i cant use the UserName associated with the PC./Excel which is where I've come undone as I can find any number of answers utilising this.

What I was after was a bit of code if possible that I can add to a "Save" button, that when clicked would prompt the user for their name and insert that with the date and time on a sheet (named "changes") and would continue to do this for each subsequent save so that I could look back and see all those who have used the sheet and when and what time they did so (allows me to resolve arguments of who asked for time off 1st)

The workbook is shared / set to track changes and auto creates backups and has no existing code. Excel 2013 Pro Plus.

Thanks for any help
 

Excel Facts

Why are there 1,048,576 rows in Excel?
The Excel team increased the size of the grid in 2007. There are 2^20 rows and 2^14 columns for a total of 17 billion cells.
You don't need a Save button, you can detect the Save event. Takes a bit of VBA.

With Excel running, press Alt-F11 to open the VB Editor.

In the Project Explorer, find the workbook, and click the + icon to open the treeview. Navigate to the listing for ThisWorkbook, and double click on it to open the ThisWorkbook code window. This is not a regular code window; it is a special one that i associated with the workbook, including responding to events that occur.

Click the left dropdown at the top of the code window, and choose Workbook. The stub of a VBA procedure appears:

Code:
Private Sub Workbook_Open()

End Sub

You can ignore this stub, and even delete it. But in the right dropdown, select BeforeSave. You will get the following stub:

Code:
Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)

End Sub

Modify this as follows:

Code:
Option Explicit

Dim msName As String

Private Sub Workbook_BeforeSave(ByVal SaveAsUI As Boolean, Cancel As Boolean)
  Dim iRow As Long
  
  ' msName is "" if it hasn't been entered since Excel started
  ' only ask the user for a name if name isn't aready stored in msname
  If Len(msName) = 0 Then
    msName = Application.InputBox("Please enter your name:", "Enter name", , , , , , 2)
    If msName = "False" Then
      ' user pressed Cancel button, so cancel their save
      Cancel = True
      Exit Sub
    End If
  End If
  
  ' code here to put user's name where you want it
  ' something like this
  With Worksheets("Changes")
    ' find last filled row
    iRow = .Cells(.Rows.Count, 1).End(xlUp).Row
    If .Cells(iRow, 1).Value = msName Then
      ' same user saved last, just update date
      .Cells(iRow, 2).Value = Now
    Else
      ' new user, enter name and date
      .Cells(iRow + 1, 1).Value = msName
      .Cells(iRow + 1, 2).Value = Now
    End If
  End With
End Sub

Good practice dictates that the module begins with "Option Explicit". Ask Google to explain it.

If you put the variable msName above any subs, it is a module level variable, and is remembered when the code runs again. This is part of not pissing off your users: if msName includes text longer than zero characters, don't keep asking the user for his name.

(They say you should write your code as if the person maintaining it is a psychopath who knows where you live.)
 
Upvote 0
Jon,
Thanks very much, exactly what I was after and in an easier format.
Also thanks for the Option Explicit tip, I need all the inbuilt help that I can get as I'll be the one maintaining the code so i always know where to find me.

Mark
 
Upvote 0

Forum statistics

Threads
1,223,909
Messages
6,175,315
Members
452,634
Latest member
cpostell

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