March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early bird discount ends December 31.
Register NowBe one of the first to start using Fabric Databases. View on-demand sessions with database experts and the Microsoft product team to learn just how easy it is to get started. Watch now
Hello everyone!
I am having trouble in creating a specific logic.
The ideia is find the average of the diference of the days between specific rows.
For example:
IDDateCriteria
1 | 18/01/2018 | First |
2 | 25/01/2018 | First |
3 | 21/01/2018 | First |
4 | 01/02/2018 | First |
1 | 03/02/2018 | Second |
2 | 14/03/2018 | Second |
1 | 05/02/2018 | Third |
In this example, I want to know the date difference between criteria but in the same ID.
The formula is = DateDifference ID = Second - First
In excel that would be:
ID 1 = 03/02/2018-18/01/2018 = 16 days
ID 2 = 14/03/2018-25/01/2018 = 48 days
ID 3 = Blank (there is no second criteria)
ID 4 = Blank (there is no second criteria)
So, the average of that is 32.
Just like the table under:
DateDIFF (Second - First) | |
ID 1 | 16,00 |
ID 2 | 48,00 |
ID 3 | Blank |
ID 4 | Blank |
Average | 32,00 |
I want to do the same for (Third-Second), and so on...
How Can I create a Measure of that?
Thanks ikn advance, I am stuck in this problem for a few days now....
PS: I want create that in DAX not in Power Query.
Solved! Go to Solution.
Hi @GertRiet
You may try to create measures as below:
Diff = VAR a = CALCULATE ( MAX ( Table1[Date] ), FILTER ( ALL ( Table1 ), Table1[Date] < MAX ( Table1[Date] ) && Table1[ID] = MAX ( Table1[ID] ) ) ) RETURN DATEDIFF ( a, MAX ( Table1[Date] ), DAY )
Average = AVERAGEX (Table1, [Diff] )
Regards,
Cherie
Hi @GertRiet
You may try to create measures as below:
Diff = VAR a = CALCULATE ( MAX ( Table1[Date] ), FILTER ( ALL ( Table1 ), Table1[Date] < MAX ( Table1[Date] ) && Table1[ID] = MAX ( Table1[ID] ) ) ) RETURN DATEDIFF ( a, MAX ( Table1[Date] ), DAY )
Average = AVERAGEX (Table1, [Diff] )
Regards,
Cherie
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount!
Your insights matter. That’s why we created a quick survey to learn about your experience finding answers to technical questions.
Arun Ulag shares exciting details about the Microsoft Fabric Conference 2025, which will be held in Las Vegas, NV.
User | Count |
---|---|
123 | |
85 | |
85 | |
70 | |
51 |
User | Count |
---|---|
205 | |
153 | |
97 | |
79 | |
69 |