Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.
Hello!
I want to create the equivalent of the workday formula in DAX. I have created a table of standard holidays and weekends where I have a column called "ISWORKINGDAY" where non-weekends/holidays are a value of 1 (0 for weekends and holidays). I used it for one formula already when I needed to count the number of working days between two dates and that was easy enough. But now I need to calculate when an item's free storage time will end. So I have the starting date + the free time length (say 4 working days) and I need to calculate the last free day.
Any ideas? The reason I need this is the billing of the item is calendar after free time expires.
Solved! Go to Solution.
Hi @Anonymous
I would suggest adding some Working Day Index columns to your Date table.
Below is an example using DAX.
You can then find the nth Working day after a given date by adding n to Last Working Day Index, and applying this as a filter on Working Day Index.
Date =
VAR StartDate =
dt"2023-01-01"
VAR EndDate =
dt"2023-12-31"
-- Sample Holidays
VAR Holidays =
{
dt"2023-01-01",
dt"2023-01-02",
dt"2023-01-16",
dt"2023-02-20",
dt"2023-05-29",
dt"2023-06-19",
dt"2023-07-04",
dt"2023-09-04",
dt"2023-10-09",
dt"2023-11-10",
dt"2023-11-11",
dt"2023-11-23",
dt"2023-12-25"
}
VAR DateBase = CALENDAR ( StartDate, EndDate )
VAR DateFinal =
GENERATE (
DateBase,
VAR d = [Date]
VAR IsWorkingDay = NETWORKDAYS ( d, d, 1, Holidays )
VAR LastWorkingDayIndex =
NETWORKDAYS ( StartDate, d, 1, Holidays )
VAR WorkingDayIndex =
IF (
IsWorkingDay,
LastWorkingDayIndex
)
RETURN
ROW (
"Is Working Day", IsWorkingDay,
"Working Day Index", WorkingDayIndex,
"Last Working Day Index", LastWorkingDayIndex
)
)
RETURN
DateFinal
Would something like that work for you?
Regards
Hi @Anonymous
I would suggest adding some Working Day Index columns to your Date table.
Below is an example using DAX.
You can then find the nth Working day after a given date by adding n to Last Working Day Index, and applying this as a filter on Working Day Index.
Date =
VAR StartDate =
dt"2023-01-01"
VAR EndDate =
dt"2023-12-31"
-- Sample Holidays
VAR Holidays =
{
dt"2023-01-01",
dt"2023-01-02",
dt"2023-01-16",
dt"2023-02-20",
dt"2023-05-29",
dt"2023-06-19",
dt"2023-07-04",
dt"2023-09-04",
dt"2023-10-09",
dt"2023-11-10",
dt"2023-11-11",
dt"2023-11-23",
dt"2023-12-25"
}
VAR DateBase = CALENDAR ( StartDate, EndDate )
VAR DateFinal =
GENERATE (
DateBase,
VAR d = [Date]
VAR IsWorkingDay = NETWORKDAYS ( d, d, 1, Holidays )
VAR LastWorkingDayIndex =
NETWORKDAYS ( StartDate, d, 1, Holidays )
VAR WorkingDayIndex =
IF (
IsWorkingDay,
LastWorkingDayIndex
)
RETURN
ROW (
"Is Working Day", IsWorkingDay,
"Working Day Index", WorkingDayIndex,
"Last Working Day Index", LastWorkingDayIndex
)
)
RETURN
DateFinal
Would something like that work for you?
Regards
User | Count |
---|---|
14 | |
9 | |
7 | |
7 | |
6 |
User | Count |
---|---|
21 | |
11 | |
10 | |
10 | |
8 |