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
rixmcx59
Helper IV
Helper IV

Getting previous date by category, not min date

Hello all, this Measure is working as long as there are only 2 dates Min and Max, but I need to get the date before Max regardless if it's Min or not. 1 table, 1 date column and 1 category column. I have a date table but I am not using it here. Thanks for any help on this, 

 

 

PreviosNameDays = 
var _Last =  MAX(Table[Created])
var _MinDate = CALCULATE (
    MIN( Table[Created]),
        ALLEXCEPT(  'Table', 'Table'[Name] ))
var _previousBKT = CALCULATE(MAX('Table'[Name]),Table[Created])
var _currentBKT = CALCULATE(MIN(Table[Name]),Table[created])
return
IF(_previousBKT =_currentBKT && _MinDate <> _Last,VALUE(UTCNOW()-_MinDate),
IF(_previousBKT =_currentBKT && _MinDate = _Last,VALUE(UTCNOW()-_MinDate),DATEDIFF(_MinDate,_Last,DAY)))

 

 

2 ACCEPTED SOLUTIONS

Thanks for clearer explanation, below you can try the new measure for the different of the days compare to previous ID.

Measure =
var forid = SELECTEDVALUE('Table'[ID])
var selectdate = SELECTEDVALUE('Table'[Date])
var previousdate = CALCULATE(MAX('Table'[Date]),FILTER(ALL('Table'),'Table'[ID]=forid-1))
var result = DATEDIFF(previousdate,selectdate,DAY)
return
IF(previousdate=BLANK(),BLANK(),result)

Another measure is the status: 
Status =
var forid = SELECTEDVALUE('Table'[ID])
var forcategory = SELECTEDVALUE('Table'[Category])
var result = CALCULATE(MAX('Table'[Category]),FILTER(ALL('Table'),'Table'[ID]=forid-1))
return
IF(result=BLANK(), BLANK(), IF(forcategory<>result, "Change", "No Change"))
 
Chew_WenJie_1-1662079701109.png

 


 

Hope this can help you.

 



View solution in original post

Hi @rixmcx59 

 

If the problem has been solved you can mark the reply for the standard answer to help the other members find it more quickly. If not, please point it out.


Looking forward to your feedback.


Best Regards,
Henry

View solution in original post

11 REPLIES 11
v-henryk-mstf
Community Support
Community Support

Hi @rixmcx59 ,

 

You can try formula like below:

Col = RANKX('Table','Table'[Date],,DESC,Dense)
M_ =
VAR min_ =
    MIN ( 'Table'[Date] )
VAR max_ =
    CALCULATE ( MAX ( 'Table'[Date] ), 'Table'[Col] = 3 )
RETURN
    DATEDIFF ( min_, max_, DAY )

vhenrykmstf_0-1662022288964.png

If the problem is still not resolved, please provide detailed error information and let me know immediately. Looking forward to your reply.


Best Regards,
Henry


If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.

 

Hello thank you for the reply, the last post in this thread has my sample data and and an explanation of what I am trying to do. I can see where RANKX can be useful but I cuold not get the desired result, I am trying to count the number of days in each category, please see my sample data posted earlier today.

Chew_WenJie
Resolver II
Resolver II

Hi, you may try to use MAXX/MINX instead of MAX/MIN. and if you want to by category, you can add

var category1 = selectedvalue('category')

 

return

CALCULATE(IF(_previousBKT = _currentBKT && _MinDate = _Last,VALUE(UTCNOW()- _MinDate), DATEDIFF(_MinDate,_Last,DAY)), 'category' = 'category1')

 

Hope this can help you 😁

Hello, thanks for the reply. my goal is to return the date before max not min, but I can't use the earlier function in a measure (or can you?), below is my data simplified, in the table I need to compare ID 1 and 4 and get the datediff in days for aName

1aName7/30/22
2aName7/15/22
3aName7/1/22
4aName8/15/22

 thanks for anu help on this

Hello, earlier function are normally used in the calculated column instead of measure. You may refer to the power bi that i had attached below, the measure i done is datediff based on the ID of the name. 

 

Dummy data:

Chew_WenJie_0-1661571769736.png
Sample measure result: 

Chew_WenJie_1-1661571778772.png

Measure:

 

Measure =
var aname = SELECTEDVALUE('Table'[Name])
var findminID = CALCULATE(MIN('Table'[ID]),'Table'[Name]=aname)
var findmaxID = CALCULATE(MAX('Table'[ID]),'Table'[Name]=aname)
var find1stdate = CALCULATE(MAX('Table'[Date]),'Table'[ID]=findminID)
var findlastdate = CALCULATE(MAX('Table'[Date]),'Table'[ID]=findmaxID)

var datedifferent = DATEDIFF(find1stdate,findlastdate,DAY)

return
datedifferent

 

.

Hope this can help you 

 

Hello, thanks for the response. in my data Min(ID) will return the first record in the group, this is not the record I want, I am looking for previous date, as I add new records I am checking for change from the most recent.

 

Thanks

Maybe, you can show me what is the result you wanted from this table, i believe that i will have a better understanding on your requirement.

Chew_WenJie_0-1661992605977.png

 

Thanks, I am testing your measure but not getting the right result. this is a better sample of the actual data. as I add new records I need to compare to the previous date, when I add ID 2, compare to ID 1, when I add ID 3, compare to ID 2. Below sample shows ID 5, I need to compare to ID 4. Using Min and Max return ID 1 and ID 5 which is not what I need to check for name change. Thank for your help

 

 

IDCategoryDateStatusDays
1aName7/27/22  
2aName8/10/22No Change14 days
3aName8/17/22No Change21 Days
4bName8/25/22Change1 Days
5bName9/1/22No Change6 Days

Thanks for clearer explanation, below you can try the new measure for the different of the days compare to previous ID.

Measure =
var forid = SELECTEDVALUE('Table'[ID])
var selectdate = SELECTEDVALUE('Table'[Date])
var previousdate = CALCULATE(MAX('Table'[Date]),FILTER(ALL('Table'),'Table'[ID]=forid-1))
var result = DATEDIFF(previousdate,selectdate,DAY)
return
IF(previousdate=BLANK(),BLANK(),result)

Another measure is the status: 
Status =
var forid = SELECTEDVALUE('Table'[ID])
var forcategory = SELECTEDVALUE('Table'[Category])
var result = CALCULATE(MAX('Table'[Category]),FILTER(ALL('Table'),'Table'[ID]=forid-1))
return
IF(result=BLANK(), BLANK(), IF(forcategory<>result, "Change", "No Change"))
 
Chew_WenJie_1-1662079701109.png

 


 

Hope this can help you.

 



Thank you, I will try this on Tuesday when I return to work and let you know.

 

I really appreciate the help

Hi @rixmcx59 

 

If the problem has been solved you can mark the reply for the standard answer to help the other members find it more quickly. If not, please point it out.


Looking forward to your feedback.


Best Regards,
Henry

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.