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

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now! Learn more

Reply
jb123
Frequent Visitor

Column that Calculates Business Days

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

2 ACCEPTED SOLUTIONS
Anonymous
Not applicable

@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,

View solution in original post

Anonymous
Not applicable

@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,

View solution in original post

9 REPLIES 9
Anonymous
Not applicable

@jb123,

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
)


1.PNG


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?

Anonymous
Not applicable

@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

 

Anonymous
Not applicable

@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.

MFelix
Super User
Super User

Hi @jb123,

From your formula I cannot perceive where you want to take out the bussines days but if you use the WEEKDAY formula you can then exclude the weekday = 1 (Sunday) or 7 (saturday).

Regards,
MFelix

Regards

Miguel Félix


Did I answer your question? Mark my post as a solution!

Proud to be a Super User!

Check out my blog: Power BI em Português



Helpful resources

Announcements
Power BI DataViz World Championships

Power BI Dataviz World Championships

The Power BI Data Visualization World Championships is back! Get ahead of the game and start preparing now!

December 2025 Power BI Update Carousel

Power BI Monthly Update - December 2025

Check out the December 2025 Power BI Holiday Recap!

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.