Hi All,
I've got a list of CustomerIDs and datetimes and a 'status' of either 1,2,3,4/5. e.g. I would like to get a date range by getting and EndDateTime.
This is what i have:
CustomerID, DateTime, Status
1, 2020-02-01 03:00:00.000, 1
1, 2020-02-01 04:00:00.000, 2
1, 2020-02-01 06:00:00.000, 3
2, 2020-02-03 07:00:00.000, 2
2, 2020-02-03 09:30:00.000, 3
2, 2020-02-03 10:30:00.000, 2
This is what i want:
CustomerID, DateTime, EndDateTime, Status
1, 2020-02-01 03:00:00.000, 1, 2020-02-01 04:00:00.000,
1, 2020-02-01 04:00:00.000, 2, 2020-02-01 06:00:00.000
1, 2020-02-01 06:00:00.000, 3, NULL
2, 2020-02-03 07:00:00.000, 2, 2020-02-03 09:30:00.000
2, 2020-02-03 09:30:00.000, 3, 2020-02-03 10:30:00.000
2, 2020-02-03 10:30:00.000, 2, NULL
In Sql I would usually use:
LEAD([DateTime]) OVER(PARTITION BY [CustomerID] ORDER BY [DateTime])
I am unable to use sql here though and need to achieve in Power BI Desktop
I want to do this in Power BI, preffarably not in power query editor but accept it may be easier in Power Query or not possible in Power BI Desktop.
Thanks
Solved! Go to Solution.
Hi @AlexoTomo ,
Please try:
EndDateTime = MINX(FILTER('Table',[CustomerID]=EARLIER('Table'[CustomerID]) && [DateTime]>EARLIER('Table'[DateTime])),[DateTime])
If it's not you wanted, please share more detail information to help us clarify your scenario.
Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
Hi @AlexoTomo ,
Please try:
EndDateTime = MINX(FILTER('Table',[CustomerID]=EARLIER('Table'[CustomerID]) && [DateTime]>EARLIER('Table'[DateTime])),[DateTime])
If it's not you wanted, please share more detail information to help us clarify your scenario.
Best Regards,
Eyelyn Qin
If this post helps, then please consider Accept it as the solution to help the other members find it more quickly.
you can do this with PREVIOUS and EARLIER functions in power BI.
Tyr the below solutions.
https://community.powerbi.com/t5/Desktop/Compute-Lead-and-Lag/m-p/425809
https://datacaffee.com/sql-equivalent-power-bi-dax-functions-part-2/
Proud to be a Super User!
Join us for a free, hands-on Microsoft workshop led by women trainers for women where you will learn how to build a Dashboard in a Day!
User | Count |
---|---|
102 | |
79 | |
71 | |
48 | |
47 |
User | Count |
---|---|
157 | |
89 | |
81 | |
69 | |
67 |