Microsoft Fabric Community Conference 2025, March 31 - April 2, Las Vegas, Nevada. Use code FABINSIDER for a $400 discount.
Register nowThe Power BI DataViz World Championships are on! With four chances to enter, you could win a spot in the LIVE Grand Finale in Las Vegas. Show off your skills.
Hi,
I need to create a column that calculates the business days. I have this working that displays the calendar days in a column and I just need to tweek it to exclude weekends:
Days =
SWITCH (
TRUE (),
'Velocity'[DashboardCreationDate] <Velocity[Completed Date] , DATEDIFF ('Velocity'[DashboardCreationDate], 'Velocity'[Completed Date], DAY ),
'Velocity'[DashboardCreationDate] > 'Velocity'[Completed Date], DATEDIFF ('Velocity'[Completed Date], 'Velocity'[DashboardCreationDate], DAY ) * -1,
0
)
TIA!!!
Solved! Go to Solution.
@jb123,
Use the following DAX to create date table and check if you get any errors.
Date = ADDCOLUMNS ( CALENDAR (DATE(2000,1,1), DATE(2025,12,31)), "DateAsInteger", FORMAT ( [Date], "YYYYMMDD" ), "Year", YEAR ( [Date] ), "Monthnumber", FORMAT ( [Date], "MM" ), "YearMonthnumber", FORMAT ( [Date], "YYYY/MM" ), "YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ), "MonthNameShort", FORMAT ( [Date], "mmm" ), "MonthNameLong", FORMAT ( [Date], "mmmm" ), "DayOfWeekNumber", WEEKDAY ( [Date] ), "DayOfWeek", FORMAT ( [Date], "dddd" ), "DayOfWeekShort", FORMAT ( [Date], "ddd" ), "Quarter", "Q" & FORMAT ( [Date], "Q" ), "YearQuarter", FORMAT ( [Date], "YYYY" ) & "/Q" & FORMAT ( [Date], "Q" )
Regards,
@jb123,
Use the following DAX instead.
Days excluding Weekends = IF(ISBLANK(Velocity[Completed Date])||ISBLANK(Velocity[DashboardCreationDate]),BLANK(),SWITCH ( TRUE (), 'Velocity'[DashboardCreationDate] <Velocity[Completed Date] , CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[DashboardCreationDate],Velocity[Completed Date] )), 'Velocity'[DashboardCreationDate] > 'Velocity'[Completed Date],CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[Completed Date],Velocity[DashboardCreationDate] )) * -1, 0 ))
Regards,
Firstly, create a date table in Power BI Desktop following the instructions in this blog.
Secondly, create a new column in the date table using the DAX below.
IsWorkDay = SWITCH(WEEKDAY('Date'[Date]),1,0,7,0,1)
Thirdly, create a new column using the following formula in your original table.
Days excluding Weekends = SWITCH ( TRUE (), 'Velocity'[DashboardCreationDate] <Velocity[Completed Date] , CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[DashboardCreationDate],Velocity[Completed Date] )), 'Velocity'[DashboardCreationDate] > 'Velocity'[Completed Date],CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[Completed Date],Velocity[DashboardCreationDate] )) * -1, 0 )
Regards,
The syntax to create a date table in the blog is incorrect. If you click on new table from moedling and do a copy and paste of the following:
Date =CALENDAR (DATE(2000;1;1); DATE(2025;12;31))
You get an error saying the syntax is incorrect so i thought ok I should copy and paste all of it so I did a copy and paste of this instead
Date =
ADDCOLUMNS (
CALENDAR (DATE(2000;1;1); DATE(2025;12;31));
"DateAsInteger"; FORMAT ( [Date]; "YYYYMMDD" );
"Year"; YEAR ( [Date] );
"Monthnumber"; FORMAT ( [Date]; "MM" );
"YearMonthnumber"; FORMAT ( [Date]; "YYYY/MM" );
"YearMonthShort"; FORMAT ( [Date]; "YYYY/mmm" );
"MonthNameShort"; FORMAT ( [Date]; "mmm" );
"MonthNameLong"; FORMAT ( [Date]; "mmmm" );
"DayOfWeekNumber"; WEEKDAY ( [Date] );
"DayOfWeek"; FORMAT ( [Date]; "dddd" );
"DayOfWeekShort"; FORMAT ( [Date]; "ddd" );
"Quarter"; "Q" & FORMAT ( [Date]; "Q" );
"YearQuarter"; FORMAT ( [Date]; "YYYY" ) & "/Q" & FORMAT ( [Date]; "Q" )
)
Again I get a syntax error. The exact error message is "The syntax for ';' is incorrect. (DAX(CALENDAR (DATE(2000;1;1); DATE(2025;12;31))))."
Any suggestions?
@jb123,
Use the following DAX to create date table and check if you get any errors.
Date = ADDCOLUMNS ( CALENDAR (DATE(2000,1,1), DATE(2025,12,31)), "DateAsInteger", FORMAT ( [Date], "YYYYMMDD" ), "Year", YEAR ( [Date] ), "Monthnumber", FORMAT ( [Date], "MM" ), "YearMonthnumber", FORMAT ( [Date], "YYYY/MM" ), "YearMonthShort", FORMAT ( [Date], "YYYY/mmm" ), "MonthNameShort", FORMAT ( [Date], "mmm" ), "MonthNameLong", FORMAT ( [Date], "mmmm" ), "DayOfWeekNumber", WEEKDAY ( [Date] ), "DayOfWeek", FORMAT ( [Date], "dddd" ), "DayOfWeekShort", FORMAT ( [Date], "ddd" ), "Quarter", "Q" & FORMAT ( [Date], "Q" ), "YearQuarter", FORMAT ( [Date], "YYYY" ) & "/Q" & FORMAT ( [Date], "Q" )
Regards,
One last issue. In some situations one of the date columns is null. Is there a way to modify this:
Days excluding Weekends = SWITCH (
TRUE (),
'Velocity'[DashboardCreationDate] <Velocity[Completed Date] , CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[DashboardCreationDate],Velocity[Completed Date] )),
'Velocity'[DashboardCreationDate] > 'Velocity'[Completed Date],CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[Completed Date],Velocity[DashboardCreationDate] )) * -1,
0
)
so that it just puts a null value if one of the values in either column is null? Right now it lists an odd number for the result in these situations..
TIA
@jb123,
Use the following DAX instead.
Days excluding Weekends = IF(ISBLANK(Velocity[Completed Date])||ISBLANK(Velocity[DashboardCreationDate]),BLANK(),SWITCH ( TRUE (), 'Velocity'[DashboardCreationDate] <Velocity[Completed Date] , CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[DashboardCreationDate],Velocity[Completed Date] )), 'Velocity'[DashboardCreationDate] > 'Velocity'[Completed Date],CALCULATE(SUM('Date'[IsWorkDay]),DATESBETWEEN('Date'[Date],Velocity[Completed Date],Velocity[DashboardCreationDate] )) * -1, 0 ))
Regards,
That did it - thanks again!!!!
You rock! That works great!!!!!!!!!!!
Thanks I will give this a try and see if I can get it to work.
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsMarch 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Check out the February 2025 Power BI update to learn about new features.
User | Count |
---|---|
86 | |
80 | |
53 | |
39 | |
39 |
User | Count |
---|---|
104 | |
85 | |
47 | |
44 | |
43 |