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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

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

 

View solution in original post

v-jayw-msft
Community Support
Community Support

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

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

3 REPLIES 3
v-jayw-msft
Community Support
Community Support

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

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.
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))

 

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
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors