March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
I'm currently using the following equation to calculate the total working days between two dates:
Total Working Days Column = SUMX ( FILTER ( 'Calendar', 'Calendar'[Date] >= Tasks[Task Start Date] && 'Calendar'[Date] <= Tasks[Task End Date] ), 'Calendar'[isWorkDay] )
Where the table Calendar, is a table with all dates listed and a column of isWorkDay, to indicate if it is Mon-Fri and not Sat or Sun.
This calculation is working for each row, except for the case when my Task End Date is an empty field.
Instead of returning NULL for the Total Workday Days Column, I'm receiving a random high value like 5042 or something similar (when instead it should not be able to calculate it because there is only a start date and no end date). I would like to receive a NULL or empty value so that when I calculate an average on my Total Working Days Column, I get an accurate number that excludes my nulls. Is there a way to add that into my column calculation or do I need to use some other filtering method?
Thank you for your help!
Solved! Go to Solution.
Hi @Anonymous I'm not able to reproduce the scenario. Please refer image. Can you please share some dummy data or else try to wrap your formula in if function as below
Total Working Days Column = IF(Tasks[Task End Date]=BLANK(),BLANK(),
SUMX (
FILTER (
'Calendar',
'Calendar'[Date] >= Tasks[Task Start Date]
&& 'Calendar'[Date] <= Tasks[Task End Date]
),
'Calendar'[isWorkDay]
))
Hi @Anonymous I'm not able to reproduce the scenario. Please refer image. Can you please share some dummy data or else try to wrap your formula in if function as below
Total Working Days Column = IF(Tasks[Task End Date]=BLANK(),BLANK(),
SUMX (
FILTER (
'Calendar',
'Calendar'[Date] >= Tasks[Task Start Date]
&& 'Calendar'[Date] <= Tasks[Task End Date]
),
'Calendar'[isWorkDay]
))
Hi @Anonymous , this appears to have fixed it! The calculation returns a blank if there is no end date. Thank you 🙂
Hi @Anonymous
try
Total Working Days Column =
(
SUM ('Calendar'[isWorkDay]),
FILTER (
'Calendar',
'Calendar'[Date] >= Tasks[Task Start Date]
&& 'Calendar'[Date] <= Tasks[Task End Date]
),
NOT(ISBLANK(Tasks[Task End Date]))
)
do not hesitate to give a kudo to useful posts and mark solutions as solution
@az38 , That function returned an error message stating that too many arguments were sent so I was not able to run it.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
25 | |
18 | |
15 | |
9 | |
8 |
User | Count |
---|---|
37 | |
32 | |
21 | |
16 | |
14 |