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

Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started

Reply
FrankWe
Helper I
Helper I

Problem with DAX query calculating an average value

Hello, 

I have a problem to create a DAX measure calculating an average value. 

I have a combined bar and line chart. The bars are showing the total numbers of rows in a table "visits" per month on the X axis. So far so good. Now I inserted a date slicer tot select a date range on yearmonth level. The yearmonth values are taken from a calendar table. using the slicer filters the data to the selected time period. 

 

Now my problem:  I would like to have a horizontal line in the chart showing the average of visits based on the selected time period. That means when I have a total of 600 visits in 5 months the horizontal line should be at a value of 120 for each month. 

I know how to get the start and end values of the slicer and also the total number of visits in the selected time period. But I have no idea how to get this horizontal line showing the same average value in each month.

 

Many thanks in advance for your help.

 

Frank

1 ACCEPTED SOLUTION

since you're not using a measure, you have to add a calculate to force the context.

VAR AverageVisits2 = 
CALCULATE(
    AVERAGEX(
        VALUES('Calendar'[MonthYear]),
        CALCULATE(COUNT(Visits[VisitID])))
   ,ALLSELECTED('Calendar')
)

View solution in original post

6 REPLIES 6
sjoerdvn
Super User
Super User

I have created something similar, but you should be able to adjust to your own measures and date dimension table. crucial  is the use of ALLSELECTED to give you the filter/slicer context:

avg montly visits = CALCULATE(AVERAGEX(VALUES('dim_date'[month_year]),[# visits]), ALLSELECTED('dim_date'))



@sjoerdvn: Hi, thank your this. I tried to implement this, but the result is that the line is showing me the total number of visits in the selected time period and not the average 🤔

 

My measure looks like this now:

 

VAR AverageVisits2 = CALCULATE(
    AVERAGEX(
        VALUES('Calendar'[MonthYear]),
        COUNT(Visits[VisitID])),
        ALLSELECTED('Calendar')
    )
 
What is wrong whit this? 

since you're not using a measure, you have to add a calculate to force the context.

VAR AverageVisits2 = 
CALCULATE(
    AVERAGEX(
        VALUES('Calendar'[MonthYear]),
        CALCULATE(COUNT(Visits[VisitID])))
   ,ALLSELECTED('Calendar')
)

@sjoerdvn: Many thanks for your help. You are my hero 😊 And it shows me that I will have to learn so much more to understand more of the DAX functionality 🤔


 
 
FreemanZ
Super User
Super User

hi @FrankWe ,

 

Constant Average Line is a standard built-in feature, check this:

https://learn.microsoft.com/en-us/power-bi/transform-model/desktop-analytics-pane

Hi, thank you for this info, but I think the constant average line is not available for a stacked bar chart as I need this to show the different visit types in the bar. Sorry for not mentioning that. When I look into the analytics pane there is now average bar available.

The chart should look like the one below. The red line is the average line and it should change every time when I change the time period in the date slicer.Screenshot 2023-11-02 103123.png

Helpful resources

Announcements
Sept PBI Carousel

Power BI Monthly Update - September 2024

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

September Hackathon Carousel

Microsoft Fabric & AI Learning Hackathon

Learn from experts, get hands-on experience, and win awesome prizes.

Sept NL Carousel

Fabric Community Update - September 2024

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