Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now
Good Day ,
Happy New year to all.
My week number ends in 52 of every year except leap year. Need your assistance in getting the week number for weeks starting on Monday.
As 2020 was a leap year there are 53 weeks and 1st Jan to 3rd Jan will be part of a 53 week. Can you advise which DAX function should be used to solve this, as weeknum function is not giving the correct answer.
Regards
Sachin
Solved! Go to Solution.
Hi @SSJ011 ,
Please check if this is what you want:
Calendar =
ADDCOLUMNS (
CALENDAR ( DATE ( 2020, 1, 1 ), DATE ( 2021, 12, 31 ) ),
"Year", YEAR ( [Date] ),
"WeekDay", WEEKDAY ( [Date], 2 ),
"WeekNum", WEEKNUM ( [Date], 2 )
)
Modified WeekNum 1 =
VAR FirstDay =
CALCULATE (
MIN ( 'Calendar'[Date] ),
FILTER ( 'Calendar', 'Calendar'[Year] = EARLIER ( 'Calendar'[Year] ) )
)
VAR MinYear =
MIN ( 'Calendar'[Year] )
RETURN
IF (
[Year] = MinYear,
[WeekNum],
COUNTROWS (
FILTER (
SELECTCOLUMNS (
GENERATESERIES ( FirstDay, 'Calendar'[Date] ),
"Dates", [Value]
),
WEEKDAY ( [Dates], 2 ) = 1
)
)
)
Modified WeekNum 2 =
VAR MaxWeekNumLastYear =
CALCULATE (
MAX ( [Modified WeekNum 1] ),
FILTER ( 'Calendar', 'Calendar'[Year] = EARLIER ( 'Calendar'[Year] ) - 1 )
)
RETURN
IF ( [Modified WeekNum 1] = BLANK (), MaxWeekNumLastYear, [Modified WeekNum 1] )
Best regards
Icey
If this post helps, then consider Accepting it as the solution to help other members find it faster.
Hi @SSJ011 ,
Please check if this is what you want:
Calendar =
ADDCOLUMNS (
CALENDAR ( DATE ( 2020, 1, 1 ), DATE ( 2021, 12, 31 ) ),
"Year", YEAR ( [Date] ),
"WeekDay", WEEKDAY ( [Date], 2 ),
"WeekNum", WEEKNUM ( [Date], 2 )
)
Modified WeekNum 1 =
VAR FirstDay =
CALCULATE (
MIN ( 'Calendar'[Date] ),
FILTER ( 'Calendar', 'Calendar'[Year] = EARLIER ( 'Calendar'[Year] ) )
)
VAR MinYear =
MIN ( 'Calendar'[Year] )
RETURN
IF (
[Year] = MinYear,
[WeekNum],
COUNTROWS (
FILTER (
SELECTCOLUMNS (
GENERATESERIES ( FirstDay, 'Calendar'[Date] ),
"Dates", [Value]
),
WEEKDAY ( [Dates], 2 ) = 1
)
)
)
Modified WeekNum 2 =
VAR MaxWeekNumLastYear =
CALCULATE (
MAX ( [Modified WeekNum 1] ),
FILTER ( 'Calendar', 'Calendar'[Year] = EARLIER ( 'Calendar'[Year] ) - 1 )
)
RETURN
IF ( [Modified WeekNum 1] = BLANK (), MaxWeekNumLastYear, [Modified WeekNum 1] )
Best regards
Icey
If this post helps, then consider Accepting it as the solution to help other members find it faster.
I have some questions about this.
Does your week always have 7 days?
What about the first week of 2021?
2021 is not a leap year. Will 2021/12/27-2022/1/2 be in the same week?
What's more, I am not sure about your mininum date in your data. if your date starts on 2020/1/1. The first week only contains 5 days.
Proud to be a Super User!
@SSJ011 , Try these columns
Week Start date = 'Date'[Date]+-1*WEEKDAY('Date'[Date],2)+1 //use 1 for sunday week WEEKDAY('Date'[Date],1)
Week End date = 'Date'[Date]+ 7-1*WEEKDAY('Date'[Date],2) //use 1 for sunday week
min week start of year = minx(filter('Date',year([Week Start date])=earlier(year(Week Start date]))),[Week Start date])
week No = quotient(datediff([min week start of year],[date],day),7)+1
Check if the Week no is what you are looking at
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
93 | |
85 | |
83 | |
72 | |
49 |
User | Count |
---|---|
142 | |
139 | |
110 | |
69 | |
55 |