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

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
Anonymous
Not applicable

How to get the the Last Contract Termination's Cause using DAX ( LAST_VALUE Over Partition in SQL)

Hi everyone,

 

I have this non-sorted table that is listing for each contractID all the status of this contract. 

anas-elkesri_0-1609555124832.png

 

You'll notice that a contract status can be at Terminated and then get back to "On-Going" and that the table is not sorted by year

 

I want to get as an output FOR EACH CONTRACT the Status Reason for the LAST time the CONTRACT STATUS have been TERMINATED. 

 

SO i should get this values for the ContractID 1 and 2.

 
IDLast Termination Status
1By Choice
2Retirement
 
 

I know i can get it using SQL with something like this : 

 

LastTerminationStatus =  LAST_VALUE(StatusReason) OVER (PARTITION By ID ORDER By StatusDate) Where ContractStatus = "Terminated"

 

But i really don't know how to get it using DAX. I tried LASTNONBLANK but this fuction requires a sorted table which is not the case here

 

Thank your in advance for your help !!

 

 

 

1 ACCEPTED SOLUTION
parry2k
Super User
Super User

@Anonymous here are two measures that can get you the result

 

Last Terminate Reason Method 1 = 
CALCULATE (
    MAX ( 'Last Terminate'[Status Reason] ),
    TOPN ( 1, FILTER ( ALLEXCEPT ( 'Last Terminate', 'Last Terminate'[Id] ), 'Last Terminate'[Contract Status] = "Terminated" ), [Status Date], DESC )
)

Last Terminate Reason Method 2 = 
VAR __table = FILTER ( ALLEXCEPT ( 'Last Terminate', 'Last Terminate'[Id] ), 'Last Terminate'[Contract Status] = "Terminated"  ) 
VAR __lastDate = CALCULATE ( MAX (  'Last Terminate'[Status Date] ), __table )
RETURN
CALCULATE (
    MAX ( 'Last Terminate'[Status Reason] ),
    __table,
    'Last Terminate'[Status Date] = __lastDate
)

 

Check my latest blog post Year-2020, Pandemic, Power BI and Beyond to get a summary of my favourite Power BI feature releases in 2020

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

@Anonymous here are two measures that can get you the result

 

Last Terminate Reason Method 1 = 
CALCULATE (
    MAX ( 'Last Terminate'[Status Reason] ),
    TOPN ( 1, FILTER ( ALLEXCEPT ( 'Last Terminate', 'Last Terminate'[Id] ), 'Last Terminate'[Contract Status] = "Terminated" ), [Status Date], DESC )
)

Last Terminate Reason Method 2 = 
VAR __table = FILTER ( ALLEXCEPT ( 'Last Terminate', 'Last Terminate'[Id] ), 'Last Terminate'[Contract Status] = "Terminated"  ) 
VAR __lastDate = CALCULATE ( MAX (  'Last Terminate'[Status Date] ), __table )
RETURN
CALCULATE (
    MAX ( 'Last Terminate'[Status Reason] ),
    __table,
    'Last Terminate'[Status Date] = __lastDate
)

 

Check my latest blog post Year-2020, Pandemic, Power BI and Beyond to get a summary of my favourite Power BI feature releases in 2020

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.

Anonymous
Not applicable

Thank you very much for your answer.

The first method didn't get me the result i want. But the second one did work perfectly and is also a pretty nice method. So thank you again !! 🙂

amitchandak
Super User
Super User

@Anonymous , check if one of the measure can work for you

 

measure = calculate(lastnonblankvalue(Table[status_date], max(Table[contract_status])))


measure = calculate(lastnonblankvalue(Table[status_date], max(Table[contract_status])) allexcept(Table[ID]))

 

measure = calculate(max(Table[contract_status]), filter(Table,Table[status_date] = calculate(max(Table[status_date]), allexpcept(Table,table[ID]))))

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

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