Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 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: Counting the Times a Worksheet is Used.
Written by Allen Wyatt (last updated October 4, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
You may want a way to keep track of how many times a particular worksheet is used. There are many ways you can accomplish this. One simple way is to just store the count in the worksheet itself. Right-click a worksheet tab, then choose View Code from the Context menu. Excel displays the Visual Basic Editor, where you should paste the following code:
Private Sub Worksheet_Activate() Range("A1").Select 'customize Range ActiveCell = ActiveCell + 1 Range("B1") = "times opened" 'customize Range End Sub
This code increments the value in cell A1 every time the worksheet is activated. You can modify the cell locations where the macro writes its information, according to your needs.
A more thorough approach is to create a macro that increments named references within the workbook. Consider the following macro:
Function IncrementEventCounter(sName As String, sht As Object) On Error Resume Next If sht.Names(sName) Is Nothing Then _ ThisWorkbook.Names.Add "'" & sht.Name & "'!" & sName, "1", False On Error GoTo 0 With ThisWorkbook.Names("'" & sht.Name & "'!" & sName) .RefersTo = Val(Mid(.Value, 2)) + 1 End With End Function
This function is designed to be called from a different macro—one triggered by the event that should cause the usage counter to increment. For instance, if you want to keep track of every time the worksheet is activated, then you would use the following macro as part of the ThisWorkbook object:
Private Sub Workbook_SheetActivate(ByVal sh As Object) IncrementEventCounter "Activated", sh End Sub
The macro increments a counter named "Activated" for the worksheet. It does this by calling the IncrementEventCounter macro, with the name of the counter and the name of the worksheet. If, instead, you wanted to count the number of times that a worksheet was changed, you could use the following macro as part of the ThisWorkbook object:
Private Sub Workbook_SheetChange(ByVal sh As Object, _ ByVal Target As Excel.Range) IncrementEventCounter "Changed", sh End Sub
The only difference between this macro and the previous one is that it increments a counter named "Changed." To see the values of the counters, just enter a formula in a cell that references the counter. For instance, you could enter =Changed to see the value of the Changed counter, or =Activated to see the value of the Activated counter. The value of each counter will differ from sheet to sheet, since the counters are maintained on a sheet-by-sheet basis.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10544) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Counting the Times a Worksheet is Used.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
On your system you may have workbooks that contain macros you know are safe to use. Microsoft provides two things you can ...
Discover MoreDeveloping macros can be rewarding, but it can also be challenging. Getting individual macros to run properly is hard ...
Discover MoreWhen writing a macro, you may want to fill a range of cells with different values. The easiest way to do this is to use ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-10-06 05:02:39
Kiwerry
@J.Woolley: thanks for yours; I trust that you didn't take my comment as criticism; it was simply meant to inform.
2024-10-05 11:37:31
J. Woolley
@Kiwerry
The Q&A site I referenced 4 years ago was discontinued several years ago. The blog has not been updated since April 2023.
2024-10-04 04:31:19
Kiwerry
Update on J.Woolley's 2020 comment:
The link given produced, at best an "Under Construction" message; it also produced a security warning from Firefox. The main site (https://wellsr.com/vba/) is still easily available but I didn't see a link to "Q&A" or anything similar. It would be unfortunate if this were a permanent change in policy.
2020-08-21 10:15:23
J. Woolley
@Brendan
Yours would be a good question for wellsr VBA Q&A: https://ask.wellsr.com/vba
Be sure to cross-reference this Tip's web address.
2020-08-20 16:12:49
Brendan
At work we have a excel template that we use to print different labels for equipment. At the moment we use another spreadsheet to track how many of each piece of equipment we print labels for.
Would it be possible that each time we hit print on the label we can have another sheet in excel that would total up the different types Of equipment for so I can present this into graphs ?
Many thanks
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 © 2024 Sharon Parq Associates, Inc.
Comments