cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
rigosakhx
Helper I
Helper I

Moving monthly average by Item

Hi all,

I have a table with the list of items and sales by month. How do I calculated monthly rolling average (3 month) by Item? I am trying to create a calcultated column. The example of data is show below

I found a few threads suggesting using AVERAGEX and DATESINPERIOD using calendar table. This does work but doesn't give me data by Part ID. 

 

Part IDMonthSalesMoving month average (3M)
AAA1Jan110 
AAA1Feb100 
AAA1Mar90 
AAA1Apr77 
AAA1May555 
AAA2Jan200 
AAA2Feb100 
AAA2Mar222 
AAA2Apr350 
AAA2May110 
1 ACCEPTED SOLUTION
RicoZhou
Community Support
Community Support

Hi @rigosakhx 

My sample table:

1.png

I build a Month table and related two tables by month columns.

2.png

Calculated column:

MonthNo = RELATED('Month'[MonthNo])
Moving Month Average (3M) =
AVERAGEX (
    FILTER (
        'Table',
        'Table'[MonthNo] <= EARLIER ( 'Table'[MonthNo] )
            && 'Table'[MonthNo]
                >= EARLIER ( 'Table'[MonthNo] ) - 2
            && 'Table'[Part ID] = EARLIER ( 'Table'[Part ID] )
    ),
    'Table'[Sales]
)

Result is as below.

3.png

You can download the pbix file from this link: Moving monthly average by Item

 

Best Regards,

Rico Zhou

 

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
RicoZhou
Community Support
Community Support

Hi @rigosakhx 

My sample table:

1.png

I build a Month table and related two tables by month columns.

2.png

Calculated column:

MonthNo = RELATED('Month'[MonthNo])
Moving Month Average (3M) =
AVERAGEX (
    FILTER (
        'Table',
        'Table'[MonthNo] <= EARLIER ( 'Table'[MonthNo] )
            && 'Table'[MonthNo]
                >= EARLIER ( 'Table'[MonthNo] ) - 2
            && 'Table'[Part ID] = EARLIER ( 'Table'[Part ID] )
    ),
    'Table'[Sales]
)

Result is as below.

3.png

You can download the pbix file from this link: Moving monthly average by Item

 

Best Regards,

Rico Zhou

 

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

I havent tested it yet, but it looks like exactly what I was looking for. Thank you!

rigosakhx
Helper I
Helper I

Hi Amit

 

It does work for a measure but not for a calculated column

amitchandak
Super User
Super User

@rigosakhx , Try like this example with date table

 

Rolling 3 = divide( CALCULATE(sum(Sales[Sales]),DATESINPERIOD('Date'[Date ],MAX('Date'[Date]),-3,MONTH)) ,
CALCULATE(distinctCOUNT('Date'[Month Year]),DATESINPERIOD('Date'[Date],MAX('Date'[Date]),-3,MONTH), not(isblank((Sales[Sales])))))

 

or

CALCULATE(Average(Sales[Sales]),DATESINPERIOD('Date'[Date ],MAX('Date'[Date]),-12,MONTH))



Power BI Features || Datamarts: https://youtu.be/8tskWsJTEpg || Field Parameters : https://youtu.be/lqF3Wa1FllE?t=70
Time Intelligence Decoded : https://youtu.be/aU2aKbnHuWs&t=145s
Did I answer your question? Mark my post as a solution! Appreciate your Kudos !! Proud to be a Super User! !!
Dashboard of My Blogs !! Connect on Linkedin !! Subscribe to my youtube Channel !!
Want To Learn Power BI | Beginners !! Advance Concepts !! Power BI For Tableau User !!

Helpful resources

Announcements
August 1 episode 9_no_dates 768x460.jpg

The Power BI Community Show

Watch the playback when Priya Sathy and Charles Webb discuss Datamarts! Kelly also shares Power BI Community updates.

Power BI Dev Camp Session 24 without aka link and time 768x460.jpg

Ted's Dev Camp - July 28, 2022

Watch Session 24 of Ted's Dev Camp along with past sessions!

Power Platform Conf 2022 768x460.jpg

Join us for Microsoft Power Platform Conference

The first Microsoft-sponsored Power Platform Conference is coming in September. 100+ speakers, 150+ sessions, and what's new and next for Power Platform.

Top Solution Authors
Top Kudoed Authors