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

Earn the coveted Fabric Analytics Engineer certification. 100% off your exam for a limited time only!

Reply
brekeke
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

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
v-jiascu-msft
Employee
Employee

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.

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

Greg_Deckler
Super User
Super User

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

 

 


@ me in replies or I'll lose your thread!!!
Instead of a Kudo, please vote for this idea
Become an expert!: Enterprise DNA
External Tools: MSHGQM
YouTube Channel!: Microsoft Hates Greg
Latest book!:
Mastering Power BI 2nd Edition

DAX is easy, CALCULATE makes DAX hard...

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...

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.

Thanks @v-jiascu-msft,

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

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

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.

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

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.

Hi @v-jiascu-msft,

 

This works for me, except that for the first 2 periods (in case of a 3-period moving average), I would like to see zeros or blanks.

 

On the other hand, I realized that I hadn't been that specific with my example. I will open another thread and link it here. Maybe you can provide with something for that challenge as well.

 

Many thanks for your help,

breki

Hi @brekeke,

 

You are welcome. You can try this formula that will set the first two values to blanks. You can change the blue part to 0s.

Measure 3 =
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",
        DIVIDE (
            CALCULATE (
                SUM ( data[fact] ),
                DATESINPERIOD (
                    'Calendar'[Date],
                    MIN ( 'tbl_periods_all'[Start Of Period] ),
                    -21,
                    DAY
                ),
                ALL ( tbl_periods_all[Period Column] )
            ),
            IF ( weekPeriods < 3, 0, weekPeriods ),
            BLANK ()
        ),
        DIVIDE (
            CALCULATE (
                SUM ( data[fact] ),
                DATESINPERIOD (
                    'Calendar'[Date],
                    MIN ( 'tbl_periods_all'[Start Of Period] ),
                    -7,
                    MONTH
                ),
                ALL ( tbl_periods_all[Period Column] )
            ),
            IF ( pPeriods < 3, 0, pPeriods ),
            BLANK ()
        )
    )

Moving_Average_Of_Calculated_Measure3

 

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.

Helpful resources

Announcements
April AMA free

Microsoft Fabric AMA Livestream

Join us Tuesday, April 09, 9:00 – 10:00 AM PST for a live, expert-led Q&A session on all things Microsoft Fabric!

March Fabric Community Update

Fabric Community Update - March 2024

Find out what's new and trending in the Fabric Community.