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
Saniat
Helper V
Helper V

Rolling average Last Month and Current Month

Hi,

I have two tables:

BLUE: Table used for Date slider/slicer
RED: Table used for all other dimensions/measures


temp.PNG



I am plotting 'sum of flag' in a timeline.

I wish to plot rolling average of 'this month and last month' in the timeline.

That means for January: 5 is okay.
For February: it should be (5+4) / 2 = 4.5
For March: (4+3)/2 = 3.5

Can someone please help me with that.


Thanks !

1 ACCEPTED SOLUTION

Hi @Saniat ,

Sorry about that, try this:

myMeasure = 
VAR _monthNumberCurrent =    MAX ( mytable[monthNumber] ) //get the month number from this row

var _thisMonthFlag = MAX(myTable[Flag])
VAR _prevMonthNumber =
    CALCULATE (
        MAX ( mytable[monthNumber] ),
        FILTER ( ALL ( myTable ), myTable[monthNumber] < _monthNumberCurrent )
    ) //filter the table to all month numbers less than this month number, and get the max value which is the month before

var _lastMonthFlag = CALCULATE(MAX(myTable[Flag]),FILTER(ALL(myTable),myTable[MonthNumber]=_prevMonthNumber))

RETURN
    DIVIDE ( _thisMonthFlag + _lastMonthFlag, IF(_lastMonthFlag = 0,1,2 ))

Nathaniel_C_0-1690227407911.png


Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos 👍are nice too.
Nathaniel

 





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

Proud to be a Super User!




View solution in original post

4 REPLIES 4
Nathaniel_C
Super User
Super User

Hi @Saniat  @JohnShepherdAPD ,
If I understand your issue correctly, please try this measure:

myMeasure =
VAR _monthNumberCurrent =
    MAX ( mytable[monthNumber] ) //get the month number from this row
VAR _prevMonthNumber =
    CALCULATE (
        MAX ( mytable[monthNumber] ),
        FILTER ( ALL ( myTable ), myTable[monthNumber] < _monthNumberCurrent )
    ) //filter the table to all month numbers less than this month number, and get the max value which is the month before
RETURN
    DIVIDE ( _monthNumberCurrent + _prevMonthNumber, 2 )


Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos 👍are nice too.
Nathaniel





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

Proud to be a Super User!




Hi @Nathaniel_C ,

Thanks for this.

I am actually looking for average of [Flag] on those months ...

In the timeline on the right bottom corner ...
For February: it should be (5+4) / 2 = 4.5
For March: (4+3)/2 = 3.5

The final measure will be 2 months rolling average ...

Many thanks

Hi @Saniat ,

Sorry about that, try this:

myMeasure = 
VAR _monthNumberCurrent =    MAX ( mytable[monthNumber] ) //get the month number from this row

var _thisMonthFlag = MAX(myTable[Flag])
VAR _prevMonthNumber =
    CALCULATE (
        MAX ( mytable[monthNumber] ),
        FILTER ( ALL ( myTable ), myTable[monthNumber] < _monthNumberCurrent )
    ) //filter the table to all month numbers less than this month number, and get the max value which is the month before

var _lastMonthFlag = CALCULATE(MAX(myTable[Flag]),FILTER(ALL(myTable),myTable[MonthNumber]=_prevMonthNumber))

RETURN
    DIVIDE ( _thisMonthFlag + _lastMonthFlag, IF(_lastMonthFlag = 0,1,2 ))

Nathaniel_C_0-1690227407911.png


Let me know if you have any questions.

If this solves your issues, please mark it as the solution, so that others can find it easily. Kudos 👍are nice too.
Nathaniel

 





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

Proud to be a Super User!




JohnShepherdAPD
Helper II
Helper II

Hi Saniat, take a look at the window function, some explanation is here:

https://www.sqlbi.com/articles/introducing-window-functions-in-dax/

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.