Power BI is turning 10, and we’re marking the occasion with a special community challenge. Use your creativity to tell a story, uncover trends, or highlight something unexpected.
Get startedJoin 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.
I want to get the aging of the items in each month from opened date to closed date.
So for the table below, what would be the age of the items below in April, then May, June and so forth. The aging will stop once the fill date has come. If no fill date, then today will be used.
Opened Date | Closed Date | April | May | June | July | August |
5/1/2023 | 8/16/2023 | |||||
4/1/2023 |
Hope this makes sense. Thanks in advance!
Solved! Go to Solution.
I assume you have a Date table. Here is the measure:
age =
VAR monthStart = MIN ( 'Date'[Date] )
VAR monthEnd = MAX ( 'Date'[Date] )
VAR opened = SELECTEDVALUE ( 'Table'[Opened Date] )
VAR closed = COALESCE ( SELECTEDVALUE ( 'Table'[Closed Date] ), TODAY () )
VAR days = DATEDIFF ( opened, monthEnd, DAY ) + 1
RETURN
IF ( TODAY () > monthEnd && monthStart >= opened && monthEnd <= closed, days )
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly. Appreciate your Kudos.
Check out my latest demo report in the data story gallery.
Stand with Ukraine!
Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/
Thank you!
Hi @Anonymous , should the age be in days or months? As far as I understand you have a matrix with months as columns.
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly. Appreciate your Kudos.
Check out my latest demo report in the data story gallery.
Stand with Ukraine!
Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/
Thank you!
Hi! The age should be in days. For the months in columns, I want to know the age if that month is finished.
I assume you have a Date table. Here is the measure:
age =
VAR monthStart = MIN ( 'Date'[Date] )
VAR monthEnd = MAX ( 'Date'[Date] )
VAR opened = SELECTEDVALUE ( 'Table'[Opened Date] )
VAR closed = COALESCE ( SELECTEDVALUE ( 'Table'[Closed Date] ), TODAY () )
VAR days = DATEDIFF ( opened, monthEnd, DAY ) + 1
RETURN
IF ( TODAY () > monthEnd && monthStart >= opened && monthEnd <= closed, days )
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly. Appreciate your Kudos.
Check out my latest demo report in the data story gallery.
Stand with Ukraine!
Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/
Thank you!
Thank you so much for your help, Mate! One last question, what if I want to get the age up to the current day or up to the closed date? for example in the row 2, the closed date is 8/16, right? I want to get the age on the August column but up to the August 16 only.
age =
VAR monthStart =
MIN ( 'Date'[Date] )
VAR monthEnd =
MAX ( 'Date'[Date] )
VAR opened =
SELECTEDVALUE ( 'Table'[Opened Date] )
VAR closed =
COALESCE ( SELECTEDVALUE ( 'Table'[Closed Date] ), TODAY () )
VAR days =
DATEDIFF ( opened, monthEnd, DAY ) + 1
VAR endDay =
IF ( monthEnd <= closed, monthEnd, closed )
VAR days_last =
DATEDIFF ( opened, endDay, DAY ) + 1
RETURN
IF ( TODAY () > monthEnd && monthStart >= opened, days_last )
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly. Appreciate your Kudos.
Check out my latest demo report in the data story gallery.
Stand with Ukraine!
Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/
Thank you!
Thanks for this. My problem with this is that if the monthEnd is greater than today and the monthStart < opened, the data is skewed and I tried creating a solution but to no avail. 😞
This is perfecly working! I have another question, would it be possible to count the number of items whose age is 90+? For example, in the month of June, there is 1 item whose age is 91 so that should count as 1 for the month of June only.
Hi. Yes.
age 90+ =
VAR t =
FILTER (
ADDCOLUMNS (
GENERATE (
VALUES ( 'Date'[Month-Year] ),
SUMMARIZE ( 'Table', 'Table'[Opened Date], 'Table'[Closed Date] )
),
"@age", [age]
),
[@age] >= 90
)
RETURN
COUNTROWS ( t )
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly. Appreciate your Kudos.
Check out my latest demo report in the data story gallery.
Stand with Ukraine!
Here are official ways you can support Ukraine financially (accounts with multiple currencies):
1) Support the Armed Forces of Ukraine: https://bank.gov.ua/ua/about/support-the-armed-forces
2) Come Back Alive foundation: https://www.comebackalive.in.ua/
Thank you!
This is your chance to engage directly with the engineering team behind Fabric and Power BI. Share your experiences and shape the future.
Check out the June 2025 Power BI update to learn about new features.
User | Count |
---|---|
14 | |
11 | |
10 | |
10 | |
9 |
User | Count |
---|---|
18 | |
13 | |
12 | |
11 | |
8 |