The ultimate Microsoft Fabric, Power BI, Azure AI, and SQL learning event: Join us in Stockholm, September 24-27, 2024.
Save €200 with code MSCUST on top of early bird pricing!
Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
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
Whrere the measures "dia 2", "dia 3" and "dia 4" are:
Measures:
Sow&Cycle | Cycle | Service | MatingDate | Mating Result | Repeat Date 1try | IRR1 | ||
SOW10-1 | 1 | 1 | 06/03/2022 | Repetition | 13/03/2022 | 7 | ||
SOW10-1 | 1 | 2 | 13/03/2022 | Repetition | 14/03/2022 | 1 | ||
SOW10-2 | 1 | 3 | 14/03/2022 | Repetition | should be 30/03/2022 | 16 | ||
SOW10-1 | 1 | 4 | 30/03/2022 | Farrowed | ||||
SOW10-2 | 2 | 1 | 24/06/2022 | Repetition | 26/07/2022 | 32 | ||
SOW10-2 | 2 | 2 | 26/07/2022 | Repetition | 05/08/2022 | 10 | ||
SOW10-3 | 2 | 3 | 05/08/2022 | Farrowed | ||||
Solved! Go to 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)
Make sure to tick ‘Show items with no data’.
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.
Sorry but the table have one error.
Here is the writ one
Thanks
Sow&Cycle | Cycle | Service | MatingDate | Mating Result | Repeat Date 1try | IRR1 | ||
SOW10-1 | 1 | 1 | 06/03/2022 | Repetition | 13/03/2022 | 7 | ||
SOW10-1 | 1 | 2 | 13/03/2022 | Repetition | 14/03/2022 | 1 | ||
SOW10-1 | 1 | 3 | 14/03/2022 | Repetition | should be 30/03/2022 | 16 | ||
SOW10-1 | 1 | 4 | 30/03/2022 | Farrowed | ||||
SOW10-2 | 2 | 1 | 24/06/2022 | Repetition | 26/07/2022 | 32 | ||
SOW10-2 | 2 | 2 | 26/07/2022 | Repetition | 05/08/2022 | 10 | ||
SOW10-2 | 2 | 3 | 05/08/2022 | Farrowed | ||||
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)
Make sure to tick ‘Show items with no data’.
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
Join the community in Stockholm for expert Microsoft Fabric learning including a very exciting keynote from Arun Ulag, Corporate Vice President, Azure Data.
Check out the August 2024 Power BI update to learn about new features.
User | Count |
---|---|
21 | |
20 | |
17 | |
15 | |
13 |
User | Count |
---|---|
42 | |
36 | |
23 | |
22 | |
17 |