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

Moving Average Of Calculated Measure

Hi All,

 

I would like to calculate the moving average of an already calculated (% of grand total) measure. I've tried a lot of solutions but none of them seem to work correctly.

 

Table structure:

1. original table with dimensions and facts (simple DWH table)

2. calculated table with DAX

 

Date structure of 1st table: (of course, it's simplified...)

- date/time column

- period

- fact

 

Data structure of 2nd table:

- period (text): i.e. 2016_P1

- artificial date (date): i.e. 2016.04.01 (dynamic column to have a date column for the DAX date functions)

- calculated % of GT measure (it's a simple measure in the table)

- moving average of the calculated measure (it should be simple: = (value of 2016_P1 + 2016_P2 + 2016_P3) / 3

 

Any ideas how to solve it?

 

Thanks,

breki

 

moving_avg_sample_v1.PNG

1 ACCEPTED SOLUTION

Accepted Solutions
Microsoft v-jiascu-msft
Microsoft

Re: Moving Average Of Calculated Measure

Hi @brekeke,

 

Please try this formula.

Measure 2 =
VAR weekPeriods =
    CALCULATE (
        DISTINCTCOUNT ( tbl_periods_all[Period Column] ),
        DATESINPERIOD (
            'Calendar'[Date],
            MIN ( tbl_periods_all[Start Of Period] ),
            -21,
            DAY
        ),
        ALL ( tbl_periods_all[Period Column] )
    )
VAR pPeriods =
    CALCULATE (
        DISTINCTCOUNT ( tbl_periods_all[Period Column] ),
        DATESINPERIOD (
            'Calendar'[Date],
            MIN ( 'tbl_periods_all'[Start Of Period] ),
            -7,
            MONTH
        ),
        ALL ( tbl_periods_all[Period Column] )
    )
RETURN
    IF (
        MIN ( 'Period Selector'[period] ) = "Week",
        CALCULATE (
            SUM ( data[fact] ),
            DATESINPERIOD (
                'Calendar'[Date],
                MIN ( 'tbl_periods_all'[Start Of Period] ),
                -21,
                DAY
            ),
            ALL ( tbl_periods_all[Period Column] )
        )
            / weekPeriods,
        CALCULATE (
            SUM ( data[fact] ),
            DATESINPERIOD (
                'Calendar'[Date],
                MIN ( 'tbl_periods_all'[Start Of Period] ),
                -7,
                MONTH
            ),
            ALL ( tbl_periods_all[Period Column] )
        )
            / pPeriods
    )

Moving_Average_Of_Calculated_Measure2

 

Best Regards,

Dale

 

Community Support Team _ Dale
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

12 REPLIES 12
Super User IV
Super User IV

Re: Moving Average Of Calculated Measure

Have you tried the technique described here, it would appear to apply:

 

https://community.powerbi.com/t5/Community-Blog/Design-Pattern-Groups-and-Super-Groups/ba-p/138149

 

 


I have book! Learn Power BI from Packt


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

Proud to be a Datanaut!

Microsoft v-jiascu-msft
Microsoft

Re: Moving Average Of Calculated Measure

Hi @brekeke,

 

Did you try the method of @Greg_Deckler? You measure could be like this:

New Measure =
CALCULATE (
    SUMX (
        SUMMARIZE ( 'Sales', 'Product'[Color], "Amount", [Your old measure] ),
        [Amount]
    ),
    DATESINPERIOD ( 'Calender'[Date], MAX ( 'Calender'[Date] ), -3, MONTH )
)

It would be great if you can share your pbix file. Dummy one is enough.

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
brekeke Frequent Visitor
Frequent Visitor

Re: Moving Average Of Calculated Measure

Thanks for the advice. It might work but first I need to fully understand your solution. I'm fairly new into power BI and the logic is less than obvious to me sometimes...

Microsoft v-jiascu-msft
Microsoft

Re: Moving Average Of Calculated Measure

Hi @brekeke,

 

It would be great if you can provide the DUMMY pbix file (Not your real data). I can add the solution to the file and send back to you. Then it could be easier for you to try the solution out.

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
brekeke Frequent Visitor
Frequent Visitor

Re: Moving Average Of Calculated Measure

Thanks @v-jiascu-msft,

 

I quickly tried the below formula but it doesn't work. My assumption is that my data structure is making me fool.

 

What I did not mention previously is that the period column is dynamically calculated: it can be changed with a slicer, thus it can show quarterly and weekly data as well.

 

IMO, your formula doesn't work because it wrongly summarizing:

1. measure is the original calculated measure

2. measure is exactly your formula

 

Values are different, so filtering for time interval works, but somehow it's grouping badly (according to my humble opinion)...

 

Thanks

 

suggestion_v-jiascu-ms.PNG

brekeke Frequent Visitor
Frequent Visitor

Re: Moving Average Of Calculated Measure

Thanks @v-jiascu-msft,

I'll try to make a dummy file, but it will take some time I guess.

brekeke Frequent Visitor
Frequent Visitor

Re: Moving Average Of Calculated Measure

Hi @v-jiascu-msft,

 

Here you go: https://www.dropbox.com/s/nd46tlcbz98th1p/moving_average_dummy_v0.1.pbix?dl=0

 

Data structure is exactly the same except some supporting table but those don't matter.

 

Thanks,

breki

Microsoft v-jiascu-msft
Microsoft

Re: Moving Average Of Calculated Measure

Hi @brekeke,

 

I made a few changes in your file. Please check it out here.

The measure is:

Measure =
IF (
    MIN ( 'Period Selector'[period] ) = "Week",
    CALCULATE (
        SUM ( data[fact] ),
        DATESINPERIOD (
            'Calendar'[Date],
            MIN ( 'tbl_periods_all'[Start Of Period] ),
            -21,
            DAY
        ),
        ALL ( tbl_periods_all[Period Column] )
    ),
    CALCULATE (
        SUM ( data[fact] ),
        DATESINPERIOD (
            'Calendar'[Date],
            MIN ( 'tbl_periods_all'[Start Of Period] ),
            -7,
            MONTH
        ),
        ALL ( tbl_periods_all[Period Column] )
    )
)

Moving_Average_Of_Calculated_Measure

 

Best Regards,

Dale

Community Support Team _ Dale
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
brekeke Frequent Visitor
Frequent Visitor

Re: Moving Average Of Calculated Measure

Hi @v-jiascu-msft/Dale,

 

This solution works for a rolling total, but it needs to be modified a bit for the moving average because if we divide the sum by 3 (I need the 3-period moving average), the first two periods will be wrong. So I will need to work on that a bit further.

 

Thanks,

brekeke

Helpful resources

Announcements
Coming Soon: T-Shirt Design Contest

Coming Soon: T-Shirt Design Contest

Keep your eyes open for our upcoming T-shirt design contest!

Meet the 2020 Season 1 Power BI Super Users!

Meet the 2020 Season 1 Power BI Super Users!

It’s the start of a new Super User season! Learn all about the new Super Users and brand-new tiered recognition system.

Super User Challenge: Can You Solve These?

Super User Challenge: Can You Solve These?

We're celebrating the start of the New Super User season with our first ever Super User 'Can You Solve These?' challenge.

Power Platform Online Conference

Power Platform Online Conference

Join us for the first ever Power Platform Online Conference!

Top Solution Authors
Top Kudoed Authors
Users online (880)