cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
Krish89
Helper II
Helper II

12 months rolling average

Hi,

I have a sales table with the last 5years data and the table look like below.

I would like to calculate the rolling average of last 12 months based on the selected date from date table in the slicer and PeriodTypeId = 2.

For Example: If I select 2020-05 in the slicer, I should get the rolling average of last 12 months (2020-04 to 2019-05)

The rolling average should be calculated only for the PeriodTypeId=2

Krish89_0-1624357257541.png

 

Thanks in advance!

 

 

1 ACCEPTED SOLUTION
v-janeyg-msft
Community Support
Community Support

Hi, @Krish89 

 

According to your description, I think you need to create a single list and use the date column as slicer. Then create a measure to display the results.

Like this:

 

Table = CALCULATETABLE(DISTINCT(Table1[Date]),Table1[PeriodTypeld]=2)
Rolling Average = 
VAR last =
    DATE ( YEAR ( SELECTEDVALUE ( 'Table'[Date] ) ) - 1, MONTH ( SELECTEDVALUE ( 'Table'[Date] ) ), DAY ( SELECTEDVALUE ( 'Table'[Date] ) ) )
VAR s =
    SUMX (
        FILTER (
            ALL ( Table1 ),
            [PeriodTypeld] = 2
                && [Date] < SELECTEDVALUE ( 'Table'[Date] )
                && [Date] >= last
        ),
        [Amount]
    )
RETURN
    DIVIDE ( s, 12 )

 

vjaneygmsft_0-1624526710105.png

My sample file is below. Hope it helps.

 

Best Regards

Janey Guo

 

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

2 REPLIES 2
v-janeyg-msft
Community Support
Community Support

Hi, @Krish89 

 

According to your description, I think you need to create a single list and use the date column as slicer. Then create a measure to display the results.

Like this:

 

Table = CALCULATETABLE(DISTINCT(Table1[Date]),Table1[PeriodTypeld]=2)
Rolling Average = 
VAR last =
    DATE ( YEAR ( SELECTEDVALUE ( 'Table'[Date] ) ) - 1, MONTH ( SELECTEDVALUE ( 'Table'[Date] ) ), DAY ( SELECTEDVALUE ( 'Table'[Date] ) ) )
VAR s =
    SUMX (
        FILTER (
            ALL ( Table1 ),
            [PeriodTypeld] = 2
                && [Date] < SELECTEDVALUE ( 'Table'[Date] )
                && [Date] >= last
        ),
        [Amount]
    )
RETURN
    DIVIDE ( s, 12 )

 

vjaneygmsft_0-1624526710105.png

My sample file is below. Hope it helps.

 

Best Regards

Janey Guo

 

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

selimovd
Community Champion
Community Champion

Hey @Krish89 ,

 

try the following measure:

Rolling Average =
CALCULATE(
    AVERAGE( myTable[Amount] ),
    myTable[PeriodTypeId] = 2,
    DATESINPERIOD(
        dateTable[Date],
        MAX( dateTable[Date] ),
        -1,
        YEAR
    )
)

 

Be aware that you need a proper date table in order for the time intelligence functions to work.

Take a look on how to create a date table:

https://softcrylic.com/blogs/power-bi-for-beginners-how-to-create-a-date-table-in-power-bi/

 

If you need any help please let me know.
If I answered your question I would be happy if you could mark my post as a solution ✔️ and give it a thumbs up 👍
 
Best regards
Denis
 

 

Helpful resources

Announcements
PBI_User Group Leader_768x460.jpg

Manage your user group events

Check out the News & Announcements to learn more.

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.

Get Ready for Power BI Dev Camp

Microsoft named a Leader in The Forrester Wave

Microsoft received the highest score of any vendor in both the strategy and current offering categories.

R2 (Green) 768 x 460px.png

Microsoft Dynamics 365 & Power Platform User Professionals

DynamicsCon is a FREE, 4 half-day virtual learning experience for 11,000+ Microsoft Business Application users and professionals.

Top Solution Authors
Top Kudoed Authors