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

Compete to become Power BI Data Viz World Champion! First round ends August 18th. Get started.

Reply
deek2123
New Member

Add working days to a submitted date

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:

 

Calc_Is Business Day = IF(WEEKDAY('dw Dim_Date'[Calendar_Date])=1 || WEEKDAY('dw Dim_Date'[Calendar_Date])=7 || NOT(ISBLANK('dw Dim_Date'[Is_Holiday])),0,1)
 
Calc_Rank Business Day = RANKX(FILTER('dw Dim_Date','dw Dim_Date'[Calc_Is Business Day]=1),'dw Dim_Date'[Calendar_Date].[Date],,ASC)
 
Calc_Plus 10 BD = LOOKUPVALUE('dw Dim_Date'[Calendar_Date],'dw Dim_Date'[Calc_Is Business Day],1,'dw Dim_Date'[Calc_Rank Business Day],'dw Dim_Date'[Calc_Rank Business Day]+10)
 
This works in my Calendar table and I am having trouble getting this to translate to my record table where I have a table.date_submitted_adjusted column that adjusts the date based on the time of submission. For example, if a record is submitted after 5PM then it shows an adjusted date of Date_submitted+1day. 
 
I would like to be able to display a column with my date_submitted_adjusted and then a column that shows a date that is +10BD. 
1 ACCEPTED SOLUTION
parry2k
Super User
Super User

@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.

View solution in original post

3 REPLIES 3
parry2k
Super User
Super User

@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!

mahoneypat
Microsoft Employee
Microsoft Employee

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





Did I answer your question? Mark my post as a solution! Kudos are also appreciated!

To learn more about Power BI, follow me on Twitter or subscribe on YouTube.


@mahoneypa HoosierBI on YouTube


Helpful resources

Announcements
August Power BI Update Carousel

Power BI Monthly Update - August 2025

Check out the August 2025 Power BI update to learn about new features.

August 2025 community update carousel

Fabric Community Update - August 2025

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

Top Solution Authors