Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Inserting the User's Name in a Cell.

Inserting the User's Name in a Cell

by Allen Wyatt
(last updated January 11, 2017)

4

Sunlim noted that when Office is installed, the user specifies their name. This name can be accessed in some Office programs, such as in Word. Sunlim wonders how he can access the user's name in Excel and place that name in a cell.

The way to do this is to implement a short, one-line macro that accesses the UserName property of the Application object. This technique is detailed in a different issue of ExcelTips:

http://excelribbon.tips.net/T009814

That approach is great at determining the user name associated with the current installation of Excel. However, that may not be the same thing as who is using the current workbook. For instance, if the workbook is shared, it is possible that multiple people could be using it at the same time. In that case, you need a way to determine those names, as shown here:

Function UserNames() As String
    Dim Users As Variant
    Dim sMsg As String
    Dim iIndex As Integer

    Users = ActiveWorkbook.UserStatus

    For iIndex = 1 To UBound(Users, 1)
        sMsg = Users(iIndex, 1) & vbLf
    Next iIndex
    'remove final line feed
    sMsg = Left(sMsg, Len(sMsg) - 1)

    UserNames = sMsg
End Function

To use the function, just enter the following formula in the cell where you want the names to appear:

=UserNames

If you instead want to know who is using the computer currently, it is best to look beyond Office and instead grab the name from Windows itself. In that way you can determine who is logged in to Windows and use that as the user name. This takes an API function call declaration, but is otherwise relatively easy:

Private Declare Function GetUserName Lib "advapi32.dll" _
  Alias "GetUserNameA" (ByVal lpBuffer As String, nSize _
  As Long) As Long

Function UserName2() As String
    Dim strBuff As String * 100
    Dim lngBuffLen As Long

    lngBuffLen = 100
    GetUserName strBuff, lngBuffLen
    UserName2 = Left(strBuff, lngBuffLen - 1)
End Function

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12745) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Inserting the User's Name in a Cell.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He  is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Updating an Entire TOC from a Macro

The TOC (Table of Contents) is generated by a field. This field may be updated in a macro using a single command line.

Discover More

Printing All or Nothing

Want to make sure that when you worksheet is printed that everything in the workbook is really printed? You can ...

Discover More

Copying a Worksheet

Need to make a copy of one of your worksheets? Excel provides a few different ways you can accomplish the task.

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Drop-Down List Font Sizes

Excel has several features that cannot be customized. The font size in the drop-down lists is one of them. If you need ...

Discover More

Changing Your Name

One of the many pieces of information that Excel keeps track of is your name. If you want to change your name for Excel's ...

Discover More

Disappearing Status Bar

Ever had your Excel status bar disappear unexpectedly? Here's some ideas on why this may be happening.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is eight minus 1?

2017-09-15 02:49:11

lemmens freddy

Hé Eduaro, what a great idea ! It works fine for me, but I had to tick on 'Use relative Reference' and in the comment box I used Ctrl + Home and then Ctrl + Shift + End to select the whole name and then Ctrl + C. Thx again!


2017-08-02 14:34:17

Renam Eduardo Pereira

Hello everybody.
I found a way too simple to do that (I had searches in whole web, and no source code that I found did work for me.
So, I thought and I'e created a "recorded macro", like this:
a. Create a macro called "Username" (for example);
b. Go to the desired cell and add a comment.
Note that the first thing that appears is the username, right? Select it and CTRL+C
c. Return to the cell and paste the value.
d. Remove the comment
e. Stop the macro

So, you can do log control, user control, and so on.

I hope this help anyone here.

Best regards!
Eduardo


2017-01-11 08:53:21

Chris

How would the UserName2() code (and its Declaration stt's) need to be modified to support 64-bit Excel?

I've tried but using:

#If VBA7 Then
Private Declare PtrSafe Function GetUserName Lib "advapi32.dll" _
Alias "GetUserNameA" (ByVal lpBuffer As String, nSize As LongLong) As LongLong
#Else
Private Declare Function GetUserName Lib "advapi32.dll" _
Alias "GetUserNameA" (ByVal lpBuffer As String, nSize As Long) As Long
#EndIf

gets flagged for a compile error that I haven't been able to figure out.


2013-11-25 08:39:02

Bryan

You don't even need the API call. You can do the whole thing in a one-line macro:

Function UserName3() as String
UserName3 = Environ("UserName")
End Function


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.