Skip to content
xlsoffice. All Rights Reserved
  • Home
  • Excel For Beginners
  • Excel Intermediate
  • Advanced Excel For Experts

Lookup and Reference Examples

  • How to get last row in text data in Excel
  • How to get address of first cell in range in Excel
  • How to use Excel TRANSPOSE Function
  • Count unique text values with criteria
  • MATCH function: Description, Usage, Syntax, Examples and Explanation

Data Analysis Examples

  • Managing Conditional Formatting Rules in Excel
  • How to create dynamic reference table name in Excel
  • How to Create One and Two Variable Data Tables in Excel
  • Example of COUNTIFS with variable table column in Excel
  • Randomize/ Shuffle List in Excel

Data Validation Examples

  • Excel Data validation must contain specific text
  • Excel Data validation number multiple 100
  • How To Create Drop-down List in Excel
  • Excel Data validation with conditional list
  • Excel Data validation whole percentage only

Steps to create Dynamic calendar grid in Excel

by

This tutorial show how to  create Dynamic calendar grid in Excel using the example below.

You can set up dynamic calendar grid on an Excel worksheet with a series of formulas, as explained in this article.

Explanation of how this formula works

In the example shown, the formula in B6 is:

=start-CHOOSE(WEEKDAY(start),0,1,2,3,4,5,6)

where “start” is the named range K5, and contains the date September 1, 2018.

Note: This example assumes the start date will be provided as the first of the month. See below for a formula that will dynamically return the first day of the current month.

With the layout of grid as shown, the main problem is calculate the date in the first cell in the calendar (B6). This is done with this formula:

=start-CHOOSE(WEEKDAY(start),0,1,2,3,4,5,6)

This formula figures out the Sunday prior to the first day of the month by using the CHOOSE function to “roll back” the right number of days to the previous Sunday. CHOOSE works perfectly in this situation, because it allows arbitrary values for each day of the week. We use this feature to roll back zero days when the first day of the month is a Sunday. More details about this problem are provided here.

Worked Example:   Dynamic date list in Excel

With the first day established in B6, the other formulas in the grid simply increment the previous date by one, beginning with the formula in C6:

=IF(B6<>"",B6,$H5)+1

This formula tests the cell immediately to the left for a value. If no value is found, it pulls a value from column H in the row above. Note $H5 is a mixed reference, to lock the column as the formula is copied throughout the grid. The same formula is used in all cells except B6.

Conditional formatting rules

The calendar uses conditional formatting formulas change formatting to shade previous and future months, and to highlight the current day. Both rules are applied to the entire grid. For for previous and next months, the formula is:

Worked Example:   Get age from birthday in Excel
=MONTH(B6)<>MONTH(start)

For current day, the formula is:

=B6=TODAY()

Calendar heading

The calendar title – month and year – are calculated with this formula in cell B4:

=start

Formatted with the custom number format “mmmm yyyy”. To center the title above the calendar, the range B4:H4 has horizontal alignment set to “center across selection”. This is a better option than merge cells, since it doesn’t alter the grid structure in the worksheet.

Perpetual calendar with current date

To create a calendar that updates automatically based on the current date, you can use formula like this in K5:

=EOMONTH(TODAY(),-1)+1

This formula gets the current date with the TODAY function, then gets the first day of the current month using the EOMONTH function. Replace TODAY() with any given date to build a calendar in a different month. More details on how EOMONTH works here.

Worked Example:   Get first Monday before any date in Excel

Follow steps below to create Dynamic calendar grid

  1. Hide grid lines (optional)
  2. Add a border to B5:H11 (7R x 7C)
  3. Name K5 “start” and enter date like “September 1, 2018”
  4. Formula in B4 =start
  5. Format B4 as “mmmm yyyy”
  6. Select B4:H4, set alignment to “Center across selection”
  7. In range B5:H5, enter day abbreviations (SMTWTFS)
  8. Formula in B6 =start-CHOOSE(WEEKDAY(start),0,1,2,3,4,5,6)
  9. Select B6:H11, apply custom number format “d”
  10. Formula in C6 =IF(B6<>””,B6,$H5)+1
  11. Copy formula in C6 to remaining cells in calendar grid
  12. Add Prev/Next conditional formatting rule (see formula above)
  13. Add Current conditional formatting rule (see formula above)
  14. Change date in K5 to another “first of month” date to test
  15. For perpetual calendar, formula in K5 =EOMONTH(TODAY(),-1)+1

Post navigation

Previous Post:

Count birthdays by month in Excel

Next Post:

Get days, months, and years between dates in Excel

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Learn Basic Excel

Ribbon
Workbook
Worksheets
Format Cells
Find & Select
Sort & Filter
Templates
Print
Share
Protect
Keyboard Shortcuts

Categories

  • Charts
  • Data Analysis
  • Data Validation
  • Excel Functions
    • Cube Functions
    • Database Functions
    • Date and Time Functions
    • Engineering Functions
    • Financial Functions
    • Information Functions
    • Logical Functions
    • Lookup and Reference Functions
    • Math and Trig Functions
    • Statistical Functions
    • Text Functions
    • Web Functions
  • Excel VBA
  • Excel Video Tutorials
  • Formatting
  • Grouping
  • Others
  • Remove text by matching in a cell in Excel
  • How to Separate Text Strings in Excel
  • How to extract word containing specific text in Excel
  • How to strip html from text or numbers in Excel
  • Split dimensions into three parts in Excel
  • Get day from date in Excel
  • Convert text timestamp into time in Excel
  • Display the current date and time in Excel
  • DATEVALUE function: Description, Usage, Syntax, Examples and Explanation
  • Extract date from a date and time in Excel
  • COUPDAYS function: Description, Usage, Syntax, Examples and Explanation
  • Calculate periods for annuity in Excel
  • Bond valuation example in Excel
  • ODDLPRICE function: Description, Usage, Syntax, Examples and Explanation
  • XNPV function: Description, Usage, Syntax, Examples and Explanation
Acronyms, Abbreviations, Initialism & What They Stand For
© 2021 xlsoffice. All Rights Reserved | Teal Smiles