Fabric is Generally Available. Browse Fabric Presentations. Work towards your Fabric certification with the Cloud Skills Challenge.
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.
appreciate any help here @swat @mahoneypat @edhans @PhilipTreacy
Solved! Go to Solution.
@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)
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
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
Now, add a new column in your data table and use the formula =fnPreviousWorkday([NameOfDateColumn])
DAX is for Analysis. Power Query is for Data Modeling
Proud to be a Super User!
MCSA: BI Reporting@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)
⭕ Subscribe and learn Power BI from these videos
⚪ Website ⚪ LinkedIn ⚪ PBI User Group
Check out the November 2023 Power BI update to learn about new features.
Read the latest Fabric Community announcements, including updates on Power BI, Synapse, Data Factory and Data Activator.