cancel
Showing results for 
Search instead for 
Did you mean: 

Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.

Reply
Anonymous
Not applicable

Function - get previous workday date

I am looking for some power query gurus help here , as am totally unfamiliar with M language . 

 

i would need to create a function to get my previous working day date . 

E.g.

  1. if today is May 31st then expected result is 28th May 2021
  2. if today is 1st june 2021 then expected result it 31st May 

 

appreciate any help here @swat  @mahoneypat @edhans @PhilipTreacy 

1 ACCEPTED SOLUTION
Fowmy
Super User
Super User

@Anonymous 

Add the following code as a new custom column: 

let
  today = Date.From(DateTime.LocalNow()), 
  d     = Date.DayOfWeek(today, Day.Monday)
in
  if d = 6 then
    Date.AddDays(today, - 2)
  else if d = 0 then
    Date.AddDays(today, - 3)
  else
    Date.AddDays(today, - 1)
Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

View solution in original post

3 REPLIES 3
edhans
Super User
Super User

Here is a cutom function to do that @Anonymous 

(varDate as date) =>
let
    Source = 
        let
            varDayOfWeek = Date.DayOfWeek(varDate, Day.Monday)
        in
        if varDayOfWeek = 0 then Date.AddDays(varDate, -3)
        else if varDayOfWeek = 6 then Date.AddDays(varDate, -2)
        else Date.AddDays(varDate, -1)
in
    Source

 

  1. Create a new blank query
  2. In the advanced editor, remove ALL of the code
  3. Paste the code above into the advanced editor and press Done.
  4. Rename it fnPreviousWorkDay (instead of Query1 or whatever it was called.

Now, add a new column in your data table and use the formula =fnPreviousWorkday([NameOfDateColumn])

edhans_0-1622735882893.png

 



Did I answer your question? Mark my post as a solution!
Did my answers help arrive at a solution? Give it a kudos by clicking the Thumbs Up!

DAX is for Analysis. Power Query is for Data Modeling


Proud to be a Super User!

MCSA: BI Reporting
Fowmy
Super User
Super User

@Anonymous 

Add the following code as a new custom column: 

let
  today = Date.From(DateTime.LocalNow()), 
  d     = Date.DayOfWeek(today, Day.Monday)
in
  if d = 6 then
    Date.AddDays(today, - 2)
  else if d = 0 then
    Date.AddDays(today, - 3)
  else
    Date.AddDays(today, - 1)
Did I answer your question? Mark my post as a solution! and hit thumbs up


Subscribe and learn Power BI from these videos

Website LinkedIn PBI User Group

Anonymous
Not applicable

Thanks @Fowmy  really appreciate your time for responding to my query .

Helpful resources

Announcements
PBI November 2023 Update Carousel

Power BI Monthly Update - November 2023

Check out the November 2023 Power BI update to learn about new features.

Community News

Fabric Community News unified experience

Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.

Power BI Fabric Summit Carousel

The largest Power BI and Fabric virtual conference

130+ sessions, 130+ speakers, Product managers, MVPs, and experts. All about Power BI and Fabric. Attend online or watch the recordings.