cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
oliverblane
Helper I
Helper I

Optimise Query for Calculating Number of Business Days

I have a table "DateTable" which has two columns:

  • the first is every date between a start date (1st March 2019) and the current date
  • the second is the number of business days that have occurred between that row and the first row (i.e. excluding weekends and holidays), where holidays are stored in a table "bank-holidays-dl".

A snippet of the table:

oliverblane_2-1638377096947.png

 

I set up the DateTable by creating a list of dates between the start and end date using List.Dates, converting it to a table, and then applying the following custom function to get the number of business days counting from the 01/03/2019:

(StartDate as date, EndDate as date) as number =>

let
ListDates = List.Dates(StartDate, Number.From(EndDate - StartDate), #duration(1, 0, 0, 0)),
RemoveWeekends = List.Select(ListDates, each Date.DayOfWeek(_, Day.Monday) < 5),
RemoveHolidays = List.RemoveItems(RemoveWeekends, #"bank-holidays-dl"),
CountDays = List.Count(RemoveHolidays)
in
CountDays

 The function works as expected, however refreshing the data takes a long time. I was wondering if there could be any way to optimise this? Thank you!

1 ACCEPTED SOLUTION
AlexisOlson
Super User
Super User

The key to performance is to only calculate this column once instead of once for each row of your date table.

My approach would be to add an index column after filtering out weekends and holidays and then merge this back with the original dates.

 

let
    StartDate = #date(2019, 3, 1),
    EndDate = Date.From(DateTime.LocalNow()),
    ListDates = List.Dates(StartDate, Number.From(EndDate - StartDate), #duration(1, 0, 0, 0)),
    ListToTable = Table.FromList(ListDates, Splitter.SplitByNothing(), {"Date"}),
    DateTable = Table.TransformColumnTypes(ListToTable, {{"Date", type date}}),
    RemoveDays = Table.SelectRows(DateTable, each Date.DayOfWeek([Date], 1) < 5 and
                                                  not List.Contains(#"bank-holidays-dl",
    AddIndex = Table.AddIndexColumn(RemoveDays, "Index", 1, 1, Int64.Type),
    MergeQueries = Table.NestedJoin(DateTable, {"Date"}, AddIndex, {"Date"}, "RemovedDays", JoinKind.LeftOuter),
    ExplandIndex = Table.ExpandTableColumn(MergeQueries, "RemovedDays", {"Index"}, {"WorkingDaysSinceStart"}),
    SortRows = Table.Sort(ExplandIndex,{{"Date", Order.Ascending}}),
    FillDown = Table.FillDown(SortRows, {"WorkingDaysSinceStart"})
in
    FillDown

 

View solution in original post

3 REPLIES 3
CNENFRNL
Community Champion
Community Champion

(StartDate as date, EndDate as date) =>

List.Accumulate(
    List.Dates(StartDate, Duration.TotalDays(EndDate - StartDate), #duration(1, 0, 0, 0)),
    0,
    (s,c) => if Date.DayOfWeek(c, Day.Monday) >= 5 or List.Contains(#"bank-holidays-dl", c) then s else s+1
)
AlexisOlson
Super User
Super User

The key to performance is to only calculate this column once instead of once for each row of your date table.

My approach would be to add an index column after filtering out weekends and holidays and then merge this back with the original dates.

 

let
    StartDate = #date(2019, 3, 1),
    EndDate = Date.From(DateTime.LocalNow()),
    ListDates = List.Dates(StartDate, Number.From(EndDate - StartDate), #duration(1, 0, 0, 0)),
    ListToTable = Table.FromList(ListDates, Splitter.SplitByNothing(), {"Date"}),
    DateTable = Table.TransformColumnTypes(ListToTable, {{"Date", type date}}),
    RemoveDays = Table.SelectRows(DateTable, each Date.DayOfWeek([Date], 1) < 5 and
                                                  not List.Contains(#"bank-holidays-dl",
    AddIndex = Table.AddIndexColumn(RemoveDays, "Index", 1, 1, Int64.Type),
    MergeQueries = Table.NestedJoin(DateTable, {"Date"}, AddIndex, {"Date"}, "RemovedDays", JoinKind.LeftOuter),
    ExplandIndex = Table.ExpandTableColumn(MergeQueries, "RemovedDays", {"Index"}, {"WorkingDaysSinceStart"}),
    SortRows = Table.Sort(ExplandIndex,{{"Date", Order.Ascending}}),
    FillDown = Table.FillDown(SortRows, {"WorkingDaysSinceStart"})
in
    FillDown

 

View solution in original post

This worked perfectly, thank you!

Helpful resources

Announcements
2022 Release Wave 1 760x460.png

2022 Release Wave 1 Plan

Power Platform release plan for the 2022 release wave 1 describes all new features releasing from April 2022 through September 2022.

Power BI December 2021 Update_carousel 768x460.jpg

Check it Out!

Click here to read more about the December 2021 Updates!

Jan 2022 Dev Camp 768x460 copy.png

Power BI Dev Camp- January 27th, 2022

Mark your calendars and join us for our next Power BI Dev Camp!

Top Solution Authors