Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request now

Reply
Anonymous
Not applicable

Adding column for Rolling Average (6 month)

I need help to add a new column to my table that will show the 6 month rolling average.

Date column to use is M-Y and want to get 6 month rolling average of the Order Value

 

 

1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @Anonymous ,

Sorry for being late!
You can try this DAX:

_average = 
CALCULATE(
    AVERAGE('Table'[Order Value]),
    ALLEXCEPT('Table', 'Table'[Sold To Region]),
    DATESINPERIOD(
        'Table'[M-Y],
        LASTDATE('Table'[M-Y]),
        -6,
        MONTH
    )
)

And the final output is as below:

vjunyantmsft_0-1709511874528.png


Best Regards,
Dino Tao
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
Anonymous
Not applicable

Hi @Anonymous ,

Just as @lbendlin says, DAX will be much more easier.
Here is my sample data:

vjunyantmsft_0-1709266606782.png

1. Power Query solution:
Just put all of these M funxtions into the Advanced Editor:

let
    Source = Table.FromRows(Json.Document(Binary.Decompress(Binary.FromText("jdJBDoQgDAXQu7DWRApUXKrHMN7/GkP/QIZ8MZkFZuIbfkvxupwsIrMXN7m9rKTl4d099XCUJWkAZ1kx9xDmxVdIan8REsvyaQBWPbwBivTw69d+BRIUWV5AUL6XUDtWHCqSoLERnG1eDEfr+O8dVkMCQaxR2JEILArtMqBdep/qe7V5KsHZboQBw1IC7c+3DgBRDHuLYrDieRSFT2u0Y8fBA8naBMPKneS+r43AqgQl2GrWFr+f0VMwx4fgdoeCW2xp9wc=", BinaryEncoding.Base64), Compression.Deflate)), let _t = ((type nullable text) meta [Serialized.Text = true]) in type table [#"M-Y" = _t, #"Sold To Region" = _t, #"Order Value" = _t, #"Date Index" = _t]),
    #"Changed Type" = Table.TransformColumnTypes(Source,{{"M-Y", type date}, {"Sold To Region", type text}, {"Order Value", Int64.Type}, {"Date Index", Int64.Type}}),
    RollingAverage = Table.AddColumn(#"Changed Type", "Rolling Avg 6 Month", each List.Average(List.Transform(Table.SelectRows(#"Changed Type", (row) => row[#"M-Y"] <= [#"M-Y"] and row[#"M-Y"] > Date.AddMonths([#"M-Y"], -6))[Order Value], each _)))
in
    RollingAverage

The final output is as below:

vjunyantmsft_1-1709266681347.png


2. DAX solution:
Use this DAX to create a calculated column:

_average = 
CALCULATE(
    AVERAGE('Table'[Order Value]),
    ALL('Table'),
    DATESINPERIOD(
        'Table'[M-Y],
        LASTDATE('Table'[M-Y]),
        -6,
        MONTH
    )
)

The final output is as below:

vjunyantmsft_2-1709266759542.png


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

Anonymous
Not applicable

Hi v-junyant-msft, thank you for your response. What do I need to add to DAX to separate it by Sold To Region? Region A should have a different value than B, etc.

Anonymous
Not applicable

Hi @Anonymous ,

Sorry for being late!
You can try this DAX:

_average = 
CALCULATE(
    AVERAGE('Table'[Order Value]),
    ALLEXCEPT('Table', 'Table'[Sold To Region]),
    DATESINPERIOD(
        'Table'[M-Y],
        LASTDATE('Table'[M-Y]),
        -6,
        MONTH
    )
)

And the final output is as below:

vjunyantmsft_0-1709511874528.png


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

lbendlin
Super User
Super User

Does it have to be Power Query ? This would be much easier using the DAX WINDOW function.

Helpful resources

Announcements
November Power BI Update Carousel

Power BI Monthly Update - November 2025

Check out the November 2025 Power BI update to learn about new features.

Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.