Subtract value with pervious record

  • Dear All,

    I need the to subtract the value from the previous record and insert into another table

    Declare @temp Table( [DeviceID] Int,[ctDate] DateTime,[Value] INT )

    Insert Into @temp Values(1,'20131114 00:00:00',10)

    Insert Into @temp Values(1,'20131114 00:10:00',15)

    Insert Into @temp Values(1,'20131114 00:20:00',21)

    Insert Into @temp Values(1,'20131114 00:30:00',28)

    Insert Into @temp Values(1,'20131114 00:40:00',32)

    Insert Into @temp Values(2,'20131114 00:00:00',7)

    Insert Into @temp Values(2,'20131114 00:10:00',16)

    Insert Into @temp Values(2,'20131114 00:20:00',18)

    Insert Into @temp Values(2,'20131114 00:30:00',23)

    Insert Into @temp Values(2,'20131114 00:40:00',33)

    select * from @temp

    ------------------------------------------------------------------------------

    Exactly what I need like this

    DeviceID,ctDate,Value

    1,'20131114 00:00:00',10

    1,'20131114 00:10:00',5

    1,'20131114 00:20:00'6

    1,'20131114 00:30:00',7

    1,'20131114 00:40:00',4

    2,'20131114 00:00:00',7

    2,'20131114 00:10:00',9

    2,'20131114 00:20:00',2

    2,'20131114 00:30:00',5

    2,'20131114 00:40:00',10

    Explanation of requirement:

    Actually device sending the data every 10mins where the value is accumulated with previous 10min and send to database.

    We need to subtract the data with previous slot and insert into new slot

  • SPtiruttani (11/14/2013)


    Dear All,

    I need the to subtract the value from the previous record and insert into another table

    Declare @temp Table( [DeviceID] Int,[ctDate] DateTime,[Value] INT )

    Insert Into @temp Values(1,'20131114 00:00:00',10)

    Insert Into @temp Values(1,'20131114 00:10:00',15)

    Insert Into @temp Values(1,'20131114 00:20:00',21)

    Insert Into @temp Values(1,'20131114 00:30:00',28)

    Insert Into @temp Values(1,'20131114 00:40:00',32)

    Insert Into @temp Values(2,'20131114 00:00:00',7)

    Insert Into @temp Values(2,'20131114 00:10:00',16)

    Insert Into @temp Values(2,'20131114 00:20:00',18)

    Insert Into @temp Values(2,'20131114 00:30:00',23)

    Insert Into @temp Values(2,'20131114 00:40:00',33)

    select * from @temp

    ------------------------------------------------------------------------------

    Exactly what I need like this

    DeviceID,ctDate,Value

    1,'20131114 00:00:00',10

    1,'20131114 00:10:00',5

    1,'20131114 00:20:00'6

    1,'20131114 00:30:00',7

    1,'20131114 00:40:00',4

    2,'20131114 00:00:00',7

    2,'20131114 00:10:00',9

    2,'20131114 00:20:00',2

    2,'20131114 00:30:00',5

    2,'20131114 00:40:00',10

    Explanation of requirement:

    Actually device sending the data every 10mins where the value is accumulated with previous 10min and send to database.

    We need to subtract the data with previous slot and insert into new slot

    Try this:

    with OrderedRows

    as (select ro = row_number() over (order by DeviceId, ctDate)

    ,*

    from @temp

    )

    select CalcValue = o1.Value - isnull(o2.value, 0)

    ,o1.*

    from OrderedRows o1

    left join OrderedRows o2 on o1.ro = (o2.ro + 1)

    and o1.DeviceID = o2.DeviceID

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

  • Hi,

    That's amazing... its working ... thanks a lot...

  • SPtrt (11/18/2013)


    Hi,

    That's amazing... its working ... thanks a lot...

    No problem, thanks for posting back 🙂

    The absence of evidence is not evidence of absence
    - Martin Rees
    The absence of consumable DDL, sample data and desired results is, however, evidence of the absence of my response
    - Phil Parkin

Viewing 4 posts - 1 through 3 (of 3 total)

You must be logged in to reply to this topic. Login to reply