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

Get 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

Reply
maarten_74
Frequent Visitor

Create a new table with a row for each weekday between two dates for each ID

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:

1.png

 

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:

2.png

Figure 3:                                           Figure 4:

3.png         4.png

1 ACCEPTED SOLUTION
AlB
Super User
Super User

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
            )
        )
)

View solution in original post

1 REPLY 1
AlB
Super User
Super User

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
            )
        )
)

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

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! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

Check out the November 2024 Power BI update to learn about new features.