Skip to main content
cancel
Showing results for 
Search instead for 
Did you mean: 

Register now to learn Fabric in free live sessions led by the best Microsoft experts. From Apr 16 to May 9, in English and Spanish.

Reply
ebhend
Regular Visitor

Subtracting a cell from a previous cell in a single column

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:00384634
6/1/2016 23:10384665
6/1/2016 23:20384688
6/1/2016 23:3017
6/1/2016 23:4034
6/1/2016 23:5066

 

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.  

1 ACCEPTED SOLUTION
v-sihou-msft
Employee
Employee

@ebhend

 

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:

  1. Add an index column in Query Editor.
    6661.jpg
  2. Create two columns for both Hour and Minute with formulas below:
    Hour = HOUR('Sensor Data'[Date/Time])
    
    Minute = MINUTE('Sensor Data'[Date/Time])
    
  3. Create a column for PreObjs with below formula below:
    PreObjs = 
    IF (
        'Sensor Data'[Hour] = 23
            && 'Sensor Data'[Minute] = 30,
        0,
        LOOKUPVALUE (
            'Sensor Data'[Totalized Objects],
            'Sensor Data'[Index], 'Sensor Data'[Index] - 1
        )
    )
    
  4. Create a column to get the variance:
    PeriodObjs = 'Sensor Data'[Totalized Objects] - 'Sensor Data'[PreObjs]

6662.png

 

Regards,

 

 

 

View solution in original post

3 REPLIES 3
v-sihou-msft
Employee
Employee

@ebhend

 

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:

  1. Add an index column in Query Editor.
    6661.jpg
  2. Create two columns for both Hour and Minute with formulas below:
    Hour = HOUR('Sensor Data'[Date/Time])
    
    Minute = MINUTE('Sensor Data'[Date/Time])
    
  3. Create a column for PreObjs with below formula below:
    PreObjs = 
    IF (
        'Sensor Data'[Hour] = 23
            && 'Sensor Data'[Minute] = 30,
        0,
        LOOKUPVALUE (
            'Sensor Data'[Totalized Objects],
            'Sensor Data'[Index], 'Sensor Data'[Index] - 1
        )
    )
    
  4. Create a column to get the variance:
    PeriodObjs = 'Sensor Data'[Totalized Objects] - 'Sensor Data'[PreObjs]

6662.png

 

Regards,

 

 

 

Works perfect for with my issue.... Thank you for the hint. 

chrisu
Responsive Resident
Responsive Resident

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.   

Helpful resources

Announcements
Microsoft Fabric Learn Together

Microsoft Fabric Learn Together

Covering the world! 9:00-10:30 AM Sydney, 4:00-5:30 PM CET (Paris/Berlin), 7:00-8:30 PM Mexico City

PBI_APRIL_CAROUSEL1

Power BI Monthly Update - April 2024

Check out the April 2024 Power BI update to learn about new features.

April Fabric Community Update

Fabric Community Update - April 2024

Find out what's new and trending in the Fabric Community.