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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
Lindino08
Frequent Visitor

Calculate the Average of a measure over selected months

Hello Power Bi Community! Hoping someone can help me out.

I have a measure which calulates the "Incident Rate" (IR). Formula for IR is:

IR = 'Injury Data'[Recordable Injuries] * 200000 / 'Injury Data'[Total Working Hours]

We have the IR placed on a monthly bar graph which is correct. Now we would like to add a Line y-axis to show a cumulative average of the IR based on the selected Months.

Red line is what I have drawn and need to create a formula for.

Screenshot 2022-08-02 093611.png
1 ACCEPTED SOLUTION

Hey,

 

I think it's because the ALLSELECTED function doesn't work properly this way. Could you try this code?

Cumulative Average =
VAR MinDate =
    CALCULATE ( MIN ( 'Employee Hours'[Date (Start of Month]) ), ALLSELECTED ( 'Employee Hours' ) )
VAR MaxDate =
    MAX ( 'Employee Hours'[Date (Start of Month])] )
RETURN
    CALCULATE (
        'Injury Data'[Recordable Injuries] * 200000 / 'Injury Data'[Total Working Hours],
        'Employee Hours'[Date (Start of Month])] >= MinDate,
        'Employee Hours'[Date (Start of Month])] <= MaxDate
    )

View solution in original post

6 REPLIES 6
Barthel
Solution Sage
Solution Sage

Hey,

 

Assuming you have a calendar table called 'Calendar', this is the code you can use for a measure:

 

Cumulative Average =
VAR CurrentDate =
    MAX ( Calendar[Date] )
RETURN
    CALCULATE (
        'Injury Data'[Recordable Injuries] * 200000 / 'Injury Data'[Total Working Hours],
        ALLSELECTED ( Calendar ),
        Calendar[Date] <= CurrentDate
    )

 

Instead of redefining the IR measure in the above code, you can also refer to your already existing IR measure.

Thanks Barthel!

I tried your code and have different results (which is good) but not what we are looking for. Here is a screentshot. 

Screenshot 2022-08-02 104841.png

Hey,

 

Just thinking out loud here. What kind of column is the 'Month' column? A string or value? The VAR CurrentDate must take the MAX of a value column, so that the less than or equal to statement works logically. Is that the case? If not, take the MAX of the column on which you base the sort order of 'Month', rather than 'Month' itself.

Good thoughts! I tried to change it to a calendar value column that I am pulling the month name from. Here is what I get. The second screen shot is of the relationship between the two tables I have and you can see the date columns. 
Screenshot 2022-08-02 160217.pngScreenshot 2022-08-02 160308.png

Hey,

 

I think it's because the ALLSELECTED function doesn't work properly this way. Could you try this code?

Cumulative Average =
VAR MinDate =
    CALCULATE ( MIN ( 'Employee Hours'[Date (Start of Month]) ), ALLSELECTED ( 'Employee Hours' ) )
VAR MaxDate =
    MAX ( 'Employee Hours'[Date (Start of Month])] )
RETURN
    CALCULATE (
        'Injury Data'[Recordable Injuries] * 200000 / 'Injury Data'[Total Working Hours],
        'Employee Hours'[Date (Start of Month])] >= MinDate,
        'Employee Hours'[Date (Start of Month])] <= MaxDate
    )

Prefect! You're Awesome! Thanks for the help.Screenshot 2022-08-02 162732.png

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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