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

Be 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

Reply
LoonaMoon
Frequent Visitor

Use List.Number to generate dates in a loop

Hi everyone,

 

I'm trying to generate calendar of holidays for the next 6 years. Where I live, it is a common practice to add an extra day to a holiday if the actual holiday occures on weekends. For example, this year January 1st was on Sunday, that's why we had additional day off on Tuesday, January 3rd since January 2 is a holiday as well. 

The idea is as such:

There is a table of holidays without actual dates:

LoonaMoon_0-1680260879735.png

I need to generate dates of holidays for 2023 - 2029 so in result I will have a table:

LoonaMoon_2-1680261180949.png

 

If the holiday is on weekend I need to add an additional row with extra day off:

LoonaMoon_4-1680261238798.png

 

It's all feasible with separate steps in Power Query

- I generated list of years for each row

- Then Expanded to New Rows

- With #date function generated dates

- checked if it is weekend via Custom Column

 

But how to make it more dynamic and automatic in case the range of years will change.

I plan to take min - max years from a Sharepoint List with tasks from MS Project.

So I need to take min-max year from it, generate list of years, generate dates for holidays and check if tis weekend, and if it is add an extra row for additiona day off.

 

I appreciate your help!

 

Create a list of numbers using a variable, Relate a Sharepoint User Information List to Another SharePoint List Loop through the table in M query 

1 ACCEPTED SOLUTION
BA_Pete
Super User
Super User

Hi @LoonaMoon ,

 

I would recommend looking for state holidays on your government's website and either scrape that or download from the endpoint.

For example, I'm in the UK and the GOV website has the following endpoint: https://www.gov.uk/bank-holidays.json 

 

Using this, I just run the following query in a dataflow each night to have the most up-to-date listings:

let
  Source = Json.Document(Web.Contents("https://www.gov.uk/bank-holidays.json")),
  toList = Record.ToList(Source),
  toTable = Table.FromRecords(toList),
  expandEandWevents = toTable{0}[events],
  toTable2 = Table.FromList(expandEandWevents, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
  expandRecords = Table.ExpandRecordColumn(toTable2, "Column1", {"title", "date", "notes", "bunting"}, {"title", "date", "notes", "bunting"}),
  remOthCols = Table.SelectColumns(expandRecords, {"date", "title", "notes"}),
  repQE2Funeral = Table.ReplaceValue(remOthCols, "Bank Holiday for the State Funeral of Queen Elizabeth II", "QE2 State Funeral BH", Replacer.ReplaceValue, {"title"}),
  repKC3Coronation = Table.ReplaceValue(repQE2Funeral, "Bank holiday for the coronation of King Charles III", "KC3 Coronation BH", Replacer.ReplaceValue, {"title"}),
  repBankHol1 = Table.ReplaceValue(repKC3Coronation, "bank holiday", "BH", Replacer.ReplaceText, {"title"}),
  repBankHol2 = Table.ReplaceValue(repBankHol1, "Bank Holiday", "BH", Replacer.ReplaceText, {"title"}),
  repBankHol3 = Table.ReplaceValue(repBankHol2, "Bank holiday", "BH", Replacer.ReplaceText, {"title"}),
  chgTypes = Table.TransformColumnTypes(repBankHol3,{{"title", type text}, {"date", type date}, {"notes", type text}}),
  renCols = Table.RenameColumns(chgTypes, {{"title", "holiday"}})
in
  renCols

 

Query output:

BA_Pete_0-1680266146081.png

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




View solution in original post

2 REPLIES 2
AlienSx
Super User
Super User

Hello, @LoonaMoon . So you have a code for single year, right? Then

 - create a custom function out of your code with holidays table and year as parameters.

 - generate a list of years {year_from..year_to}.

 - transform this list List.Transform(years_list, each function_name(holidays, _)).

 - and finally List.Combine to get a single table with all your dates. 

BA_Pete
Super User
Super User

Hi @LoonaMoon ,

 

I would recommend looking for state holidays on your government's website and either scrape that or download from the endpoint.

For example, I'm in the UK and the GOV website has the following endpoint: https://www.gov.uk/bank-holidays.json 

 

Using this, I just run the following query in a dataflow each night to have the most up-to-date listings:

let
  Source = Json.Document(Web.Contents("https://www.gov.uk/bank-holidays.json")),
  toList = Record.ToList(Source),
  toTable = Table.FromRecords(toList),
  expandEandWevents = toTable{0}[events],
  toTable2 = Table.FromList(expandEandWevents, Splitter.SplitByNothing(), null, null, ExtraValues.Error),
  expandRecords = Table.ExpandRecordColumn(toTable2, "Column1", {"title", "date", "notes", "bunting"}, {"title", "date", "notes", "bunting"}),
  remOthCols = Table.SelectColumns(expandRecords, {"date", "title", "notes"}),
  repQE2Funeral = Table.ReplaceValue(remOthCols, "Bank Holiday for the State Funeral of Queen Elizabeth II", "QE2 State Funeral BH", Replacer.ReplaceValue, {"title"}),
  repKC3Coronation = Table.ReplaceValue(repQE2Funeral, "Bank holiday for the coronation of King Charles III", "KC3 Coronation BH", Replacer.ReplaceValue, {"title"}),
  repBankHol1 = Table.ReplaceValue(repKC3Coronation, "bank holiday", "BH", Replacer.ReplaceText, {"title"}),
  repBankHol2 = Table.ReplaceValue(repBankHol1, "Bank Holiday", "BH", Replacer.ReplaceText, {"title"}),
  repBankHol3 = Table.ReplaceValue(repBankHol2, "Bank holiday", "BH", Replacer.ReplaceText, {"title"}),
  chgTypes = Table.TransformColumnTypes(repBankHol3,{{"title", type text}, {"date", type date}, {"notes", type text}}),
  renCols = Table.RenameColumns(chgTypes, {{"title", "holiday"}})
in
  renCols

 

Query output:

BA_Pete_0-1680266146081.png

 

Pete



Now accepting Kudos! If my post helped you, why not give it a thumbs-up?

Proud to be a Datanaut!




Helpful resources

Announcements
Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!

November Carousel

Fabric Community Update - November 2024

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

Dec Fabric Community Survey

We want your feedback!

Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.