Let’s say you have daily data and your boss wants to see the trends by week of month or week of quarter? How do you calculate the week number of month or quarter? In this article, let me explain the logic and formulas we can use Excel for this.
Why calculate week in month or quarter?
Calculating “week of month” or “week of quarter” let’s us see trends by week in across months or quarters. Answering business questions like,
- How many customers we had in first of week January vs. first week of February?
- What are the total reservations in first 4 weeks of Q1 vs. first 4 weeks of Q3?
- Cumulative weekly totals for March vs. June
is easier when you have the week of month and week of quarter available in your data.
Step 1: Calculate the WEEKNUM in year
Before we can calculate the weeknum in a month or quarter, we need to do two other important calculations. The first one of them is WEEKNUM in year.
Add a column adjacent to your data and use the below formula to calculate the weeknumber in year.
=WEEKNUM(B4,2)
This assumes your date is in the cell B4 and your week begins on Monday. If you want to do the analysis from SUNDAY start, just use =WEEKDAY(B4)
Step 2: Calculate the MONTH number
Our next formula is to figure out which month we are in. Add another column adjacent to your data and use this formula.
=MONTH(B4)
At this stage your data should look like this:
Step 3: Calculate Week in Month
Now that we know the “week in year” and “month number”, we can easily calculate the week in month using below formula.
=D4-WEEKNUM(DATE(YEAR(B4),E4,1),2)+1
How this “week in month” formula works?
- D4 has the weeknumber in year
- E4 has the month number
- DATE(YEAR(B4),E4,1) tells us the first date of the month (for example, all dates in JAN 2024 will have this as 1-Jan-2024)
- WEEKNUM(DATE(YEAR(B4),E4,1),2) will give us the weeknumber for that date (with Monday start)
- D4-WEEKNUM(DATE(YEAR(B4),E4,1),2)+1 finally tells us the weeknumber of the month (we need to add +1 so that the first week of month will be 1 instead of 0)
[Optional] Step 4: Formula for Week in Quarter
If you need to calculate the “Week in Quarter” for some analysis, you can use the below formula to do that.
=D4-WEEKNUM(DATE(YEAR(B4),INT((E4-1)/3)*3+1,1),2)+1
How this “week in quarter” formula works?
- D4 has the weeknumber in year
- E4 has the month number
- INT((E4-1)/3)*3+1 calculates the first month of the quarter (so months 1,2,3 ? 1, 4,5,6 ? 4 … )
- DATE(YEAR(B4),INT((E4-1)/3)*3+1,1) tells us the first date of the quarter (for example, all dates in JAN, FEB, MAR 2024 will have this as 1-Jan-2024)
- WEEKNUM(DATE(YEAR(B4),INT((E4-1)/3)*3+1,1),2) will give us the weeknumber for that date (with Monday start)
- D4-WEEKNUM(DATE(YEAR(B4),INT((E4-1)/3)*3+1,1),2)+1 finally tells us the weeknumber of the quarter (we need to add +1 so that the first week of quarter will be 1 instead of 0)
What if I want Sunday Week Start?
If your week starts on Sunday, you can use the below formulas instead.
'For Week in year
=WEEKNUM(B4)
'For Month number
=MONTH(B4)
'For week in month
=D4-WEEKNUM(DATE(YEAR(B4),E4,1))+1
'For week in quarter
=D4-WEEKNUM(DATE(YEAR(B4),INT((E4-1)/3)*3+1,1))+1
For weeks beginning on other days (such as Friday start)
You just need to pass the type of week start to the WEEKNUM() function. Refer to below table to find what you need to use.
Download Sample File with Weeknumber Formulas
If you are having trouble implementing the formulas, refer to free example workbook. It has all the formulas for,
- Calculating week number in year
- Month number
- Week of month
- Week of quarter
In conclusion…
Calculating “week of month” and “week of quarter” is relatively simple and easy process with Excel. Once you have the values in your data, you can use them to better understand the trends across months or quarters. If you have the data in a table, then applying and maintaining these formulas is easy too, as Excel tables auto-extend the formulas for all cells.
Few additional tips to take this idea further:
- Integrate these calculations into Power Query: If you are bringing external data into Excel through Power Query, try adding these columns with Power Query “Add column” feature. Learn more about Power Query here.
- Use a separate calendar table: If you have too many rows of transactional data (like tickets or sales), then instead of calculating the week number for every row, use a calendar table and do the calculations there. After that use “data modeling” feature of Excel to link calendar table to your transactional data. This way you can combine data from both tables in your pivot reports. Learn more about calendar tables and data modeling feature.
Other ways to work with dates
Please refer to these tutorials and examples to solve other date problems in Excel.
5 Responses to “How to calculate WEEKNUMBER in Month / Quarter / Year with Excel?”
dear Chandoo,
I have found anothet solution for calculating the weeknumers in a month:
=SWITCH(ROUNDUP(MONTH(B4)/3,0),1,WEEKNUM(B4,2),2,WEEKNUM(B4,2)-13,3,WEEKNUM(B4,2)-26,4,WEEKNUM(B4,2)-39)
Do you think this is an OK-formula?
YS
I assume you meant this was a formula for weeknumber in a quarter.
The switch formula is ALMOST equivalent. But, check out what happens if you use the dates in 2018. Specifically, when the first day of the quarter is the last day of the 13th week. Then you are off by one for a few months.
Also, another note, you can simplify your formula by taking the weeknum out of the switch. Then by realizing that you are just taking the switch value times 13:
=WEEKNUM(B5,2)-13*(ROUNDUP(MONTH(B5)/3,0)-1)
This doesn't fix the inaccuracy of the formula, but it does make it simpler!
Interesting find. In the case 2018, what should be the week number for that first day (assuming your week starts on Monday)? Logically it should be 1. But if we alter the definition of week number to "weeks in a month / quarter always begin on the first monday of the period", then the number I've calculated is wrong. In this case, you can use ISOWEEKNUM instead of WEEKNUM.
I may have been defining weeks differently. I assumed a week that started in March, but ended in April would be week 13 of quarter 1, but the end of it would be week 1 of quarter 2, and thus you may only have a couple of days in week 1 of the quarter (or month).
To be clear, I calculated it the same way you did @Chandoo. I was replying to @Kees when seeing the issue in 2018 with his formula.
Another nuance or potential factor is that we may not consider the first day of a month/quarter to be part of the first week of that month/quarter if it falls on a Friday or Saturday (maybe not even a Thursday). In other words, in some contexts, we might expect a week to contain a certain number of days to be counted as an actual week in a given period. And if we are operating in a business context, then it might even be a minimum number of weekdays.
Consider November 2024 as an example where the first day is a Friday. Would we say that November 1 and 2 are part of the first week in November, or would we say they're really part of the last week in October? In such cases, a formula like this one, using 3 as the minimum number of weekdays to constitute a week and "focal" as the date in question, could provide an adjusted week number.
=LET(
focal,DATE(2024,11,2),
minday,3,
dayone,EOMONTH(focal,-1)+1,
firstfri,WORKDAY.INTL(EOMONTH(dayone,-1),1,"1111011"),
wknum,ISOWEEKNUM(focal)-ISOWEEKNUM(dayone)+1,
out,IF(NETWORKDAYS(dayone,firstfri)<minday,wknum-1,wknum),
out
)
With November 2 as the focal date, this formula returns 0 to indicate the date is actually part of the final week of the previous month. If focal were DATE(2024,11,18), then the answer would be 3.
A variation on this idea would be wanting to know the date of the Friday in the second week of August. Not the second Friday in August, but the Friday of the second week in August. For 2024, that would be August 16.
=LET(
dayone,DATE(2024,8,1),
minday,3,
weekend,REPLACE("1111111",5,1,"0"),
firstfri,WORKDAY.INTL(EOMONTH(dayone,-1),1,weekend),
target,WORKDAY.INTL(EOMONTH(dayone,-1),2,weekend),
out,IF(NETWORKDAYS(dayone,firstfri)<minday,target+7,target),
out
)