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

Enhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.

Reply
OCBB_SFAFPandA
Resolver I
Resolver I

Rolling 26 week with week # in a date table

Hello, 

 

I have a week number in my date table, which is takes into account leap year. If I want to do a rolling 26 week sales calculation, how would I do that? Most of the articles I see use the DATEADD function, which doesn't include weeks.

 

My weeks always start on sundays, so I can't just have the last 7 days from a Thursday or so. Any suggestions? 

2 ACCEPTED SOLUTIONS
amitchandak
Super User
Super User

@OCBB_SFAFPandA , In you date table have these columns

 

new columns
Week Start date = 'Date'[Date]+-1*WEEKDAY('Date'[Date],2)+1
Week End date = 'Date'[Date]+ 7-1*WEEKDAY('Date'[Date],2)
Week Rank = RANKX(all('Date'),'Date'[Week Start date],,ASC,Dense)
OR
Week Rank = RANKX(all('Date'),'Date'[Year Week],,ASC,Dense) //YYYYWW format

 

then you can have measures
This Week = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])))
Last Week = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])-1))

 

Last  26 weeks = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]>=max('Date'[Week Rank])-26 && 'Date'[Week Rank]<=max('Date'[Week Rank])))

 

or

 

Last 26 weeks =
var _max1 = maxx(allselected('Table'), 'Table'[date])
var _max = maxx(filter(all(date), date[date] = _max1), week[Rank])
return
CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]>=_max-26 && 'Date'[Week Rank]<=_max))

 

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

View solution in original post

Anonymous
Not applicable

Hi @OCBB_SFAFPandA ,

 

Create calculated columns like below:

year_week = YEAR('Table'[date])*100+WEEKNUM('Table'[date],1)

week_rank = RANKX('Table',[year_week],,ASC,Dense)

vjaywmsft_0-1654675135701.png

Then create the rolling 26 week measure like below:

rolling_26_week =
SUMX (
    FILTER (
        ALLSELECTED ( 'Table' ),
        'Table'[week_rank] <= SELECTEDVALUE ( 'Table'[week_rank] )
            && 'Table'[week_rank]
                > SELECTEDVALUE ( 'Table'[week_rank] ) - 26
    ),
    'Table'[value]
)

vjaywmsft_1-1654675202972.png

 

Best Regards,

Jay

View solution in original post

3 REPLIES 3
Anonymous
Not applicable

Hi @OCBB_SFAFPandA ,

 

Create calculated columns like below:

year_week = YEAR('Table'[date])*100+WEEKNUM('Table'[date],1)

week_rank = RANKX('Table',[year_week],,ASC,Dense)

vjaywmsft_0-1654675135701.png

Then create the rolling 26 week measure like below:

rolling_26_week =
SUMX (
    FILTER (
        ALLSELECTED ( 'Table' ),
        'Table'[week_rank] <= SELECTEDVALUE ( 'Table'[week_rank] )
            && 'Table'[week_rank]
                > SELECTEDVALUE ( 'Table'[week_rank] ) - 26
    ),
    'Table'[value]
)

vjaywmsft_1-1654675202972.png

 

Best Regards,

Jay

amitchandak
Super User
Super User

@OCBB_SFAFPandA , In you date table have these columns

 

new columns
Week Start date = 'Date'[Date]+-1*WEEKDAY('Date'[Date],2)+1
Week End date = 'Date'[Date]+ 7-1*WEEKDAY('Date'[Date],2)
Week Rank = RANKX(all('Date'),'Date'[Week Start date],,ASC,Dense)
OR
Week Rank = RANKX(all('Date'),'Date'[Year Week],,ASC,Dense) //YYYYWW format

 

then you can have measures
This Week = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])))
Last Week = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]=max('Date'[Week Rank])-1))

 

Last  26 weeks = CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]>=max('Date'[Week Rank])-26 && 'Date'[Week Rank]<=max('Date'[Week Rank])))

 

or

 

Last 26 weeks =
var _max1 = maxx(allselected('Table'), 'Table'[date])
var _max = maxx(filter(all(date), date[date] = _max1), week[Rank])
return
CALCULATE(sum('Table'[Qty]), FILTER(ALL('Date'),'Date'[Week Rank]>=_max-26 && 'Date'[Week Rank]<=_max))

 

Share with Power BI Enthusiasts: Full Power BI Video (20 Hours) YouTube
Microsoft Fabric Series 60+ Videos YouTube
Microsoft Fabric Hindi End to End YouTube

Thanks Amitchandak!

 

The rank formula is something i needed, since I don't have access to the data for PQ. 

Is the solution provided able to get the running total?

For example

26weekago - 100

25weekago - 350 ( previous + current week)

24weekago - 1000 (previous + current)

.....

last week - x

 

I am looking to get this time of data on a table

Helpful resources

Announcements
July PBI25 Carousel

Power BI Monthly Update - July 2025

Check out the July 2025 Power BI update to learn about new features.

Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 community update carousel

Fabric Community Update - June 2025

Find out what's new and trending in the Fabric community.