Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Be one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now

Reply
SSJ011
Frequent Visitor

Leap year week number

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

 

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

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] )

week1.JPG

week2.JPG

 

 

Best regards

Icey

 

If this post helps, then consider Accepting it as the solution to help other members find it faster.

View solution in original post

3 REPLIES 3
Icey
Community Support
Community Support

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] )

week1.JPG

week2.JPG

 

 

Best regards

Icey

 

If this post helps, then consider Accepting it as the solution to help other members find it faster.

ryan_mayu
Super User
Super User

@SSJ011 

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?

1.PNG

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.

1.PNG

 

 





Did I answer your question? Mark my post as a solution!

Proud to be a Super User!




amitchandak
Super User
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

 

 

Join us as experts from around the world come together to shape the future of data and AI!
At the Microsoft Analytics Community Conference, global leaders and influential voices are stepping up to share their knowledge and help you master the latest in Microsoft Fabric, Copilot, and Purview.
️ November 12th-14th, 2024
 Online Event
Register Here

Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.

ArunFabCon

Microsoft Fabric Community Conference 2025

Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.

December 2024

A Year in Review - December 2024

Find out what content was popular in the Fabric community during 2024.