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 moreShape the future of the Fabric Community! Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions. Take survey.
Dear all,
I am trying to create a measure that calculates the differences in hours between two columns taking into account the weekends and non worked days.
I am using the follwoing formula for the measure:
Measure Avg Time = var tabla=CALCULATETABLE(Table1) var startdate= SUMX(tabla;Table1[Start Date]) var enddate=SUMX(tabla;Table1[End Date]) var Firstdayend =DATE(YEAR(startdate);MONTH(startdate);DAY(startdate)+1) var LastdayStart = DATE(YEAR(enddate);MONTH(enddate);DAY(enddate)) var LastdayEnd = DATE(YEAR(enddate);MONTH(enddate);DAY(enddate)+1) var secondsfirstday= SUMX(tabla; IF(Firstdayend<=startdate; 0; DATEDIFF(startdate;Firstdayend;SECOND) )) var secondslastday= SUMX(tabla; IF(enddate>=LastdayStart && enddate<=LastdayEnd; DATEDIFF(LastdayStart;enddate;SECOND); IF(enddate>LastdayEnd; DATEDIFF(LastdayStart;LastdayEnd;SECOND); 0 ) )) var secondsmidday=SUMX(tabla; (CALCULATE(DISTINCTCOUNT('Calendar'[Date Calculations]);FILTER('Calendar';'Calendar'[Date Calculations]>startdate &&'Calendar'[Date Calculations]<enddate && 'Calendar'[Is Weekday]=TRUE()))-1)*3600*24 ) return SUMX(tabla;(secondsfirstday+secondslastday+secondsmidday)/3600)
The result of that formula is OK for each individual member but i don't know how to calculate the aggregate (average) for all the rows in the table.
Currently i have the following result:
And here you have the original Table:
As you can see this measure works fine (without the sumx) as a calculated column, but i want to apply this measure in a large database and it is not possible to use a calculated column because it is too slow and i have errors when i try to calculate it.
Thanks,
Francesc.
Solved! Go to Solution.
Hi @fturmo,
The result of that formula is OK for each individual member but i don't know how to calculate the aggregate (average) for all the rows in the table.
In this scenario, you may need two measures to work this out. First measure to calculate the time difference for the individual column which is similar to the measure you provided above.. The formula below is for your reference.
Measure Time For Individual Member = VAR startdate = MAX ( Table1[Start Date] ) VAR enddate = MAX ( Table1[End Date] ) VAR Firstdayend = DATE ( YEAR ( startdate ), MONTH ( startdate ), DAY ( startdate ) + 1 ) VAR LastdayStart = DATE ( YEAR ( enddate ), MONTH ( enddate ), DAY ( enddate ) ) VAR LastdayEnd = DATE ( YEAR ( enddate ), MONTH ( enddate ), DAY ( enddate ) + 1 ) VAR secondsfirstday = IF ( Firstdayend <= startdate, 0, DATEDIFF ( startdate, Firstdayend, SECOND ) ) VAR secondslastday = IF ( enddate >= LastdayStart && enddate <= LastdayEnd, DATEDIFF ( LastdayStart, enddate, SECOND ), IF ( enddate > LastdayEnd, DATEDIFF ( LastdayStart, LastdayEnd, SECOND ), 0 ) ) VAR secondsmidday = ( CALCULATE ( DISTINCTCOUNT ( 'Calendar'[Date Calculations] ), FILTER ( 'Calendar', 'Calendar'[Date Calculations] > startdate && 'Calendar'[Date Calculations] < enddate && 'Calendar'[Is Weekday] = TRUE () ) ) - 1 ) * 3600 * 24 RETURN ( secondsfirstday + secondslastday + secondsmidday ) / 3600
Then use a new measure to sum each individual time difference together for the table.
Measure Avg Time = SUMX ( Table1, [Measure Time For Individual Member] )
Regards
Hi @fturmo,
The result of that formula is OK for each individual member but i don't know how to calculate the aggregate (average) for all the rows in the table.
In this scenario, you may need two measures to work this out. First measure to calculate the time difference for the individual column which is similar to the measure you provided above.. The formula below is for your reference.
Measure Time For Individual Member = VAR startdate = MAX ( Table1[Start Date] ) VAR enddate = MAX ( Table1[End Date] ) VAR Firstdayend = DATE ( YEAR ( startdate ), MONTH ( startdate ), DAY ( startdate ) + 1 ) VAR LastdayStart = DATE ( YEAR ( enddate ), MONTH ( enddate ), DAY ( enddate ) ) VAR LastdayEnd = DATE ( YEAR ( enddate ), MONTH ( enddate ), DAY ( enddate ) + 1 ) VAR secondsfirstday = IF ( Firstdayend <= startdate, 0, DATEDIFF ( startdate, Firstdayend, SECOND ) ) VAR secondslastday = IF ( enddate >= LastdayStart && enddate <= LastdayEnd, DATEDIFF ( LastdayStart, enddate, SECOND ), IF ( enddate > LastdayEnd, DATEDIFF ( LastdayStart, LastdayEnd, SECOND ), 0 ) ) VAR secondsmidday = ( CALCULATE ( DISTINCTCOUNT ( 'Calendar'[Date Calculations] ), FILTER ( 'Calendar', 'Calendar'[Date Calculations] > startdate && 'Calendar'[Date Calculations] < enddate && 'Calendar'[Is Weekday] = TRUE () ) ) - 1 ) * 3600 * 24 RETURN ( secondsfirstday + secondslastday + secondsmidday ) / 3600
Then use a new measure to sum each individual time difference together for the table.
Measure Avg Time = SUMX ( Table1, [Measure Time For Individual Member] )
Regards
That works perfectly.
Thanks Jerry for your Response.
Francesc.
User | Count |
---|---|
93 | |
92 | |
85 | |
83 | |
49 |
User | Count |
---|---|
150 | |
142 | |
112 | |
73 | |
55 |