Power BI is turning 10! Tune in for a special live episode on July 24 with behind-the-scenes stories, product evolution highlights, and a sneak peek at what’s in store for the future.
Save the dateEnhance your career with this limited time 50% discount on Fabric and Power BI exams. Ends August 31st. Request your voucher.
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?
Solved! Go to Solution.
@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))
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)
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]
)
Best Regards,
Jay
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)
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]
)
Best Regards,
Jay
@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))
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
Check out the July 2025 Power BI update to learn about new features.
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
User | Count |
---|---|
20 | |
7 | |
6 | |
5 | |
5 |
User | Count |
---|---|
26 | |
10 | |
10 | |
9 | |
6 |