Calculate amount on every row in a orderlogg

I have a trigger that logs the customer order changes in a table. I shall, for each row in the log table to figure out how much the value has changed. I have three columns to be used, quantity, price and discount.

In the table, the three columns like this:

old_price, new_price, old_qty, new_qty, old_discount, new_discount.

Everything works except that I do not get into how I can calculate the amount of change per row. Each entry in the table is logged in the field operation if there is a change, removal, or new row. 1 = New row, 2 = Change 3 = Removal.

I do like this below now, it works if you just make one change. If you make two changes or more on the same row, for example, the number and price, it does not work. Even if there are no changes at all on these three fields it dont work. What I have done is wrong, so the question is how I will do it right?

     (new_qty - old_qty) as cc_qty,
        (new_price - old_price) as cc_price,
        (new_discount - old_discount) as cc_discount,

          (case when cc_qty = 0 Then old_qty else cc_qty end *  
           case when cc_price = 0 Then old_price else cc_price end *
            ucase when cc_discount = 0 Then (1-old_discount/100) else ( case when ol_operation = 1 then (1-cc_discount/100) else (- cc_discount /100) end ) end  ) as cc_amount,

Please provide sample data and expected output from your sample data

Here are sample data. Column cc_amount is the value I want to calculate.

ordernr----old_price----new_price----old_qty----new_qty----old_discount----new_discount----operation----cc_amount
-1025---------0------------1,3----------0----------30------------0---------------0---------------1-------_39_----- new row
-1025---------1,3----------1,3---------30----------45------------0---------------1,5-------------2-------_18,62--- update row
-1025---------1,3----------1,1---------45----------60------------1,5--------------1--------------2-------_7,72_--- update row
-1025---------1,1----------1,1---------60----------40------------1----------------0--------------2------_-21,34_-- update row
-1025---------1,1----------0-----------40----------0- -----------0----------------0--------------3------_-44_----- delete row

Something like:

with order_log(ordernr,old_price,new_price,old_qty,new_qty,old_discount,new_discount,operation,cc_amount)
  as (          select 1025,0,1.3,0,30,0,0,1,39
      union all select 1025,1.3,1.3,30,45,0,1.5,2,18.62
      union all select 1025,1.3,1.1,45,60,1.5,1.0,2,7.72
      union all select 1025,1.1,1.1,60,40,1,0,2,-21.34
      union all select 1025,1.1,0,40,0,0,0,3,-44.00
     )
select new_qty
      ,new_price
      ,new_discount
      ,cast(new_qty*new_price*(1-new_discount/100) as decimal(18,2)) as new_amount
      ,old_qty
      ,old_price
      ,old_discount
      ,cast(old_qty*old_price*(1-old_discount/100) as decimal(18,2)) as old_amount
      ,cast(new_qty*new_price*(1-new_discount/100)
           -old_qty*old_price*(1-old_discount/100)
            as decimal(18,2)
           ) as diff_amount
  from order_log