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.
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
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:
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.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
If you develop applications or add-ins using VBA, you may want to create a help file that supports your project. This tip ...
Discover MoreNamed ranges are great, but they don't move when you sort data. If you want them to move, it is helpful to remember that ...
Discover MoreAll the rave these days seems to be displaying information in either "light mode" or "dark mode." If you are interested ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
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/
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments