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: Hiding Columns Not within a Date Range.

Hiding Columns Not within a Date Range

Written by Allen Wyatt (last updated March 1, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


3

Jason has a worksheet that contains several columns, each of which represent a fiscal week for his company. These fiscal weeks begin with column G, with column H being the second fiscal week, column I being the third week, and so forth. Jason would like to create a macro that, when run, would look at today's date, calculate the fiscal week based on that date, and then hide any of the fiscal-week columns that are not within a specified range.

For the purposes of providing an answer, I'm going to assume that the range you want displayed will be equal to the 13 weeks (one quarter) immediately preceding the current fiscal week. With this in mind, there are a couple of things that must be done by the macro. First, it must determine what fiscal week it currently is. Then, it must hide all weeks not in the 13 weeks prior to this current fiscal week and unhide all those that are.

This is all relatively easy to do, with the exception of figuring out which fiscal week it currently is. The method of determining fiscal weeks can vary wildly from company to company. For simplicity's sake, however, I'm going to assume that the determination is fairly straightforward: divide the day of the year by seven and see what we have.

The following macro implements the approach discussed so far.

Sub HideWeeks()
    Dim BeginYear As Date           'start of fiscal year date
    Dim FirstWeekCol As Integer     'first fiscal week column
    Dim FirstShowWkCol As Integer   'first column to show
    Dim CurrWkCol As Integer        'current week column
    Dim J As Integer

    BeginYear = Cells(1, 1).Value
    FirstWeekCol = 7  'fiscal weeks begin with Col 7 (G)

    'Calculate Column of the current fiscal week
    CurrWkCol = ((Date - BeginYear) \ 7) + FirstWeekCol - 1
    'Calculate column of the first week to show
    FirstShowWkCol = CurrWkCol - 14
    If FirstShowWkCol < FirstWeekCol Then
        FirstShowWkCol = FirstWeekCol
    End If

    Application.ScreenUpdating = False

    'Unhide all columns
    Columns("G:IV").Hidden = False  'Unhide all week Columns

    'Hide week column before the rolling quarter
    For J = FirstWeekCol To FirstShowWkCol
        Columns(J).Hidden = True
    Next J

    'Hide week column after current week
    For J = CurrWkCol + 1 To 256
        Columns(J).Hidden = True
    Next J

    Application.ScreenUpdating = True
End Sub

Note that there is one value that must be grabbed from the worksheet in this macro: the last day of the prior year. It is assumed that this is in cell A1, and it is grabbed and placed in the BeginYear variable. This value is used to determine the day of the current year.

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 (9550) 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: Hiding Columns Not within a Date Range.

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 Default File Name

When you first save a new file, Word bases the name of that file on the contents of the start of the first paragraph in ...

Discover More

Copying Subtotals

If you have added subtotals to your worksheet data, you might want to copy those subtotals somewhere else. This is easy ...

Discover More

Changing App Notifications

Windows apps can communicate with you, keeping you up to date with whatever task they are designed to perform. If you get ...

Discover More

Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!

More ExcelTips (ribbon)

Widening Multiple Columns Proportionally

It is easy to adjust the width of columns in Excel. It is much harder to adjust the width of a range of columns ...

Discover More

Unhiding Columns that are Persistently Hidden

If you were trying to format a worksheet and nothing you did could make the first two columns appear, would you be ...

Discover More

Sizing Columns and Rows Using the Keyboard

Are you a keyboard-only user wondering how you can set column width or row height without using the mouse? This tip ...

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 five more than 3?

2023-03-09 08:10:02

Brian

Just to add to my comment from yesterday I realised it's even easier:

Range(Cells(1, FirstWeekCol), Cells(1, FirstShowWkCol).Address).EntireColumn.Hidden = True

Range(Cells(1, CurrWkCol + 1), Cells(1, 256).Address).EntireColumn.Hidden = True


2023-03-08 10:06:57

J. Woolley

@Brian
Or maybe just
Range(Columns(FirstWeekCol), Columns(FirstShowWkCol)).Hidden = True


2023-03-07 15:42:01

Brian

Wouldn't it much faster to hide the columns as range rather than in a loop, which we all know are quite slow?

I think the loop:

For J = FirstWeekCol To FirstShowWkCol
Columns(J).Hidden = True
Next J

Could be replaced with:

ColAddr = Right(Cells(1,FirstWeekCol).Address, Len(Cells(1,FirstWeekCol).Address) - 1)
FirstWeekStr = Left(ColAddr, InStr(1, ColAddr, "$", vbTextCompare) - 1)

ColAddr = Right(Cells(1,FirstShowWkCol).Address, Len(Cells(1,FirstShowWkCol).Address) - 1)
FirstShowWkStr = Left(ColAddr, InStr(1, ColAddr, "$", vbTextCompare) - 1)

Columns(FirstWeekStr & ":" & FirstShowWkStr).Hidden = True


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.