Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet 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
I am trying to get an average of the Duration column. Basic format is DD:HH:MM:SS.
Solved! Go to Solution.
Hi @Anonymous
As tested, in my excel, the "duration" column is of time type or text type,
after importing to Power BI, i can go to Edit queries to transform it to duration type.
Then in Edit queries->Add columns->Duration->total seconds
Close&&apply, go to report view
Create measures
average = CALCULATE(AVERAGE(Sheet1[Total Seconds]),ALL(Sheet1)) total hours = INT(ROUNDDOWN([average]/3600,0)) Minutes = INT(ROUNDDOWN(([average]-[total hours]*3600)/60,0)) seconds = INT(ROUNDUP([average]-[total hours]*3600-[Minutes]*60,0)) days = INT(ROUNDDOWN([total hours]/24,0)) average format = [days]&"."&([total hours]-[days]*24)&":"&[Minutes]&":"&[seconds]
Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hello
the duration data type does not accept to be summarized, any suggestion to get an average duration to use in a bar chart ?
Thank you
Amaury
Hi @Anonymous
As tested, in my excel, the "duration" column is of time type or text type,
after importing to Power BI, i can go to Edit queries to transform it to duration type.
Then in Edit queries->Add columns->Duration->total seconds
Close&&apply, go to report view
Create measures
average = CALCULATE(AVERAGE(Sheet1[Total Seconds]),ALL(Sheet1)) total hours = INT(ROUNDDOWN([average]/3600,0)) Minutes = INT(ROUNDDOWN(([average]-[total hours]*3600)/60,0)) seconds = INT(ROUNDUP([average]-[total hours]*3600-[Minutes]*60,0)) days = INT(ROUNDDOWN([total hours]/24,0)) average format = [days]&"."&([total hours]-[days]*24)&":"&[Minutes]&":"&[seconds]
Best Regards
Maggie
Community Support Team _ Maggie Li
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Thank you very much, you have been a great help!!
What if you tried this measure:
Avg Duration = FORMAT(AVERAGE( Duration[Duration] ),"dd:hh:mm:ss")
Not sure how your data is set up, so that's more of a guess
Thanks, Nick. I've tried your suggestion and set up a new measure, but I still get the error : "MdxScript(Model) (4, 57) calculation error in measure 'Export Worksheet'[Avg Duration]: The function AVERAGE cannot work with values of type String.
You can try changing the data type in power query to type Duration.
if the column errors out when you make that change (not sure where that column comes from) you will then have to calculate the duration yourself using whatever start and end points you want.
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
89 | |
88 | |
82 | |
64 | |
49 |
User | Count |
---|---|
125 | |
111 | |
88 | |
69 | |
66 |