Hi @Analyst_SQL ,
Please refer below:
;WITH cte
as(
SELECT NULL Trans_ID,NULL Trans_Type,NULL TransDate,'Opening' Trans_Remarks,NULL Code,NULL Head,null Debit,null Credit,isnull(opening,0) Balance
from #tbl_COA
where Level_Four_ID=1222
UNION ALL
SELECT T.Trans_ID,ty.trans_type_name as Trans_Type,Convert(varchar, T.Trans_Date ,101)as TransDate,
(CONCAT(COA.Level_Four_Name ,' ','Online Receipt C/O',' ',COAc.Level_Four_Name,' ', 'Rs. ',T.Trans_Amount)) as Trans_Remarks,
T.Level_Four_ID_C as Code ,COAc.Level_Four_Name as Head, T.Trans_Amount as Debit, CAST(0 AS decimal(18,2)) as Credit,T.Trans_Amount- CAST(0 AS decimal(18,2)) Balance
FROM #tbl_transection T
inner join #tbl_COA COA on COA.Level_Four_ID=T.Level_Four_ID_D
inner join #tbl_COA COAc on COAc.Level_Four_ID=T.Level_Four_ID_C
inner join #tbl_trans_type ty on ty.trans_type_ID=T.Trans_Type_ID
where COA.Level_Four_ID=1222
UNION ALL
SELECT T.Trans_ID,ty.trans_type_name as Trans_Type, Convert(varchar, T.Trans_Date ,101)as TransDate,
(CONCAT(COA.Level_Four_Name ,'Online Receipt C/O',' ',COA.Level_Four_Name, '',T.Trans_Amount)) as Trans_Remarks,
T.Level_Four_ID_D as Code,COA.Level_Four_Name as Head, CAST(0 AS decimal(18,2)) as Debit, Trans_Amount as Credit,CAST(0 AS decimal(18,2))-Trans_Amount Balance
FROM #tbl_transection T
inner join #tbl_COA COA on COA.Level_Four_ID=T.Level_Four_ID_D
inner join #tbl_trans_type ty on ty.trans_type_ID=T.Trans_Type_ID
where T.Level_Four_ID_c=1222
),cte1 as (
SELECT Trans_ID,Trans_Type,TransDate,Trans_Remarks, Code,Head,Debit,Credit,sum(Balance) over (order by (select null) ROWS UNBOUNDED PRECEDING) Balance
FROM cte)
select * from cte1
UNION ALL
SELECT NULL ,NULL ,NULL , null,null, 'Total',sum(Debit),sum(Credit),null
from cte1
Output:
Best regards
Melissa
If the answer is helpful, please click "Accept Answer" and upvote it.
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.