Starting December 3, join live sessions with database experts and the Microsoft product team to learn just how easy it is to get started
Learn moreGet 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
Hello everyone,
I have a question about makingsomethign in Power BI that I can do trivially in Excel, but can't do in Power BI. I have some time series data from sensors that will give a new data point every 10 minutes that I have created a series of graph of. One of these data point is a totalized count fo objects that move past a sensor. this totalized value is reset once a day at 11:30 pm. This data will look like the following:
Date/ time | Totalized Objects |
6/1/2016 23:00 | 384634 |
6/1/2016 23:10 | 384665 |
6/1/2016 23:20 | 384688 |
6/1/2016 23:30 | 17 |
6/1/2016 23:40 | 34 |
6/1/2016 23:50 | 66 |
I am looking at determing the number of objects that passed the sensor over a 10 minute period. In excel I just write a recusive formula subtracting a cell from the previous cell in the same column except for the reset time which is just the totalized number. How would I go about doing this in DAX? I know it has something to do wiht Calculate or Filter functions, but can't them to work exactly as I want. If it helps I also have columns seperating out the date time to be just the date or just the time. Any help would be appreciated.
Solved! Go to Solution.
In this scenario, you can get the Hours and Minutes part of date/time column, then use LOOKUPVALUE() function to get total objects of previous row and calculate the variance. Please refer to following steps:
Hour = HOUR('Sensor Data'[Date/Time]) Minute = MINUTE('Sensor Data'[Date/Time])
PreObjs = IF ( 'Sensor Data'[Hour] = 23 && 'Sensor Data'[Minute] = 30, 0, LOOKUPVALUE ( 'Sensor Data'[Totalized Objects], 'Sensor Data'[Index], 'Sensor Data'[Index] - 1 ) )
PeriodObjs = 'Sensor Data'[Totalized Objects] - 'Sensor Data'[PreObjs]
Regards,
In this scenario, you can get the Hours and Minutes part of date/time column, then use LOOKUPVALUE() function to get total objects of previous row and calculate the variance. Please refer to following steps:
Hour = HOUR('Sensor Data'[Date/Time]) Minute = MINUTE('Sensor Data'[Date/Time])
PreObjs = IF ( 'Sensor Data'[Hour] = 23 && 'Sensor Data'[Minute] = 30, 0, LOOKUPVALUE ( 'Sensor Data'[Totalized Objects], 'Sensor Data'[Index], 'Sensor Data'[Index] - 1 ) )
PeriodObjs = 'Sensor Data'[Totalized Objects] - 'Sensor Data'[PreObjs]
Regards,
Works perfect for with my issue.... Thank you for the hint.
PowerPivotPro's post on this issue would probably be helpful. There is an example in the post that uses an index column with the LOOKUPVALUE to get what you want, and there are several examples in the comments using EARLIER.
For LOOKUPVALUE, you would add an index column and use the index of the current objects to look up objects for index-1. For the 11:30 reset, you can add an IF to test whether the time is 11:30 and return 0 if true, the difference in objects if false.
Starting December 3, join live sessions with database experts and the Fabric product team to learn just how easy it is to get started.
March 31 - April 2, 2025, in Las Vegas, Nevada. Use code MSCUST for a $150 discount! Early Bird pricing ends December 9th.
User | Count |
---|---|
92 | |
86 | |
85 | |
67 | |
49 |
User | Count |
---|---|
140 | |
113 | |
104 | |
64 | |
60 |