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

Get Fabric Certified for FREE during Fabric Data Days. Don't miss your chance! Request 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
Community Champion
Community Champion

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
Community Champion
Community Champion

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
Fabric Data Days Carousel

Fabric Data Days

Advance your Data & AI career with 50 days of live learning, contests, hands-on challenges, study groups & certifications and more!

October Power BI Update Carousel

Power BI Monthly Update - October 2025

Check out the October 2025 Power BI update to learn about new features.

FabCon Atlanta 2026 carousel

FabCon Atlanta 2026

Join us at FabCon Atlanta, March 16-20, for the ultimate Fabric, Power BI, AI and SQL community-led event. Save $200 with code FABCOMM.

Top Solution Authors