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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
ChrisBroome
Frequent Visitor

Null values where missing date

Hi,

 

I've got a query set to calculate the number of working days based on two dates;

= (InitialDate as date, FinalDate as date ) as number =>
let
DaysBetweenDates = Duration.Days(FinalDate-InitialDate),
DaysList = List.Dates(List.Min({InitialDate,FinalDate}),Number.Abs(DaysBetweenDates)+1, Duration.From(1)),
WeekDaysList = List.Select(DaysList, each (Date.DayOfWeek(_, Day.Monday) < 5) ),
WorkingDays = (if DaysBetweenDates < 0 then -1 else 1) * List.Count(WeekDaysList)
in
WorkingDays

 

however, I don't always have dates available in these columns, and so where this is the case, I get an error. Can anyone suggest a way to prevent me getting these errors flagged? I'd be fine with just Null values in these instances, but can't work out how to get these to show instead of the error.

 

Regards

2 ACCEPTED SOLUTIONS
CNENFRNL
Community Champion
Community Champion

Hi, @ChrisBroome , a most straightforward way is to enclose the function invocation into a try ... otherwise to catch errors like this,

 

Invoking = try Query1(#date(2020, 11, 10), null) otherwise ""

 

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

View solution in original post

AlB
Super User
Super User

Hi @ChrisBroome 

Try this:

(InitialDate as any, FinalDate as any ) as any =>
    if (InitialDate=null  or  FinalDate=null) then null else
        let
            DaysBetweenDates = Duration.Days(FinalDate-InitialDate),
            DaysList = List.Dates(List.Min({InitialDate,FinalDate}),Number.Abs(DaysBetweenDates)+1, Duration.From(1)),
            WeekDaysList = List.Select(DaysList, each (Date.DayOfWeek(_, Day.Monday) < 5) ),
            WorkingDays = (if DaysBetweenDates < 0 then -1 else 1) * List.Count(WeekDaysList)
        in
            WorkingDays

 

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

 

View solution in original post

3 REPLIES 3
Icey
Community Support
Community Support

Hi @ChrisBroome ,

 

Please let us know if the replies above are helpful.

 

If they are, please always accept the replies making sense as solution to your question so that people who may have the same question can get the solution directly.

 

If not, please give us more details.

 

 

Best Regards,

Icey

AlB
Super User
Super User

Hi @ChrisBroome 

Try this:

(InitialDate as any, FinalDate as any ) as any =>
    if (InitialDate=null  or  FinalDate=null) then null else
        let
            DaysBetweenDates = Duration.Days(FinalDate-InitialDate),
            DaysList = List.Dates(List.Min({InitialDate,FinalDate}),Number.Abs(DaysBetweenDates)+1, Duration.From(1)),
            WeekDaysList = List.Select(DaysList, each (Date.DayOfWeek(_, Day.Monday) < 5) ),
            WorkingDays = (if DaysBetweenDates < 0 then -1 else 1) * List.Count(WeekDaysList)
        in
            WorkingDays

 

Please mark the question solved when done and consider giving a thumbs up if posts are helpful.

Contact me privately for support with any larger-scale BI needs, tutoring, etc.

Cheers 

SU18_powerbi_badge

 

CNENFRNL
Community Champion
Community Champion

Hi, @ChrisBroome , a most straightforward way is to enclose the function invocation into a try ... otherwise to catch errors like this,

 

Invoking = try Query1(#date(2020, 11, 10), null) otherwise ""

 

 


Thanks to the great efforts by MS engineers to simplify syntax of DAX! Most beginners are SUCCESSFULLY MISLED to think that they could easily master DAX; but it turns out that the intricacy of the most frequently used RANKX() is still way beyond their comprehension!

DAX is simple, but NOT EASY!

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

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

April Fabric Community Update

Fabric Community Update - April 2024

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

Top Solution Authors