Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi,
I have two tables:
BLUE: Table used for Date slider/slicer
RED: Table used for all other dimensions/measures
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 !
Solved! Go to 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 ))
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
Proud to be a 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
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 ))
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
Proud to be a Super User!
Hi Saniat, take a look at the window function, some explanation is here:
https://www.sqlbi.com/articles/introducing-window-functions-in-dax/
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
101 | |
98 | |
97 | |
38 | |
37 |
User | Count |
---|---|
152 | |
121 | |
73 | |
71 | |
63 |