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

Join us for an expert-led overview of the tools and concepts you'll need to become a Certified Power BI Data Analyst and pass exam PL-300. Register now.

Reply
aallman
Helper I
Helper I

Calculate Past Due Backlog Over Time

I have a data set that includes all line items sold, their due dates, actual ship dates, and value. I am able to calculate today's past due backlog (PDBL) by summing the value of all lines whose due date is before today but whose ship date is blank. What I want to do is to create a table that shows what the PDBL was on each day. I don't know how to do this. How can I create a table of dates and compare each line to the date in the table to say 'count me if my due date is before this day but my ship date is on or after this day'. I don't know how to create a table with dates that are not linked specifically to a date for each line item sold, because items can be counted in multiple days if they are late by multiple days. So if something was due 10/2/22 and shipped 10/4/22 I would want its value counted in both 10/3/22 and 10/4/22 of the table.

 

What date do I use in my output table? Do I have to somehow create a new field? Would I create a measure to reference this new date field and how do I do that? 

 

Here is a quick very simplified example set of data and an example of what I want my output to look like:

Example Data

Order #Order DateDue DateShip DateValue
109/30/2210/1/2210/3/22$5
210/1/2210/2/2210/3/22$7
310/2/2210/3/2210/4/22$10
410/2/2210/4/2210/4/22$5
510/3/2210/4/2210/5/22$5

 

Output Visual:

DateBacklog ValueBacklog Count
10/02/22$51
10/03/22$122
10/04/22$101
10/05/22$51
1 ACCEPTED SOLUTION
Anonymous
Not applicable

Hi @aallman 

First , you need create a date table to compare with Due date and Ship date . You can extract date from your sample data table . Create a calculated table like this :

 

Table 2 = CALENDAR(MIN('Table'[Due Date]),MAX('Table'[Ship Date]))

 

You will get a table like this :

Ailsamsft_0-1667444659650.png

Then create measures to return the sum and count .

 

Sum = CALCULATE(SUM('Table'[Value]),FILTER(ALL('Table'),'Table'[Due Date]<MIN('Table 2'[Date])&&'Table'[Ship Date]>=MIN('Table 2'[Date])))
count = CALCULATE(COUNT('Table'[Value]),FILTER(ALL('Table'),'Table'[Due Date]<MIN('Table 2'[Date])&&'Table'[Ship Date]>=MIN('Table 2'[Date])))

 

You will get the result you want .

Ailsamsft_1-1667444764507.png

 

Best Regards,
Community Support Team _ Ailsa Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

View solution in original post

1 REPLY 1
Anonymous
Not applicable

Hi @aallman 

First , you need create a date table to compare with Due date and Ship date . You can extract date from your sample data table . Create a calculated table like this :

 

Table 2 = CALENDAR(MIN('Table'[Due Date]),MAX('Table'[Ship Date]))

 

You will get a table like this :

Ailsamsft_0-1667444659650.png

Then create measures to return the sum and count .

 

Sum = CALCULATE(SUM('Table'[Value]),FILTER(ALL('Table'),'Table'[Due Date]<MIN('Table 2'[Date])&&'Table'[Ship Date]>=MIN('Table 2'[Date])))
count = CALCULATE(COUNT('Table'[Value]),FILTER(ALL('Table'),'Table'[Due Date]<MIN('Table 2'[Date])&&'Table'[Ship Date]>=MIN('Table 2'[Date])))

 

You will get the result you want .

Ailsamsft_1-1667444764507.png

 

Best Regards,
Community Support Team _ Ailsa Tao
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

Helpful resources

Announcements
Join our Fabric User Panel

Join our Fabric User Panel

This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.

June 2025 Power BI Update Carousel

Power BI Monthly Update - June 2025

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

June 2025 community update carousel

Fabric Community Update - June 2025

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