Gilbert has a worksheet (named "Control") that contains a list of desired worksheet names in cells A1:A12. He needs a way, in a macro, to rename each of the other 12 worksheets in the workbook based upon that range of cells. The worksheet names don't need to be dynamic; they just need to be renamed when he runs the macro.
The core of developing a macro to address this need is to rely on the Name property of each worksheet you want to rename. For instance, you could use a very simple macro like this:
Sub RenameSheets() Dim c As Range Dim J As Integer J = 0 For Each c In Range("A1:A12") J = J + 1 If Sheets(J).Name = "Control" Then J = J + 1 Sheets(J).Name = c.Text Next c End Sub
The macro simply steps through the cell range A1:A12 and, if the next worksheet isn't named "Control," it renames the worksheet to the cell value.
As noted, this macro is very simplistic and should, in all likelihood, be a lot more robust. For instance, what should be done if there are more (or fewer) than 13 worksheets in the current workbook? What should be done if there are empty cells in the range A1:A12? What should be done if someone runs the macro and "Control" isn't the active worksheet? What should be done if there are two identical values in A1:A12? What if there are leading or trailing spaces on one or more names in the range A1:A12? These and (most likely) a whole range of other questions can affect how the macro finally looks. Here's a commented version of the macro that takes into account several of the possibilities just mentioned:
Sub RenameSheets() Dim c As Range Dim J As Integer Dim K As Integer Dim sName As String Dim w(12) As String Dim bGo As Boolean Dim sTemp As String bGo = True If Worksheets.Count <> 13 Then ' Check to make sure exactly 13 worksheets in workbook bGo = False sTemp = "There are more than 13 worksheets." End If If ActiveSheet.Name <> "Control" Then ' Check to make sure Control is active bGo = False sTemp = "Control worksheet is not active." Else ' Check for empty and duplicate cells in range J = 0 For Each c In Range("A1:A12") sName = Trim(c.Text) If sName <> "" Then For K = 1 to J If LCase(w(K)) = LCase(sName) Then bGo = False sTemp = "Duplicate sheet names in list." End If Next K If bGo Then ' Everything still good; add name J = J + 1 w(J) = sName End If End If Next c End If If bGo Then K = 0 For J = 1 To 12 K = K + 1 If Sheets(K).Name = "Control" Then K = K + 1 Sheets(K).Name = w(J) Next J Else MsgBox(sTemp) End If End Sub
Notice how much longer the second version of the macro is than the first? Anytime you start adding multiple checks in a macro, it can really make it much longer than without the checks. The benefit in adding the checks, of course, is that your macro is less likely to run into problems as it is used by people other than you.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (1506) applies to Microsoft Excel 2007, 2010, 2013, and 2016.
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!
Macros are great for working with strings, and one of the most commonly used string functions is Len. This tip explains ...
Discover MoreA common part of working with text strings in a worksheet is normalizing those strings so that they follow whatever rules ...
Discover MoreOne of the most common ways of creating macros is to use Excel's macro recorder. This tip shows how easy it is to use the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-11-26 08:32:44
HC&TS (Hans Hallebeek)
One important additional routine you should include and seriously keep in mind if the length of the proposed (new) worksheet name, it should NOT exceed 31 characters
2021-11-25 09:27:34
Jad
Hello Allen,
Thank you for the macro, and all the tips and information you put on your site.
I have one question about the macro here, I might have missed the point but I see that you set J = 0 and then for in the loop K = 1 to J, but I do not see were the upper limit for J is set.
Thank you in advance for your clarification
2018-07-02 06:57:19
piyush
Wow... loved the code. Thanks a ton.
2018-06-28 18:44:39
Kuldeep
Did not work
Gave subscript out of range error
Sheets(j).name=c.text
KD
2018-06-19 11:31:29
Rob
Amazing, worked first time! Thanks so much
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 © 2022 Sharon Parq Associates, Inc.
Comments