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: Sheets for Days.

Sheets for Days

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


3

When you are starting a new workbook, it is very common to name each worksheet after a different day of the month. If you do this quite a bit, you know it can be tiresome to rename each worksheet, individually, to exactly what you need.

The following macro was developed to help in these situations. It checks the names of the worksheets in your workbook, renaming them to the days of the month if they begin with the letters "Sheet". If there are not enough sheets in the workbook, it adds sheets, as necessary, for each day of the month.

Sub DoDays()
    Dim J As Integer
    Dim K As Integer
    Dim sDay As String
    Dim sTemp As String
    Dim iTarget As Integer
    Dim dBasis As Date

    iTarget = 13
    While (iTarget < 1) Or (iTarget > 12)
        iTarget = Val(InputBox("Numeric month?"))
        If iTarget = 0 Then Exit Sub
    Wend

    Application.ScreenUpdating = False
    sTemp = Str(iTarget) & "/1/" & Year(Now())
    dBasis = CDate(sTemp)
    
    For J = 1 To 31
        sDay = Format((dBasis + J - 1), "dddd mm-dd-yyyy")
        If Month(dBasis + J - 1) = iTarget Then

            If J <= Sheets.Count Then
                If Left(Sheets(J).Name, 5) = "Sheet" Then
                    Sheets(J).Name = sDay
                Else
                    Sheets.Add.Move after:=Sheets(Sheets.Count)
                    ActiveSheet.Name = sDay
                End If
            Else
                Sheets.Add.Move after:=Sheets(Sheets.Count)
                ActiveSheet.Name = sDay
            End If
        End If
    Next J

    For J = 1 To (Sheets.Count - 1)
        For K = J + 1 To Sheets.Count
            If Right(Sheets(J).Name, 10) > _
              Right(Sheets(K).Name, 10) Then
                Sheets(K).Move Before:=Sheets(J)
            End If
        Next K
    Next J

    Sheets(1).Activate
    Application.ScreenUpdating = True
End Sub

Note that the macro assumes that the month for which you want worksheets is in the current year. If that is not the case, you'll need to make one small change. Note the following line near the beginning of the macro:

    sTemp = Str(iTarget) & "/1/" & Year(Now())

Let's say that you actually want the month to be in 2015 for some reason. Just change the line to the following:

    sTemp = Str(iTarget) & "/1/2015"

The macro sets each tab name equal to the day of the week followed by the actual date, as in "Wednesday 03-28-2020." If you want to change the way that the tabs are named for each day, just change how the sDay variable is constructed in the macro.

The last step in the macro is that it places the worksheets in proper order, based on the days of the month. The result is that if you have any other worksheets left in the workbook (in other words, you had some that did not begin with the letters "Sheet," then those worksheets end up at the end of the workbook, after the sheets for each day.

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 (11523) 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: Sheets for Days.

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

Changing the Formatting of All Instances of a Word

Need to find all the instances of a particular word and change the formatting of those instances? It's easy to do using ...

Discover More

Trimming Off All Spaces

The easy way to get rid of spaces at the beginning or end of a cell's contents is to use the TRIM function. ...

Discover More

Limiting Printing to a Workbook from a Set Location

When you share workbooks on a company server, it can be frustrating if the workbooks are downloaded to individual ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Referencing Worksheet Tabs

Ever want to use the name of a worksheet tab within a cell? Here's how you can access that information using the CELL ...

Discover More

Quickly Inserting a New Worksheet

Want a quick way to insert a worksheet? There's nothing faster than using the handy shortcut.

Discover More

Limiting How Many Times a Worksheet Can Be Calculated

Excel, by default, recalculates your worksheets as you make changes in those worksheets. If you want to limit the number ...

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 two more than 7?

2021-04-30 06:09:03

Willy Vanhaelen

@Cam
I don't know if your request is still valid but here it is:

Sub doDays()
Dim D As Integer, M As Integer
M = Val(InputBox("Numeric month?"))
If M < 1 Or M > 12 Then Exit Sub
For D = 1 To Day(DateSerial(Year(Now), M + 1, 0))
Worksheets("Template").Copy before:=Sheets("Template") ').Name = S
ActiveSheet.Name = Format(DateSerial(Year(Now), M, D), "ddd mm.dd.yy")
Next D
End Sub

Note that my 9 lines macro does the job equally well as the 42 lines macro in this tip.
If your template worksheet has another name, just replace "Template" in the macro with "your name".


2021-01-05 13:54:45

Cam

Can this be modified to create the sheets from a template?


2020-08-12 20:02:16

Giancarlo

Hi Allen, I appreciate your macro post above. I copied and pasted in Visual Basic (firs time using it) and I'm almost there to get what I need but not quite. I have a master worksheet log which I need to complete every day of the year Monday-Friday and I would like that master worksheet copied exactly for every day of every month of the year and again the same thing for all of 2021. After I copied the macro you posted above, my master was showing under the August 1, 2020 tab. I would appreciate your help


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.