LAG & LEAD depending on other column

Enric 81 Reputation points
2022-04-13T15:44:31.663+00:00

Hi there,

DECLARE @tMovements AS TABLE(id2 INT, typeop CHAR(1), amount DECIMAL(18,2), createdate DATE)

INSERT INTO @tMovements(id2,typeop,amount,createdate)
select 1, 'D',2500,'2022-01-01'
UNION
SELECT 2,'D',3456.25,'2022-01-01'
UNION
SELECT 3,'C',-5250,'2022-01-01'
UNION
SELECT 4, 'C',-3000,'2022-01-05'
UNION
SELECT 5,'D',10000,'2022-01-06'
UNION
SELECT 6,'C',-1500,'2022-01-31'

select * from @tMovements

I'd need to get the good ledger according to whether credit or debit and get the good ledger

desired outcome

id2 amount createddate
2 5956.25 2022-01-01
3 706.25 2022-01-01
4 -2293.75 2022-01-05
5 7706.25 2022-01-06
6 6206.25 2022-01-31

Thanks a lot,

SQL Server
SQL Server
A family of Microsoft relational database management and analysis systems for e-commerce, line-of-business, and data warehousing solutions.
12,755 questions
Transact-SQL
Transact-SQL
A Microsoft extension to the ANSI SQL language that includes procedural programming, local variables, and various support functions.
4,554 questions
0 comments No comments
{count} votes

Accepted answer
  1. Yitzhak Khabinsky 25,026 Reputation points
    2022-04-13T16:09:12.343+00:00

    Hi @Enric ,

    Please try the following solution.

    SQL

    -- DDL and sample data population, start  
    DECLARE @tMovements AS TABLE(id2 INT, typeop CHAR(1), amount DECIMAL(18,2), createdate DATE);  
    INSERT INTO @tMovements(id2,typeop,amount,createdate) VALUES  
    (1, 'D',2500,'2022-01-01'),  
    (2,'D',3456.25,'2022-01-01'),  
    (3,'C',-5250,'2022-01-01'),  
    (4, 'C',-3000,'2022-01-05'),  
    (5,'D',10000,'2022-01-06'),  
    (6,'C',-1500,'2022-01-31');  
    -- DDL and sample data population, end  
      
    SELECT *   
    	, result = SUM(amount) OVER (ORDER BY id2)  
    FROM @tMovements;  
    

    Output

    +-----+--------+----------+------------+----------+  
    | id2 | typeop |  amount  | createdate |  result  |  
    +-----+--------+----------+------------+----------+  
    |   1 | D      |  2500.00 | 2022-01-01 |  2500.00 |  
    |   2 | D      |  3456.25 | 2022-01-01 |  5956.25 |  
    |   3 | C      | -5250.00 | 2022-01-01 |   706.25 |  
    |   4 | C      | -3000.00 | 2022-01-05 | -2293.75 |  
    |   5 | D      | 10000.00 | 2022-01-06 |  7706.25 |  
    |   6 | C      | -1500.00 | 2022-01-31 |  6206.25 |  
    +-----+--------+----------+------------+----------+  
    
    0 comments No comments

2 additional answers

Sort by: Most helpful
  1. Viorel 112.5K Reputation points
    2022-04-13T16:07:46.28+00:00

    Check if this query gives the desired outcome:

    select id2, sum(amount) over (order by id2) as amount, createdate
    from @tMovements
    order by id2
    offset 1 row
    
    0 comments No comments

  2. LiHong-MSFT 10,046 Reputation points
    2022-04-14T02:01:36.123+00:00

    Hi @Enric
    You don't need to use LEAD or LAG functions, please check this query:

    ;WITH CTE AS  
    (  
     SELECT MAX(id2)AS ID,typeop,SUM(amount)AS Amount,createdate  
     FROM @tMovements  
     GROUP BY createdate,typeop  
    )  
    SELECT ID,SUM(Amount)OVER(ORDER BY ID)AS Amount,createdate  
    FROM CTE  
    ORDER BY ID  
    

    Best regards,
    LiHong


    If the answer is the right solution, please click "Accept Answer" and kindly upvote it. If you have extra questions about this answer, please click "Comment".
    Note: Please follow the steps in our Documentation to enable e-mail notifications if you want to receive the related email notification for this thread.

    0 comments No comments