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

Get inspired! Check out the entries from the Power BI DataViz World Championships preliminary rounds and give kudos to your favorites. View the vizzies.

Reply
Anonymous
Not applicable

Averages Showing Wildly Incorrect Numbers

I am trying to find the average pickup and dropoff times for each client in our center to compare to the scheduled pickup/dropoff times for analysis. I have tried this a few different ways but the averages I am getting are so far off from what they should be. Looking for any assistance. Currently I am using the following formula to find the average pickup time :

AveragePickUpTime =
AVERAGEX(
FILTER('Form Data', 'Form Data'[PickUpOrDropOff] = "PickUp"),
'Form Data'[Date]
)

and this one for the column in the table

AveragePickUpColumn =
AVERAGEX(
FILTER('Form Data', 'Form Data'[PickUpOrDropOff] = "PickUp" && 'Form Data'[Client] = 'Client Schedules'[Client Initials]),
'Form Data'[Date]
)

I honestly got confused because there were a lot of conflicting tutorials and I got messed up along the way. All I want is the average pickup time per client and the average dropoff time per client. I would also like this data to be filterable. Please let me know if any additional screenshots

 This is the schedule page where I am trying to make a calculated fieldThis is the schedule page where I am trying to make a calculated fieldThis is the relationshipThis is the relationshipThis is the form data from the sign-in/outThis is the form data from the sign-in/out 

For reference here is what the averages should be: 
Screenshot 2024-05-22 134748.png

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

Hi  @Anonymous ,

I created some data:

vyangliumsft_0-1716451656157.png

I'm not very clear about what you mean by date average, whether it refers to the average of the minimum date and the maximum date (hh:mm:ss), if it's convenient, you can explain the logic of date average, we can help you better.

 

Here are the steps you can follow:

1. Create calculated column.

If you want to get the average of the minimum and maximum dates after grouping (hh:mm:ss)

 

AVG(hhmmss) =
var _mindate=
MINX(FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
var _maxdate=
MAXX(FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
var _second=
DATEDIFF(
    _mindate,_maxdate,SECOND)
var _count=
COUNTX(
  FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
var _avg=
DIVIDE(
    _second,_count)
RETURN
TIME ( 0, 0, FLOOR ( _avg, 1 ) )

 

If you want to get the average date between the minimum and maximum dates after grouping.

 

AVG =
var _mindate=
MINX(FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
RETURN
_mindate + [AVG(hhmmss)]

 

2. Set the data format as follows.

vyangliumsft_1-1716451656159.png

3. Result:

vyangliumsft_2-1716451934992.png

 

Best Regards,

Liu Yang

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

1 REPLY 1
v-yangliu-msft
Community Support
Community Support

Hi  @Anonymous ,

I created some data:

vyangliumsft_0-1716451656157.png

I'm not very clear about what you mean by date average, whether it refers to the average of the minimum date and the maximum date (hh:mm:ss), if it's convenient, you can explain the logic of date average, we can help you better.

 

Here are the steps you can follow:

1. Create calculated column.

If you want to get the average of the minimum and maximum dates after grouping (hh:mm:ss)

 

AVG(hhmmss) =
var _mindate=
MINX(FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
var _maxdate=
MAXX(FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
var _second=
DATEDIFF(
    _mindate,_maxdate,SECOND)
var _count=
COUNTX(
  FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
var _avg=
DIVIDE(
    _second,_count)
RETURN
TIME ( 0, 0, FLOOR ( _avg, 1 ) )

 

If you want to get the average date between the minimum and maximum dates after grouping.

 

AVG =
var _mindate=
MINX(FILTER(ALL('Table'),'Table'[Group]=EARLIER('Table'[Group])),[Scheduled DropOff])
RETURN
_mindate + [AVG(hhmmss)]

 

2. Set the data format as follows.

vyangliumsft_1-1716451656159.png

3. Result:

vyangliumsft_2-1716451934992.png

 

Best Regards,

Liu Yang

If this post helps, then please consider Accept it as the solution to help the other members find it more quickly

Helpful resources

Announcements
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!

FebPBI_Carousel

Power BI Monthly Update - February 2025

Check out the February 2025 Power BI update to learn about new features.

Feb2025 NL Carousel

Fabric Community Update - February 2025

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