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
Hi there,
I've got a hour-related table that looks like figure 1. i would like to convert this table so it looks like figure 3 or figure 4.
Figure 1:
For each workingday between the begindate and enddate there a line created with an equal distubution of the hours based on working days.
Figure 2:
Figure 3: Figure 4:
Solved! Go to Solution.
Hi @maarten_74
Create calculated tables. For the one in Figure2:
NewTable2 = GENERATE ( ALL ( Table1[ID] ); VAR AuxTable_ = FILTER ( CALENDAR ( CALCULATE ( VALUES ( Table1[Begindate] ) ); CALCULATE ( VALUES ( Table1[Enddate] ) ) ); NOT WEEKDAY ( [Date]; 2 ) IN { 6; 7 } ) RETURN ADDCOLUMNS ( AuxTable_; "Hours"; CALCULATE ( DISTINCT ( Table1[Hours] ) ) / COUNTROWS ( AuxTable_ ) ) )
and the one in Figure3:
NewTable3 = GENERATE ( ALL ( Table1[ID] ); VAR AuxTable_ = CALENDAR ( CALCULATE ( VALUES ( Table1[Begindate] ) ); CALCULATE ( VALUES ( Table1[Enddate] ) ) ) VAR NumWorkingDays_ = COUNTROWS ( FILTER ( AuxTable_; NOT WEEKDAY ( [Date]; 2 ) IN { 6; 7 } ) ) RETURN ADDCOLUMNS ( AuxTable_; "Hours"; IF ( NOT WEEKDAY ( [Date]; 2 ) IN { 6; 7 }; CALCULATE ( DISTINCT ( Table1[Hours] ) ) / NumWorkingDays_; 0 ) ) )
Hi @maarten_74
Create calculated tables. For the one in Figure2:
NewTable2 = GENERATE ( ALL ( Table1[ID] ); VAR AuxTable_ = FILTER ( CALENDAR ( CALCULATE ( VALUES ( Table1[Begindate] ) ); CALCULATE ( VALUES ( Table1[Enddate] ) ) ); NOT WEEKDAY ( [Date]; 2 ) IN { 6; 7 } ) RETURN ADDCOLUMNS ( AuxTable_; "Hours"; CALCULATE ( DISTINCT ( Table1[Hours] ) ) / COUNTROWS ( AuxTable_ ) ) )
and the one in Figure3:
NewTable3 = GENERATE ( ALL ( Table1[ID] ); VAR AuxTable_ = CALENDAR ( CALCULATE ( VALUES ( Table1[Begindate] ) ); CALCULATE ( VALUES ( Table1[Enddate] ) ) ) VAR NumWorkingDays_ = COUNTROWS ( FILTER ( AuxTable_; NOT WEEKDAY ( [Date]; 2 ) IN { 6; 7 } ) ) RETURN ADDCOLUMNS ( AuxTable_; "Hours"; IF ( NOT WEEKDAY ( [Date]; 2 ) IN { 6; 7 }; CALCULATE ( DISTINCT ( Table1[Hours] ) ) / NumWorkingDays_; 0 ) ) )
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 |
---|---|
94 | |
92 | |
83 | |
71 | |
49 |
User | Count |
---|---|
143 | |
120 | |
110 | |
59 | |
57 |