The ultimate Fabric, Power BI, SQL, and AI community-led learning event. Save €200 with code FABCOMM.
Get registeredCompete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.
I am new-ish to Power BI and I am trying to display a column with the date that is 10 working days after a record is submitted. I already have a calendar table in my model and I have added some new columns to give me the base info I think I need:
Solved! Go to Solution.
@deek2123 watch the video provided by @mahoneypat or use the following expression to add a column that I used many times to achieve something similar, in this expression, we are calculating x number of days after the order date to get the ship date, you can replace the table and column name as per you model. The only thing is required is to have a "working day" flag in your date dimension.
Shipping Date =
VAR __numberofDays = 10
VAR __orderDate = Orders[Order Date]
VAR __dateTable =
CALCULATETABLE (
VALUES ( 'Dim Date Table'[Date] ),
'Dim Date Table'[Is Working Day] = 1,
'Dim Date Table'[Date] >= __orderDate
)
VAR __dateTableWithRank =
ADDCOLUMNS (
__dateTable,
"@Rank", RANKX ( __dateTable, [Date], , ASC, Dense )
)
RETURN
MAXX (
FILTER (
__dateTableWithRank,
[@Rank] = __numberofDays + 1
),
[Date]
)
Check my latest blog post Compare Budgeted Scenarios vs. Actuals I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!
⚡Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.⚡
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
@deek2123 watch the video provided by @mahoneypat or use the following expression to add a column that I used many times to achieve something similar, in this expression, we are calculating x number of days after the order date to get the ship date, you can replace the table and column name as per you model. The only thing is required is to have a "working day" flag in your date dimension.
Shipping Date =
VAR __numberofDays = 10
VAR __orderDate = Orders[Order Date]
VAR __dateTable =
CALCULATETABLE (
VALUES ( 'Dim Date Table'[Date] ),
'Dim Date Table'[Is Working Day] = 1,
'Dim Date Table'[Date] >= __orderDate
)
VAR __dateTableWithRank =
ADDCOLUMNS (
__dateTable,
"@Rank", RANKX ( __dateTable, [Date], , ASC, Dense )
)
RETURN
MAXX (
FILTER (
__dateTableWithRank,
[@Rank] = __numberofDays + 1
),
[Date]
)
Check my latest blog post Compare Budgeted Scenarios vs. Actuals I would ❤ Kudos if my solution helped. 👉 If you can spend time posting the question, you can also make efforts to give Kudos to whoever helped to solve your problem. It is a token of appreciation!
⚡Visit us at https://perytus.com, your one-stop-shop for Power BI-related projects/training/consultancy.⚡
Subscribe to the @PowerBIHowTo YT channel for an upcoming video on List and Record functions in Power Query!!
Learn Power BI and Fabric - subscribe to our YT channel - Click here: @PowerBIHowTo
If my solution proved useful, I'd be delighted to receive Kudos. When you put effort into asking a question, it's equally thoughtful to acknowledge and give Kudos to the individual who helped you solve the problem. It's a small gesture that shows appreciation and encouragement! ❤
Did I answer your question? Mark my post as a solution. Proud to be a Super User! Appreciate your Kudos 🙂
Feel free to email me with any of your BI needs.
This worked perfectly. Thanks!
Please see this video on how to do this.
(2) Power BI - Tales from the Front #03 - Due Date From Working Days - YouTube
Regards,
Pat
To learn more about Power BI, follow me on Twitter or subscribe on YouTube.