Find everything you need to get certified on Fabric—skills challenges, live sessions, exam prep, role guidance, and more. Get started
Hello All ,
My name is Sujit . I hope @amitchandak or other experts can help me in this . Any help is greatly appreciated .
I have a column with Timestamp in them with format yyyy/mm/dd hh:mm . And i have almost 756 rows . There are one index for it which is not integer data type but string type because it does have some alphabet in between .here is an example of my index 1234A980 .
Now following is how my data looks like ,
Datetime | Index |
1/1/2020 12:45 | 2123A4 |
1/2/2020 1:32 | 2123A4 |
1/3/2020 4:00 | 2123A4 |
1/6/2020 5:00 | 2123A4 |
2/20/2020 3:00 | 48320B3249 |
2/21/2020 4:00 | 48320B3249 |
2/22/2020 4:00 | 48320B3249 |
What i want to do is depending on the index , i have to calculate time difference in hours and minutes .
For example for index 21234A has 4 rows . hence for these 4 rows ill calculate the time difference as
first row will show as 0 in a new column as timedifference
second row will show value of 1/2/2020 1:32 - 1/1/2020 12:45
third row will show value of 1/3/2020 4:00 - 1/2/2020 1:32
So every time a index changes for the first time (first date time stamp) time diff must be zero.
The time difference should be in reference with index
Please if any doubt do comment . Any help will be appreciated .
I am trying with following DAX but its not working , its showing largest date based on index
please help
timediff =
Solved! Go to Solution.
@Vera_33 Hello i finally cracked it with your starting help . thanks .
I used MAXX instead of MINX what you used and i also made a column with RANKX and used it in the filter as current RANK > EARLIER (RANK) Thankyou so much. For my other friends out there following is what i used .
Hi @Anonymous
Another way of doing that (Including the HH:MM time format)
timediff =
VAR CurrentTime = 'Main Table'[Timestamp]
VAR CurrentIndexTable =
CALCULATETABLE ( 'Main Table', ALLEXCEPT ( 'Main Table', 'Main Table'[Index] ) )
VAR TimesBefore =
FILTER ( CurrentIndexTable, 'Main Table'[Timestamp] < CurrentTime )
VAR PreviousTime =
MAXX ( TimesBefore, 'Main Table'[Timestamp] )
VAR TimeDiff =
DATEDIFF ( PreviousTime, CurrentTime, MINUTE )
RETURN
IF (
NOT ISBLANK ( PreviousTime ),
QUOTIENT ( TimeDiff, 24 ) & ":"
& MOD ( TimeDiff, 24 )
)
@Vera_33 Hello i finally cracked it with your starting help . thanks .
I used MAXX instead of MINX what you used and i also made a column with RANKX and used it in the filter as current RANK > EARLIER (RANK) Thankyou so much. For my other friends out there following is what i used .
Hi @Anonymous
I assume you are adding a DAX Calculated column, see if it is what you are looking for
timediff =
VAR CurTime = 'Table'[Datetime]
VAR CurIndex = 'Table'[Index]
var NextTime = MINX(FILTER('Table','Table'[index]= CurIndex&&'Table'[Datetime]>CurTime), 'Table'[Datetime])
return
Datediff(CurTime,NextTime,HOUR)
hello @Vera_33 ,
Thankyou for your reply . but it is not working properly for me .
I would love to also explain one more thing ,
Following is output i am looking for ,
Col A Index Timediff
1/1/2020 12:45 | 2123A4 | 0 |
1/2/2020 1:32 | 2123A4 | A2-A1 |
1/3/2020 4:00 | 2123A4 | A3-A2 |
1/6/2020 5:00 | 2123A4 | A4-A3 |
2/20/2020 3:00 | 48320B3249 | 0 |
2/21/2020 4:00 | 48320B3249 | A6-A5 |
2/22/2020 4:00 | 48320B3249 | A7-A6 |
Check out the September 2024 Power BI update to learn about new features.
Learn from experts, get hands-on experience, and win awesome prizes.
User | Count |
---|---|
103 | |
98 | |
98 | |
38 | |
37 |
User | Count |
---|---|
152 | |
120 | |
73 | |
72 | |
63 |