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
big_ozzie1
Frequent Visitor

Max of rolling average expression

I have a measure that returns the 7-day rolling average for the Training Load metric. It is working just fine:

 

 

7dayRA = 
VAR numdays = 7
VAR _sum = CALCULATE(SUM('RPE/Wellness'[Training Load]),DATESINPERIOD('RPE/Wellness'[date], LASTDATE('RPE/Wellness'[date]),-numdays, DAY))
RETURN _sum / numdays

 

 

I want to find the max of the rolling average result set. You see below it is 197.14.

big_ozzie1_1-1682977069883.png

I have tried:

 

Test1 = CALCULATE(MAXX(VALUES('RPE/Wellness'), [7dayRA]))

 

and

 

Test2 = CALCULATE(MAXX('RPE/Wellness', [7dayRA]))

 

 

You see their results in the table. These are the solutions I have found in forums, but neither returns the result 197.14 I am looking for.

2 ACCEPTED SOLUTIONS

Hi,

These measures work

TL = SUM('RPE/Wellness'[Training Load])
TL in previous week = CALCULATE([TL],DATESBETWEEN('Date'[Date],MIN('Date'[Date])-6,min('Date'[Date])))
7 day rolling average = if(ISBLANK([TL]),BLANK(),DIVIDE([TL in previous week],7))
All time high rolling average = if(ISBLANK([TL]),BLANK(),MAXX(ALL('Date'),[7 day rolling average]))

Also, to the visul, drag Date from the Date Table.

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

View solution in original post

Hi @big_ozzie1 

 

This time I totalled the Training Load for the last 7 days and divided it by 7.  (It appears to be what you were doing with your [7dayRA] only using a date table to account for missing dates.)

 

My RA = 
VAR _CurrDt = SELECTEDVALUE( 'Date'[Date] )
VAR _LastWk = _CurrDt - 7
VAR _SumOfLastWk =
    CALCULATE(
        [Total],
        FILTER(
            ALL( 'Date'[Date] ),
            'Date'[Date] > _LastWk
                && 'Date'[Date] <= _CurrDt
        )
    )
RETURN
    _SumOfLastWk / 7

 

 

(Note: Looking at rolling totals sorted descendingly seems to be counter-intuitive for me.  If it was me, I'd only look at the dates in a descending order AFTER I was convinced they worked in ascending order.  But that's just my opinion.)

 

pbix: Help - mine.pbix

 

Let me know how this goes.

 

(Also, my apologies to @Ashish_Mathur  since I had came up with my solution last night I didn't see your almost identical solution. )

 

View solution in original post

8 REPLIES 8
amitchandak
Super User
Super User

@big_ozzie1 , You should always use date table in such cases. Try like

 

7dayRA =
VAR numdays = 7
return CALCULATE(AVERAGEX(Values(Date[Date]), calculate(SUM('RPE/Wellness'[Training Load]))),DATESINPERIOD('Date'[date], Max('Date'[date]),-numdays, DAY))

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

Thanks very much for the response. This works with the MAXX function, but unfortunately your rolling average calculation does not take null days into account. The application here is sports, so I need to account for days with no data as well.

For example, for this table, the 7-day rolling average should be 111.43. With yours it is 260.

DateTraining Load
8/8/2022  300
8/7/2022 
8/6/2022  240
8/5/2022 
8/4/2022  240
8/3/2022 
8/2/2022 

Is there any way around the blank data issue? Thanks!

Hi @big_ozzie1 

Would something like this help?

 

Total = SUM( 'RPE/Wellness'[Training Load] )

My RA = 
VAR _Days = 7
VAR _CurrDt = SELECTEDVALUE( 'Date'[Date] )
VAR _LastWk = _CurrDt - _Days
VAR _Result =
    AVERAGEX(
        FILTER(
            ALL( 'Date'[Date] ),
            'Date'[Date] >= _LastWk
                && 'Date'[Date] <= _CurrDt
        ),
        [Total]
    )
RETURN
    _Result / _Days


Max of RA = 
    MAXX(
        ALL( 'Date'[Date] ),
        [My RA]
    )

 

 

In this pbix, I looked at 2 different methods.  (I originally thought that you weren't worried about the dates with no values.)

 

pbix: MAX of 7-day Rolling Average.pbix

 

Hi @grantsamborn 

Thank you as well for the help. This is very close. You will see below your rolling average output (My RA) versus desired (7dayRA):

big_ozzie1_0-1682988902696.png

 

Your rolling average values mostly divide evenly into the desired values, strangely. One would think this observation would result in a speedy fix, though it appears I'm not yet savvy enough to figure out what's going on. Maybe you can figure it out?

Let's start at the beginning.

 

Can you show the following?

 

1)  Please provide sample data that covers your issue or question completely. 

(I hate retyping sample data.)
https://community.powerbi.com/t5/Community-Blog/How-to-provide-sample-data-in-the-Power-BI-Forum/ba-...

 

2) Please show the expected outcome based on the sample data you provided.
https://community.powerbi.com/t5/Desktop/How-to-Get-Your-Question-Answered-Quickly/m-p/1447523

 

3) Please explain how you would expect to get from 1) to 2).

 

I would like to see a) your expected result AND b) how you intend to use it.

 

Thank you for your patience. I, too, hate retyping this data. The attached PBI file should satisfy your request.

https://actionapps-my.sharepoint.com/:u:/g/personal/sam_osborne_actionapps_co_uk/EdMWEpYWru1KiclTc1Z... 

Hi @big_ozzie1 

 

This time I totalled the Training Load for the last 7 days and divided it by 7.  (It appears to be what you were doing with your [7dayRA] only using a date table to account for missing dates.)

 

My RA = 
VAR _CurrDt = SELECTEDVALUE( 'Date'[Date] )
VAR _LastWk = _CurrDt - 7
VAR _SumOfLastWk =
    CALCULATE(
        [Total],
        FILTER(
            ALL( 'Date'[Date] ),
            'Date'[Date] > _LastWk
                && 'Date'[Date] <= _CurrDt
        )
    )
RETURN
    _SumOfLastWk / 7

 

 

(Note: Looking at rolling totals sorted descendingly seems to be counter-intuitive for me.  If it was me, I'd only look at the dates in a descending order AFTER I was convinced they worked in ascending order.  But that's just my opinion.)

 

pbix: Help - mine.pbix

 

Let me know how this goes.

 

(Also, my apologies to @Ashish_Mathur  since I had came up with my solution last night I didn't see your almost identical solution. )

 

Hi,

These measures work

TL = SUM('RPE/Wellness'[Training Load])
TL in previous week = CALCULATE([TL],DATESBETWEEN('Date'[Date],MIN('Date'[Date])-6,min('Date'[Date])))
7 day rolling average = if(ISBLANK([TL]),BLANK(),DIVIDE([TL in previous week],7))
All time high rolling average = if(ISBLANK([TL]),BLANK(),MAXX(ALL('Date'),[7 day rolling average]))

Also, to the visul, drag Date from the Date Table.

Hope this helps.

Untitled.png


Regards,
Ashish Mathur
http://www.ashishmathur.com
https://www.linkedin.com/in/excelenthusiasts/

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.