Written by Allen Wyatt (last updated September 30, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Renier has a workbook that has ten worksheets in it, named Resources 1 through Resources 10. If he deletes one of these worksheets (say, Resources 3), Renier would like the remaining worksheets to be renamed, automatically, to "close up the gap," so to speak. Thus, Resources 4 through Resources 10 would automatically rename to become Resources 3 through Resources 9.
There are several ways that you can go about this task, all through the use of macros. One approach is probably less automatic than what Renier would prefer, but it works great:
Sub ReNameSheets() Dim J As Integer Dim wks As Worksheet J = 0 For Each wks In ActiveWorkbook.Worksheets J = J + 1 wks.Name = "TempSheet " & J Next wks J = 0 For Each wks In ActiveWorkbook.Worksheets J = J + 1 wks.Name = "Resources " & J Next wks End Sub
This macro simply steps through all the worksheets, renaming them using the convention that Renier preferred. The macro could be run on demand, anytime a renaming of the worksheets is desired.
Note that the code actually makes two naming passes through the worksheets. The first one is to set the names of the worksheets to temporary names, and the second is to set them to final names. The two passes helps avoid a potential problem when you add worksheets to the workbook—for instance, if you add a new worksheet just before Resources 4, then a single-pass renaming would try to rename the new worksheet as Resources 4, which would generate an error because worksheet 5 would, at that point, also be named Resources 4. By doing two passes, you rename everything to something entirely new and then do the final name setting.
For a more automatic approach, you might want to consider using the SheetBeforeDelete event for the Workbook object. This event is triggered (as its name suggests) immediately before a worksheet is deleted. Here's an example of an event-handler approach:
Private Sub Workbook_SheetBeforeDelete(ByVal Sh As Object) Dim sPrefix As String Dim iNum1 As Integer Dim iNum2 As Integer Dim wks As Worksheet sPrefix = "Resources " If Left(Sh.Name, Len(sPrefix)) = sPrefix Then iNum1 = CInt(Right(Sh.Name, Len(Sh.Name) - Len(sPrefix))) Sh.Name = "TempSheet 9999" For Each wks In Sheets If Left(wks.Name, Len(sPrefix)) = sPrefix Then iNum2 = CInt(Right(wks.Name, Len(wks.Name) - Len(Prefix))) If iNum2 > iNum1 Then wks.Name = sPrefix & (iNum2 - 1) End If End If Next End If End Sub
The event handler checks to see if the worksheet being deleted begins with the designated prefix ("Resources "). If it does, then it renames the worksheet being deleted to a temporary name ("TempSheet 9999"). Then, it steps through each of the worksheets in the workbook and renames any worksheet that has the proper prefix and a higher suffix number than the worksheet that is being deleted.
There are two big caveats with this approach. First, it won't handle if you add worksheets. Second, it will only reliably handle the deletion of single worksheets. If you delete multiple worksheets at one time, the numbering will be incorrect and, in fact, the macro may crash because of the way in which Excel handles the deletions.
If you anticipate deleting multiple worksheets quite often, then you can sidestep the issue by using a different approach. This one relies on the use of the SheetActivate and SheetDeactivate events of the Workbook object.
' These variables are declared OUTSIDE of the events, ' so they are available globally. Dim shName As String Dim Avail As Variant Private Sub Workbook_SheetDeactivate(ByVal Sh As Object) ' When the worksheet is deactivated, the name of ' that worksheet is stored in the shName variable. shName = Sh.Name End Sub
Private Sub Workbook_SheetActivate(ByVal Sh As Object) Dim wks As Worksheet Dim J As Integer On Error Resume Next ' The following line will generate an error if the ' the worksheet shName was deleted. If the error ' occurrs, then we can trigger the renaming. Avail = Sheets(shName).Range("A1") If Err Then J = 0 For Each wks In ActiveWorkbook.Worksheets J = J + 1 wks.Name = "Resources " & J Next wks End If On Error GoTo 0 End Sub
These event handlers work because the SheetDeactivate event is triggered automatically whenever a worksheet is left (for example, when you activate a different worksheet) or whenever one is deleted. The SheetActivate event is then triggered and it checks, essentially, to see if the sheet previously deactivated can be reached or not. If it cannot be reached, then we know it was deleted and we can trigger a renaming of all the worksheets.
The approach you use to renaming is entirely up to you based on a determination of how you want to work with your worksheets.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13572) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
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!
Need to sort your worksheets so that they appear in an order determined by the value of a cell on each worksheet? Using a ...
Discover MoreYou can hide a bunch of worksheets at the same time, but Excel makes it much more difficult (depending on your version of ...
Discover MoreNot all spreadsheet programs are created equal; there are some things that can be done in others that can't be done in ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-10-03 10:13:59
J. Woolley
By the way, all of the VBA procedures previously discussed ignore chart sheets. To include chart sheets, substitute Sheets for each instance of Worksheets in my most recent Workbook_SheetActivate procedure below. There are 4 such instances.
2023-10-02 11:29:34
J. Woolley
Re. the Workbook_SheetActivate procedure in my comment below, this version might be more efficient:
Private Sub Workbook_SheetActivate(ByVal Sh As Object)
Dim n As Integer, nBeg As Integer, nEnd As Integer
Const baseName = "Resources ", tempName = "TempSheet "
nEnd = Worksheets.Count
For n = 1 To nEnd
If Worksheets(n).Name = baseName & n Then nBeg = n Else Exit For
Next n
If nBeg < nEnd Then nBeg = nBeg + 1 Else Exit Sub
For n = nBeg To nEnd
Worksheets(n).Name = tempName & n
Next n
For n = nBeg To nEnd
Worksheets(n).Name = baseName & n
Next n
End Sub
Using either version, when a single activate sheet is moved or renamed the sheets will not be renumbered until another sheet is activated.
2023-09-30 15:35:52
J. Woolley
The Tip's Workbook_SheetBeforeDelete event procedure has a typo plus other problems ("caveats").
The Tip's other pair of Workbook_... event procedures do not automatically rename sheets when a sheet is copied or a new sheet is added, but that new sheet might (or might not) be renamed when a sheet is deleted.
The following single event procedure is a better way; it is inspired by the Tip's first macro:
Private Sub Workbook_SheetActivate(ByVal Sh As Object)
Dim J As Integer, wks As Worksheet
J = 0
For Each wks In ActiveWorkbook.Worksheets
J = J + 1
wks.Name = "TempSheet " & J
Next wks
J = 0
For Each wks In ActiveWorkbook.Worksheets
J = J + 1
wks.Name = "Resources " & J
Next wks
End Sub
This addresses the Tip's caveats; it works when a sheet is added (or copied or moved) and when any number of sheets is deleted.
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