Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, and 2016. 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

by Allen Wyatt
(last updated December 5, 2015)

16

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

The macro sets each tab name equal to the day of the week followed by the actual date, as in "Wednesday 03-28-2012." 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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11523) applies to Microsoft Excel 2007, 2010, 2013, and 2016. 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

Precisely Adjusting Table Column Widths

If you want to resize the width of your table columns, you can do it using a mouse, but you can get more precise widths by ...

Discover More

Using Object Anchors

An object anchor is used to signify the point at which an object is inserted into a document. If you want to see these ...

Discover More

Putting a Chart Legend On Its Own Page

Displaying information using charts in Excel is easy and there are a variety of chart styles to choose from. Integrated into ...

Discover More

Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!

More ExcelTips (ribbon)

Colors and Fonts for Worksheet Tabs

Changing the color used on a worksheet tab is easy. Just follow the three steps in this tip.

Discover More

Ordering Worksheets Based on a Cell Value

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 More

Freezing Top Rows and Bottom Rows

Freezing the top rows in a worksheet so that they are always visible is easy to do. Freezing the bottom rows is not so easy. ...

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 8Mpixels. 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 7 - 0?

2017-08-04 11:54:12

Willy Vanhaelen

The macro in this tip adds the day sheets to an existing workbook which makes it rather complex.

When you often need a new workbook with only the sheets named after each day then this much shorter macro will do the job:

Sub DoDays()
Dim D As Date, M As String, X As Integer
again:
M = InputBox("Enter date of wanted month i.e. 1/1/2018")
If M = "" Then Exit Sub
If Not IsDate(M) Then GoTo again
If Len(M) < 6 Then GoTo again
Workbooks.Add
X = Day(DateSerial(Year(M), Month(M) + 1, 0))
Sheets.Add Count:=X - Sheets.Count, after:=Sheets(Sheets.Count)
D = DateSerial(Year(M), Month(M), 0)
For X = 1 To X
Sheets(X).Name = Format(D + X, "ddd dd-mm-yy")
Next X
End Sub

Of course can can change the string in Format ("ddd dd-mm-yy") to whatever you like i.e. "ddd mm-dd-yy" for the US.

If you prefer to exclude weekends then you can use this one:

Sub DoDaysNoWE()
Dim D As Date, M As String, N As Integer, X As Integer, Y As Integer
again:
M = InputBox("Enter date of wanted month i.e. 1/1/2018")
If M = "" Then Exit Sub
If Not IsDate(M) Then GoTo again
If Len(M) < 6 Then GoTo again
Workbooks.Add
N = Day(DateSerial(Year(M), Month(M) + 1, 0))
D = DateSerial(Year(M), Month(M), 0)
For X = 1 To N
If Weekday(D + X, 2) < 6 Then
Y = Y + 1
Sheets(Y).Name = Format(D + X, "ddd dd-mm-yy")
End If
If Y = Sheets.Count Then Exit For
Next X
For X = X + 1 To N
If Weekday(D + X, 2) < 6 Then
Sheets.Add(after:=Sheets(Sheets.Count)).Name = Format(D + X, "ddd dd-mm-yy")
End If
Next X
End Sub


2017-08-01 14:47:30

John I

@john & @Scott Jones
The following modified macro does what you are asking.
Added:
yyear = Val(InputBox("Numeric year? example 2019", , 2017))
Modified:
sTemp = Str(iTarget) & "/1/" & Year(Now())
TO:
sTemp = Str(iTarget) & "/1/" & yyear



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

yyear = Val(InputBox("Numeric year? example 2019", , 2017))

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/" & yyear
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


2017-07-31 16:13:14

john

This is very helpful for me, but I am wondering if you might be able to provide an additional component or simple work around. This macro only accommodates the current year. If I am working in December 2017, and want to create a workbook for 2018, Is there a line of code that would ask for the year, as well as the month?


2017-03-16 14:21:39

Scott Jones

Mr. Wyatt,

This is very helpful for me, but I am wondering if you might be able to provide an additional component or simple work around. This macro only accommodates the current year. If I am working in December 2017, and want to create a workbook for 2018, Is there a line of code that would ask for the year, as well as the month?

Regards,

Scott


2017-01-06 15:57:13

Arie Holt

great tip!!! thanks


2017-01-05 09:11:59

Marcel

Hi,
How can I remove holidays displayed in a worksheet?
Sincerely, Marcel.


2016-12-01 16:27:02

Mandy V

Thank you so much for the tip! I'm having a problem of it adding tabs instead of re-naming the tabs I already have even though I have plenty of tabs for the month. It only does this for 4 of the tabs. Any idea why this might happen?

This wouldn't be a problem if it would copy an existing tab instead of inserting a brand new tab. I need the exact same formatting and formulas in each tab.

Thank you very much!


2016-11-22 16:33:04

J Iddings

@Jordan,
See my previous post dated 17 Jan 2016, 20:55 for creating sheets for weekdays only, not including Saturdays & Sundays


2016-11-21 13:56:53

Jordan

@ Willy Vanhaelen.

Thank you for the help, yours didn't work, but it led me to find this replacement.

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

Does anyone know how to remove the weekends and only have a 5 day week? I am just manually deleting Sat/Sun now so no big deal.

Thank you and thanks to the OP for sharing this great tip!


2016-11-12 06:08:06

Willy Vanhaelen

@Jordan

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

To: sTemp = Str(iTarget) & "/1/2017")


2016-11-11 10:47:01

Jordan

How do I change to 2017?


2016-10-18 23:41:33

Khneoh CHee Yang

how if i want to copy for the first sheet


2016-08-10 11:52:11

Josh

So I'm basically making a checklist workbook that needs to be completed by the end of each day of a given month. This macro is great for creating and naming the worksheets, but is there a way to insert the checklist as well? Here is how I was planning on setting it up:

I would have a reference sheet, called "Checklist" hidden in the workbook. The workbook will have this hidden sheet and it will also have a blank "Sheet1". Basically, I want to be able to run this macro at the beginning of the month and, when it creates the new sheets, have it also populate the sheet with a mirror of the reference "Checklist" sheet.

Is this possible? Any help would be much appreciated!


2016-03-04 11:18:35

Kel

Hi, i can only get it to work for Jan. If i put other months integer e.g. 2 or 3, nothing happens.


2016-01-17 20:55:00

J Iddings

@Erica,
Try this modified for creating sheets for weekdays only, not including Saturdays & Sundays.
It worked for me.

Sub DoDays1()
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 = dBasis + J - 1 '<---- added for eliminating Saturdays & Sundays
If Weekday(sDay) <> 1 Then '<---- added for eliminating Saturdays & Sundays
If Weekday(sDay) <> 7 Then '<---- added for eliminating Saturdays & Sundays

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

End If '<---- added for eliminating Saturdays & Sundays
End If '<---- added for eliminating Saturdays & Sundays
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


2016-01-16 21:25:36

erica

How would I change this so it only creates sheets for weekdays and not include weekends?


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.