Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365. 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

Written by Allen Wyatt (last updated May 31, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, and Excel in Microsoft 365


1

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:

https://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

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12745) 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: 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

Setting the AutoRecover Directory

When you are using Word, it normally saves temporary AutoRecover files that reflect the latest state of your document. If ...

Discover More

Inserting the Date Your Document Was Last Printed

Word keeps track of each time you print your document, and you can automatically insert the last printing date anywhere ...

Discover More

Changing the Background Color for a Comment

Comments are a great way to document your worksheets. Excel provides you the tools you need in order to format your ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Working in Feet and Inches

Your chosen occupation may require that you work with linear distances in feet and inches. Excel can do this, to a ...

Discover More

Synchronous Scrolling with More than Two Windows

Synchronous scrolling of different windows can be very helpful with some worksheets. Excel allows you to synchronize the ...

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
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}] (all 7 characters, in the sequence shown) 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 5 - 4?

2025-05-31 15:22:03

J. Woolley

My Excel Toolbox includes the following dynamic array function:
    =ListUserStatus([SkipHeader])
Login name, last activity (date/time), and type (exclusive/shared) are listed in 3 columns for each user that has the active workbook open. If SkipHeader is FALSE (default), the first row will be a header (User, Last Activity, Type).
This formula will list the login name of the Nth user who currently has the formula cell's workbook open:
    =INDEX(ListUserStatus(TRUE), N, 1)
Make N equal to 1 for the first (or only) user.
See https://sites.google.com/view/MyExcelToolbox/


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.