cancel
Showing results for 
Search instead for 
Did you mean: 
Reply
mariyahd
Frequent Visitor

Fix Measure to max date between selected dates

Hi all, 

 

I've spent quite a lot of time trying to figure this out. I'm hoping someone can help.

I have a table with the following columns:

LoanID    Date             State

003         05/05/2021   InArrears

003         06/05/2021   Cured

003         11/05/2021   Settled

 

Every loan has a row for each date until it settles.

I also have a calendar table with Date that I'm using as a filter to display number of accounts that have entered arrears in the time period selected in the filter. I need to create a measure that shows the number of loans in specific state at the end of the selected period. 

I tried:

No Of Accts Last State =
var maxdate=MAX('Calendar'[Date])
return
CALCULATE([EnteredArrears],'Table'[Date]=maxdate)
 
EnteredArrears is a measure that calculates he number of loans that have entered arrears during the selected time period.
 
The problem with the above measure is that if a loan settled before the selected maxdate it's excluded. How do I filter for maximum Date <=maxdate and still pull just one row per loan?
 
Thanks,
Mariya

 

1 ACCEPTED SOLUTION
v-jayw-msft
Community Support
Community Support

Hi @mariyahd ,

 

Check the measures.

Measure 1 = 
var _maxdate = CALCULATE(MAX('Table'[Date]),FILTER(ALLEXCEPT('Table','Table'[Loan ID]),'Table'[Date]<=MAX('date'[date])))
return
CALCULATE(MAX('Table'[State]),FILTER('Table','Table'[Date]=_maxdate))

Measure 2 = CALCULATE(DISTINCTCOUNT('Table'[Loan ID]),FILTER('Table','Table'[State]=[Measure 1]))+0

Measure 1 is to get the latest status for each id according to the slicer date.

Measure 2 is to count the ids for each status.

11.PNG

12.PNG 

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

1 REPLY 1
v-jayw-msft
Community Support
Community Support

Hi @mariyahd ,

 

Check the measures.

Measure 1 = 
var _maxdate = CALCULATE(MAX('Table'[Date]),FILTER(ALLEXCEPT('Table','Table'[Loan ID]),'Table'[Date]<=MAX('date'[date])))
return
CALCULATE(MAX('Table'[State]),FILTER('Table','Table'[Date]=_maxdate))

Measure 2 = CALCULATE(DISTINCTCOUNT('Table'[Loan ID]),FILTER('Table','Table'[State]=[Measure 1]))+0

Measure 1 is to get the latest status for each id according to the slicer date.

Measure 2 is to count the ids for each status.

11.PNG

12.PNG 

 

Best Regards,

Jay

Community Support Team _ Jay
If this post helps, then please consider Accept it as the solution
to help the other members find it.

View solution in original post

Helpful resources

Announcements
MBAS on Demand

2021 Release Wave 2 Plan

Power Platform release plan for the 2021 release wave 2 describes all new features releasing from October 2021 through March 2022.

July 2021 Update 768x460.png

Check it out!

Click here to read more about the July 2021 Updates

Power Query PA Forum 768x460.png

Check it out!

Did you know that you can visit the Power Query Forum in Power BI and now Power Apps

Urdu Hindi D365 Bootcamp 768x460.png

Urdu Hindi D365 Bootcamp

Dont miss our very own April Dunnam’s The Developer Guide to the Galaxy! Find out what the Power Platform has to offer for the traditional developer.

Top Solution Authors
Top Kudoed Authors