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

Get certified in Microsoft Fabric—for free! For a limited time, get a free DP-600 exam voucher to use by the end of 2024. Register now

Reply
DBrito79
Frequent Visitor

DAX formula to turn, in each line, the anterior date for the same ID&Service.

Hello Everyone!

 

Can you help me with a formula that i will try to explain:

 

I have a single table in PBI wich each row is an ID (sow&cycle) and a n.º of service(1, 2, 3...) and date (mating date). One ID (sow&cycle) can have or not more than 1 service. One service (p.e. 1) can end with a repetition (so it gets after another row with the service 2...) or can end in a farrowing ( There is not more services after with this ID (sow&cycle)).  There are more results of the data mating but its not necessary for the question.

I need to calculare de diference between (in days):

service 1 and 2 if i have a repetition (not a farrowing) in service 1
service 2 and 3 if i have a repetition (not a farrowing) in service 2

service 3 and 4 if i have a repetition (not a farrowing) in service 3

 

So it would be easier for me if i have the dates of the next service in the same row (if that row is a repetition) and make the diference in days after.

 

I tried a lot of formulas, the one that is more likely and have better results is:

 

Column

Repeat Date 1try = IF(
    PCH[Mating Result]="Repetition" && PCH[Service]=1,
    CALCULATE
    ([Dia 2] , ALLEXCEPT(PCH, PCH[Sow&Cycle] )),

    IF(
    PCH[Mating Result]="Repetition" && PCH[Service]=2,
    CALCULATE
    ([Dia 3] , ALLEXCEPT(PCH, PCH[Sow&Cycle] )),

    IF(
    PCH[Mating Result]="Repetition" && PCH[Service]=3,
    CALCULATE
    ([Dia 4] , ALLEXCEPT(PCH, PCH[Sow&Cycle] ))
 
    )))

 

Whrere the measures "dia 2", "dia 3" and "dia 4" are:

 

Measures:

Dia 1 = MIN(PCH[MatingDate])
 
Dia 2 =
CALCULATE(
    MINX(
    TOPN(2, 'PCH', PCH[MatingDate], DESC),
    PCH[MatingDate]), ALLEXCEPT(PCH, PCH[Sow&Cycle])
)
 
Dia 3 = VAR MinValue = [Dia 2]
RETURN
    CALCULATE(
        MIN(PCH[MatingDate]),
        FILTER(ALLSELECTED(PCH), PCH[MatingDate] > MinValue),
        ALLEXCEPT(PCH, PCH[Sow&Cycle])
    )

 

Dia 4 = VAR MinValue = [Dia 3]
RETURN
    CALCULATE(
        MIN(PCH[MatingDate]),
        FILTER(ALLSELECTED(PCH), PCH[MatingDate] > MinValue),
        ALLEXCEPT(PCH, PCH[Sow&Cycle])
    )
 
But i can only get good values until day 3, after that it appear or in blank or the first date (Service=1)
I can't make a rank of dates in each primary ID (sow&cycle). If i can it will be easier. 
 
Sow&CycleCycleServiceMatingDateMating ResultRepeat Date 1tryIRR1  
SOW10-11106/03/2022Repetition13/03/20227  
SOW10-11213/03/2022Repetition14/03/20221  
SOW10-21314/03/2022Repetitionshould be 30/03/202216  
SOW10-11430/03/2022Farrowed    
SOW10-22124/06/2022Repetition26/07/202232  
SOW10-22226/07/2022Repetition05/08/202210  
SOW10-32305/08/2022Farrowed    
         
 
Can you help me? i think the error is in the ranking ASC of dates for each Sow&Cycle
Thanks a million! 
Regards
 
 
 
1 ACCEPTED SOLUTION

Hi @DBrito79 ,

 

If you want to fetch the previous row, please try this measure.

Repeat Date = VAR _PREVIOUSDATE=CALCULATE(MAX('Table'[MatingDate]),FILTER(ALLSELECTED('Table'),[Sow&Cycle]=MAX('Table'[Sow&Cycle])&&[Service]=MAX('Table'[Service])+1))
RETURN IF(MAX('Table'[Mating Result])="Farrowed",BLANK(),_PREVIOUSDATE)

vstephenmsft_0-1688697564025.png

Make sure to tick ‘Show items with no data’.

vstephenmsft_1-1688697585400.png

 

                                                                                                                                                         

Best Regards,

Stephen 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

3 REPLIES 3
DBrito79
Frequent Visitor

Sorry but the table have one error.
Here is the writ one

Thanks

Sow&CycleCycleServiceMatingDateMating ResultRepeat Date 1tryIRR1  
SOW10-11106/03/2022Repetition13/03/20227  
SOW10-11213/03/2022Repetition14/03/20221  
SOW10-11314/03/2022Repetitionshould be 30/03/202216  
SOW10-11430/03/2022Farrowed    
SOW10-22124/06/2022Repetition26/07/202232  
SOW10-22226/07/2022Repetition05/08/202210  
SOW10-22305/08/2022Farrowed    
         

Hi @DBrito79 ,

 

If you want to fetch the previous row, please try this measure.

Repeat Date = VAR _PREVIOUSDATE=CALCULATE(MAX('Table'[MatingDate]),FILTER(ALLSELECTED('Table'),[Sow&Cycle]=MAX('Table'[Sow&Cycle])&&[Service]=MAX('Table'[Service])+1))
RETURN IF(MAX('Table'[Mating Result])="Farrowed",BLANK(),_PREVIOUSDATE)

vstephenmsft_0-1688697564025.png

Make sure to tick ‘Show items with no data’.

vstephenmsft_1-1688697585400.png

 

                                                                                                                                                         

Best Regards,

Stephen Tao

 

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

Hello Stephen Tao

Thank you very much 
It works exacly!
Thanks again, you saved me a lot of time in getting this done
Best Regards
Diogo

 

DBrito79_0-1688715645547.png

 

Helpful resources

Announcements
November Carousel

Fabric Community Update - November 2024

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

Live Sessions with Fabric DB

Be one of the first to start using Fabric Databases

Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.

Las Vegas 2025

Join us at the Microsoft Fabric Community Conference

March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.

Nov PBI Update Carousel

Power BI Monthly Update - November 2024

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

Top Solution Authors