cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
jsflint
Frequent Visitor

Exponential Moving Average in Power Query M ?

Hello! How can an exponential moving average be created in Power Query M?  I already know how to do this in Excel, and DAX can be a pain in the tail.  Here's a table of example data.  Thank you!

 

Date Value
1/1/2021 0.888073856
1/2/2021 0.087243733
1/3/2021 0.597531606
1/4/2021 0.25492501
1/5/2021 0.836644673
1/6/2021 0.253785258
1/7/2021 0.757333787
1/8/2021 0.958886707
1/9/2021 0.598108137
1/10/2021 0.180565909
1/11/2021 0.788755716
1/12/2021 0.888126908
1/13/2021 0.231740519
1/14/2021 0.107410191
1/15/2021 0.648458581
1/16/2021 0.582213204
1/17/2021 0.191300599
1/18/2021 0.864502562
1/19/2021 0.583108477

3 ACCEPTED SOLUTIONS
Fowmy
Super User IV
Super User IV

@jsflint 

Can you share the expected value based on the sample data that you have given?

You can save the  Excel file with the results in One Drive or Google Drive and share the link 


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

Proud to be a Super User!

Website   YouTube    LinkedIn   Join my Power BI User

View solution in original post

jsflint
Frequent Visitor

@jsflint 

Please find attached the PBIX file below my signature with the desired results. Basically, the solution involves a recursive operation to calculate the EMA ( Exponential Moving Average in Power Query ).

There are two columns, Average and EMA.

Fowmy_0-1623575302534.png

Complete M Code:

let
  Source = Table.FromRows(
    Json.Document(
      Binary.Decompress(
        Binary.FromText(
          "VZLbbQRBCARz2e+TD5p3LNbln4Y5adnB3yVmmqJ/fy9+8xsEvl4X/Qghwwp2fV5fhIPY3BERuJEchFRIROmN9CAXB2Ua38gOSmEmS5Ib+UGVIdIobxQHGbsEdFLkIqlM7E/2Wu+hxDV5AjIdFmUIE58YvHQwJZX1d8OWD3PWkqL5jpeQTsim5jVsGSEEzEzGCC8lkZbO5bMdLydiZar8+OfYc17gHhy2tDi+xjrMsOVF4CQVz3WwvGSHJCedOfA+Qh8uO+qw5YWCoBJDdk24L+TBswGWFe3FJeMxhl2UXlz6eHMhbCtpndGmKFhSssvaZdYnypJC3YYyz4fVv4aBvOt8fT5/",
          BinaryEncoding.Base64
        ),
        Compression.Deflate
      )
    ),
    let
      _t = ((type nullable text) meta [Serialized.Text = true])
    in
      type table [Date = _t, Value = _t]
  ),
  #"Changed Type" = Table.TransformColumnTypes(
    Source,
    {{"Date", type date}, {"Value", type number}}
  ),
  Step1 = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
  Step2 = Table.AddColumn(
    Step1,
    "Average",
    each if [Index] > 6 then List.Average(List.Range(Step1[Value], _[Index] - 7, 7)) else null
  , type number),
  Step3 = Table.AddColumn(
    Step2,
    "EMA",
    each
      if [Index] > 6 then
        let
          start = List.First(List.RemoveNulls(Step2[Average])),
          vlist = List.Range(Step2[Value], 8, _[Index] - 7),
          acc = List.Accumulate(
            vlist,
            start,
            (state, current) => (current - state) * (2 / (1 + 7)) + state
          )
        in
          if [Index] = 7 then start else acc
      else
        null,
  type number )
in
    Step3

 

 

 





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

Proud to be a Super User!

Website   YouTube    LinkedIn   Join my Power BI User

View solution in original post

4 REPLIES 4
Fowmy
Super User IV
Super User IV

@jsflint 

Can you share the expected value based on the sample data that you have given?

You can save the  Excel file with the results in One Drive or Google Drive and share the link 


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

Proud to be a Super User!

Website   YouTube    LinkedIn   Join my Power BI User

View solution in original post

jsflint
Frequent Visitor

@jsflint 

Please find attached the PBIX file below my signature with the desired results. Basically, the solution involves a recursive operation to calculate the EMA ( Exponential Moving Average in Power Query ).

There are two columns, Average and EMA.

Fowmy_0-1623575302534.png

Complete M Code:

let
  Source = Table.FromRows(
    Json.Document(
      Binary.Decompress(
        Binary.FromText(
          "VZLbbQRBCARz2e+TD5p3LNbln4Y5adnB3yVmmqJ/fy9+8xsEvl4X/Qghwwp2fV5fhIPY3BERuJEchFRIROmN9CAXB2Ua38gOSmEmS5Ib+UGVIdIobxQHGbsEdFLkIqlM7E/2Wu+hxDV5AjIdFmUIE58YvHQwJZX1d8OWD3PWkqL5jpeQTsim5jVsGSEEzEzGCC8lkZbO5bMdLydiZar8+OfYc17gHhy2tDi+xjrMsOVF4CQVz3WwvGSHJCedOfA+Qh8uO+qw5YWCoBJDdk24L+TBswGWFe3FJeMxhl2UXlz6eHMhbCtpndGmKFhSssvaZdYnypJC3YYyz4fVv4aBvOt8fT5/",
          BinaryEncoding.Base64
        ),
        Compression.Deflate
      )
    ),
    let
      _t = ((type nullable text) meta [Serialized.Text = true])
    in
      type table [Date = _t, Value = _t]
  ),
  #"Changed Type" = Table.TransformColumnTypes(
    Source,
    {{"Date", type date}, {"Value", type number}}
  ),
  Step1 = Table.AddIndexColumn(#"Changed Type", "Index", 0, 1, Int64.Type),
  Step2 = Table.AddColumn(
    Step1,
    "Average",
    each if [Index] > 6 then List.Average(List.Range(Step1[Value], _[Index] - 7, 7)) else null
  , type number),
  Step3 = Table.AddColumn(
    Step2,
    "EMA",
    each
      if [Index] > 6 then
        let
          start = List.First(List.RemoveNulls(Step2[Average])),
          vlist = List.Range(Step2[Value], 8, _[Index] - 7),
          acc = List.Accumulate(
            vlist,
            start,
            (state, current) => (current - state) * (2 / (1 + 7)) + state
          )
        in
          if [Index] = 7 then start else acc
      else
        null,
  type number )
in
    Step3

 

 

 





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

Proud to be a Super User!

Website   YouTube    LinkedIn   Join my Power BI User

View solution in original post

jsflint
Frequent Visitor

Hey @Fowmy , first of all the code you sent works awesome!  However, I've been ultimately trying to create a Triple Exponential Moving Average, and I figure I could just reuse a good part of the code to create a second and third EMA then calculate a final column to create a TEMA.  It's not working out for me right now, and I'd greatly appreciate your assistance again.  I've attached another sample Excel file that includes date, value, average, ema1,  ema2,  ema3, and Tema columns.  The formulas are present, and hopefully makes sense.  Thanks again!!!

 

TEMA 

Helpful resources

Announcements
PBI User Groups

Welcome to the User Group Public Preview

Check out new user group experience and if you are a leader please create your group!

MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Top Kudoed Authors