The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hello, Power BI Experts!
Just couldn't find through the same questions on the community the solution that might help me. Will appriciate any help!
I need to calculated average on column subtotals.
User Name is on Rows, Time Entry Year Month is on Columns.
My measure on Values AverageWeeklyHours is calculated as a sum of logged hours in a month for the user divided by the number of weeks in this months.
The number of weeks is not a whole number because it's calculated as the number of days in a months divided by 7.
TotalHoursLoggedInAMonth = CALCULATE(SUM(TT_TimeEntries[Duration]), ALLEXCEPT(TT_TimeEntries, TT_TimeEntries[User Name], TT_TimeEntries[Time Entry Year Month]))
NumberOfWeeksInAMonth = TT_TimeEntries[NumberOfDaysInAMonth] / 7
AverageWeeklyHours = DIVIDE([TotalHoursLoggedInAMonth], AVERAGE(TT_TimeEntries[NumberOfWeeksInAMonth]))
I tried several methods but couldn't get the right AVG for the selected number of months.
For the first user it should be 44.33, for the second = 3.64 and so on...
Maybe I missed something in my calculations.
Thank you in advance!
Solved! Go to Solution.
hi, @v-cherch-msft, thank you for your reply.
I tried ALLSELECTED() and it turned out that this is not my case.
But hopefully I found a solution.
I recalculated Average Number of Weeks in a Month:
TotalHours = SUM(TT_TimeEntries[Duration])
NumberOfWeeks = AVERAGEX(TT_TimeEntries, [NumberOfDaysInAMonth] / 7)
And created a final measure as:
AverageHoursInAWeek =
AVERAGEX (
VALUES ( 'TT_TimeEntries'[Time Entry Year Month] ),
CALCULATE ( DIVIDE ( [TotalHours], [NumberOfWeeks]) )
)
The final result is:
Hope somebody could use this in future.
Hi @Anonymous
It seems you may try to use ALLSELECTED Function. Below is the article for your reference. If it is not your case, It's better that if you could share some simplified data which could reproduce your scenario and your desired output.
https://www.sqlbi.com/articles/understanding-allselected/
Regards,
Cherie
hi, @v-cherch-msft, thank you for your reply.
I tried ALLSELECTED() and it turned out that this is not my case.
But hopefully I found a solution.
I recalculated Average Number of Weeks in a Month:
TotalHours = SUM(TT_TimeEntries[Duration])
NumberOfWeeks = AVERAGEX(TT_TimeEntries, [NumberOfDaysInAMonth] / 7)
And created a final measure as:
AverageHoursInAWeek =
AVERAGEX (
VALUES ( 'TT_TimeEntries'[Time Entry Year Month] ),
CALCULATE ( DIVIDE ( [TotalHours], [NumberOfWeeks]) )
)
The final result is:
Hope somebody could use this in future.
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
121 | |
85 | |
75 | |
55 | |
46 |
User | Count |
---|---|
135 | |
127 | |
78 | |
64 | |
63 |