The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hi, I have a table which shows a created date for when invoices are entered into our system. I need to add workdays onto this date to get our SLA Date. I have a Date Table which has a weekday index included with days 1-5 (saturday and sunday included as day 5). I need to add the workdays onto the created date. The two tables are connected by created date from the Invoices file and Dates from the Date table. Any help would be greatly appreciated.
Solved! Go to Solution.
Hi @Lesley1Storey ,
Don't know if you want a calculated column or a measure but you can do the following.
Create a column on your calendar table
Workday =
SWITCH (
TRUE ();
WEEKDAY('Calendar'[Date]) IN { 6 ; 7 }; FALSE ();
TRUE ()
)
Now add the following measure to your model:
Forecasted End Date =
----------------------------------------------------------
VAR relevantdate =
SELECTEDVALUE(Invoices[Date]) --this can be replaced by TODAY()
VAR workdaysremain =
15 --Can be adjusted to be another value
---------------------------------------------------------
/* create a virtual date table only for working days starting from
the relevant date and only for the workdays remaining */
VAR workingdateTable =
TOPN (
workdaysremain;
CALCULATETABLE (
'Calendar';
'Calendar'[Workday] = TRUE ();
'Calendar'[Date] >= relevantdate
)
)
---------------------------------------------------------
/* find the maximum date in the virtual table, which will be
the forecasted end date */
VAR futuredate =
CALCULATE ( MAX ( 'Calendar'[Date] ); workingdateTable )
---------------------------------------------------------
RETURN
futuredate
this was adapted from the post below:
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsHi @Lesley1Storey ,
Don't know if you want a calculated column or a measure but you can do the following.
Create a column on your calendar table
Workday =
SWITCH (
TRUE ();
WEEKDAY('Calendar'[Date]) IN { 6 ; 7 }; FALSE ();
TRUE ()
)
Now add the following measure to your model:
Forecasted End Date =
----------------------------------------------------------
VAR relevantdate =
SELECTEDVALUE(Invoices[Date]) --this can be replaced by TODAY()
VAR workdaysremain =
15 --Can be adjusted to be another value
---------------------------------------------------------
/* create a virtual date table only for working days starting from
the relevant date and only for the workdays remaining */
VAR workingdateTable =
TOPN (
workdaysremain;
CALCULATETABLE (
'Calendar';
'Calendar'[Workday] = TRUE ();
'Calendar'[Date] >= relevantdate
)
)
---------------------------------------------------------
/* find the maximum date in the virtual table, which will be
the forecasted end date */
VAR futuredate =
CALCULATE ( MAX ( 'Calendar'[Date] ); workingdateTable )
---------------------------------------------------------
RETURN
futuredate
this was adapted from the post below:
Regards
Miguel Félix
Proud to be a Super User!
Check out my blog: Power BI em PortuguêsJoin the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
111 | |
82 | |
63 | |
54 | |
52 |
User | Count |
---|---|
128 | |
115 | |
80 | |
65 | |
63 |