fbpx
Search
Close this search box.

Excel formula to convert calendar format to table

Share

Facebook
Twitter
LinkedIn

Ever have data in a calendar format and just wished you can get it in to tabular format? Something like this:

Calendar data to tabular format - Excel formula

You can use Excel formulas or Power Query to do this. In this article, let’s review formula based approach with two excellent choices.

Calendar to Table Formulas – Video

If you want to understand the formulas, watch below video or read on.

Using SUMIFS formula

We can use the SUMIFS formula to easily get data for any date, as it works with 2D ranges too.

Let’s say our calendar data is in the range B5:H16,

Use the formula =SUMIFS(B6:H16, B5:H15, “1-Aug-2020”) to get value corresponding to 1-Aug-2020.

Notice the difference between Sum range and Criteria range.

We move the sum range one row down so that we can look at dates above and get the corresponding value from below.

Limitations of SUMIFS approach:

  • Works only for numbers. If you have text values against each date, then this method will not work.
  • Can be wrong. Let’s say one of the values is 44044. Which is the number representation of 1-Aug-2020 (as Excel dates are just numbers. More on working with date & time here) Then our SUMIFS result will be wrong.

Learn more about SUMIFS formula.

Using INDEX formula

We can use INDEX formula to access any item in a range by specifying row & column numbers.

For example, =INDEX(A1:D10, 3,2) will return the value in 3rd row & 2nd column of A1:D10, ie B3 value.

So if we can calculate the row & column co-ordinates for a given date from our calendar, we can easily get the answer.

Column number: As our data is in a calendar format, each date will only fall in the column corresponding to the weekday number. We can use =WEEKDAY(input_date, 2) to get the column number, given that our calendar is from Monday to Sunday.

Row number: Once we know the column number, we can extract the entire column and look for given date in that column with MATCH function. This will give us the row number too. The below formula works fine.

=MATCH(input_date, INDEX(calendar_data, , WEEKDAY(input_date, 2)), 0)

Note: the internal INDEX() formula returns entire column as we omitted row parameter. Read up more on this functionality of INDEX formula.

Final formula:

Here is our final formula (with calendar in range B5:H16)

=INDEX($B$5:$H$16,
   MATCH(input_date,INDEX($B$5:$H$16,,WEEKDAY(input_date ,2)),0)+1,
   WEEKDAY(input_date, 2))

Related: Learn more about INDEX formula.

Download Example Workbook

Please click here to download the example file with calendar data to table format formulas. Examine the formulas or write your own to understand this technique.

Other ways to convert calendar format data

  • You can use Power Query to do this job. I highly recommend using PQ, if you deal with calendar style data often. Here is a primer on Power Query.
  • I have previously written about this problem (with SUMIFS solution) and asked my readers to share their formulas. You can see many other interesting & creative solutions here
  • VBA: You can use a simple macro to quickly reshape the data. This is a preferred option only if you can’t use Power Query. Here is a tutorial with such macro. The comments on this link also feature many Power Query based transformations.

How would you deal with calendar style data?

For something quick and easy, I will use formulas. For an on-going situation, I will use Power Query.

What about you? How would you deal with calendar style datasets? Please share your thoughts in the comments section.

Facebook
Twitter
LinkedIn

Share this tip with your colleagues

Excel and Power BI tips - Chandoo.org Newsletter

Get FREE Excel + Power BI Tips

Simple, fun and useful emails, once per week.

Learn & be awesome.

Welcome to Chandoo.org

Thank you so much for visiting. My aim is to make you awesome in Excel & Power BI. I do this by sharing videos, tips, examples and downloads on this website. There are more than 1,000 pages with all things Excel, Power BI, Dashboards & VBA here. Go ahead and spend few minutes to be AWESOME.

Read my storyFREE Excel tips book

Overall I learned a lot and I thought you did a great job of explaining how to do things. This will definitely elevate my reporting in the future.
Rebekah S
Reporting Analyst
Excel formula list - 100+ examples and howto guide for you

From simple to complex, there is a formula for every occasion. Check out the list now.

Calendars, invoices, trackers and much more. All free, fun and fantastic.

Advanced Pivot Table tricks

Power Query, Data model, DAX, Filters, Slicers, Conditional formats and beautiful charts. It's all here.

Still on fence about Power BI? In this getting started guide, learn what is Power BI, how to get it and how to create your first report from scratch.

6 Responses to “Excel formula to convert calendar format to table”

  1. Daniel Dion says:

    Here's another formula using one of your trick - https://chandoo.org/wp/extract-words-with-filterxml/

    =SORT(CHOOSE({1,2},FILTERXML("" & SUBSTITUTE(TEXTJOIN("|",,FILTER(TRANSPOSE(data),{1,0,1,0,1,0,1,0,1,0,1,0})),"|","") & "", "//n"),FILTERXML("" & SUBSTITUTE(TEXTJOIN("|",,FILTER(TRANSPOSE(data),{0,1,0,1,0,1,0,1,0,1,0,1})),"|","") & "", "//n")),1)

  2. slsuser says:

    Interesting.
    How about converting the other way, convert columns into calendar format?
    Perhaps I have a list of people with dates, like vacations or sales and I want to count or sum and place the results into a calendar format to see how may people are off that day or the total sales for the day.

  3. Please Calendar to Table using PQ. I am convince that it would be simpler!!!!

    Thanks Chandoo

  4. radhaaariv says:

    One of the best posts of today, impressive. Very interesting article. I learned many new things. I will definitely look into The Content Code. You elaborated on everything very well. It’s really an informative post. I found this article very helpful.

  5. Prasad says:

    Hi Team,

    I am big fan of this site, as I have picked alot of hidden uses and behaviour of basic formulaes also here.

    one observation in the above SUMIFS formula, what if any of the value under a date is equivalent to a date value, and if you wanted to value of the date, then it will give you incorrect answer.

    say 1 Aug has a value 44046. And I wanted to fetch the value of 3 Aug 2020. Then instead of 12181, it will show 44051 (actually 8th aug 2020 date)

    Regards,
    Prasad DN

Leave a Reply