cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
rsbin
Post Partisan
Post Partisan

Moving Average -> Standard Deviation

Good Morning,

Reaching out to the DAX experts out there.  I am trying to calculate the Standard Deviation of a Measure based on a 3 Day Moving Average (i.e. 3DayStdDev_EquipIDRatio).  My sample data looks like this:

DateGSIndexEquipmentIDCountTotalVisitsEquipmentIDRatio
8/1/201913079135550.227
8/2/201922931135240.217
8/3/20193103749970.208
8/4/2019463733260.192
8/5/20195232686190.270
8/6/201962908145990.199
8/7/201972994143830.208
DateGSIndex3DayEquipID3DayVisits3DayStdDev_EquipIDRatioStd. Dev Excel
8/1/20191    
8/2/20192    
8/3/2019370473207600.0080
8/4/2019446052184700.0104
8/5/2019540001694200.0338
8/6/2019658712654400.0353
8/7/2019782283760100.0314

 

EquipIDCount , TotalVisits and Equipment IDRatio are all Measures.

EquipIDRatio is a measure  - simply (EquipIDCount / TotalVisits).

3DayVisits and 3DayEquipID are moving average calculations wherein I use the Index to Sumx the 3 values (Current Day +2 prior days). 

I am able to calculate Standard Deviation on my database as a whole using this DAX provided by @Greg_Deckler and @az38 

 

 

 

StdDev_EquipIDRatio = 
VAR _table = SUMMARIZE(FILTER(GeneralStatistics, GeneralStatistics[TotalVisits] <> 0),[Date],"_EquipIDRatio",[EquipmentIDRatio])
RETURN STDEVX.P(_table,[_EquipIDRatio])

 

 

 

The Standard Deviation in the last column was calculated in Excel.  This is the number I am trying to replicate in DAX.  This number is the Standard Deviation of the EquipmentIDRatio of the current day + the previous 2 days.

So on day 3, I need to take the Ratio values from Day 1 - 3

On day 4, I need to take the Ratio values from Day 2 - 4. And so on.....

Since EquipIDRatio is a measure, to calculate Std Dev.,  I need to construct a virtual table as I have done above, but containing only the 3 relevant values for each Date or Index.  I have hit a wall and unable to figure out the correct way to do this in DAX.

Hoping one of you can point me in the right direction.

Thanks in advance and best regards,

 

1 ACCEPTED SOLUTION
Icey
Community Support
Community Support

Hi @rsbin ,

 

How about using ALLSELECTED in the expression?

3DayStdDev_EquipIDRatio =
VAR CurrentIndex =
    MAX ( GeneralStatistics[GSIndex] )
VAR PreviousIndex = CurrentIndex - 2
VAR _table =
    SUMMARIZE (
        FILTER (
            ALLSELECTED (GeneralStatistics ),   ------------------edited
            GeneralStatistics[TotalVisits] <> 0
                && GeneralStatistics[GSIndex] >= PreviousIndex
                && GeneralStatistics[GSIndex] <= CurrentIndex
        ),
        [Date],
        "_EquipIDRatio", [EquipmentIDRatio]
    )
RETURN
    STDEVX.P ( _table, [_EquipIDRatio] )

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

4 REPLIES 4
Icey
Community Support
Community Support

Hi @rsbin ,

 

How about this?

3DayStdDev_EquipIDRatio =
VAR CurrentIndex =
    MAX ( GeneralStatistics[GSIndex] )
VAR PreviousIndex = CurrentIndex - 2
VAR _table =
    SUMMARIZE (
        FILTER (
            GeneralStatistics,
            GeneralStatistics[TotalVisits] <> 0
                && GeneralStatistics[GSIndex] >= PreviousIndex
                && GeneralStatistics[GSIndex] <= CurrentIndex
        ),
        [Date],
        "_EquipIDRatio", [EquipmentIDRatio]
    )
RETURN
    STDEVX.P ( _table, [_EquipIDRatio] )

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

rsbin
Post Partisan
Post Partisan

Good Morning @Icey 

Thanks much for the reply.   I have attempted that code as as Solution, but it returns only an answer for the last date.

 

table soln 1.pngline chart.png

The ".03142" is the correct answer for Index = 7.   I too thought it would cycle through and provide an answer for each Index, but as you can from the above, it Returns just a single value.

I got up this morning thinking "CALCULATETABLE" might be the way to proceed.   Really appreciate you taking the time to respond. If you have further suggestions I would be grateful to hear them.  Kudos for the attempt.

 

Kind Regards,

Icey
Community Support
Community Support

Hi @rsbin ,

 

How about using ALLSELECTED in the expression?

3DayStdDev_EquipIDRatio =
VAR CurrentIndex =
    MAX ( GeneralStatistics[GSIndex] )
VAR PreviousIndex = CurrentIndex - 2
VAR _table =
    SUMMARIZE (
        FILTER (
            ALLSELECTED (GeneralStatistics ),   ------------------edited
            GeneralStatistics[TotalVisits] <> 0
                && GeneralStatistics[GSIndex] >= PreviousIndex
                && GeneralStatistics[GSIndex] <= CurrentIndex
        ),
        [Date],
        "_EquipIDRatio", [EquipmentIDRatio]
    )
RETURN
    STDEVX.P ( _table, [_EquipIDRatio] )

 

 

Best Regards,

Icey

 

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

rsbin
Post Partisan
Post Partisan

Good Morning @Icey 

 

Yes, the edit works.  I finally am able to get the Std. Dev values for each Index.   Thank you very much for the assistance.

 

Unfortunately, still having some issues having it display properly in my line charts.   I have to figure out why it is behaving like that.

But thanks again, it is a relief to finally solve the first part of this.

 

Kind Regards and all the best,

Helpful resources

Announcements
UG GA Amplification 768x460.png

Launching new user group features

Learn how to create your own user groups today!

Power BI October Update 2021.jpg

Power BI Release

Click here to read more about the October 2021 Release!

Community Connections 768x460.jpg

Community & How To Videos

Check out the new Power Platform Community Connections gallery!

Teds Dev Camp Oct. 2021 768x460.jpg

Power BI Dev Camp - October 28th, 2021

Mark your calendars and join us for our next Power BI Dev Camp!