apzl_leasing/src_sql/function/bb_getLoanInterest.sql

61 lines
2.9 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

create function bb_getLoanInterest(bill_id_ varchar(32), start_date_ varchar(32), end_date_ varchar(32)) returns decimal(22,2)
begin
declare accrued_interest DECIMAL(22,2) default 0; #
DECLARE real_start_date varchar(32);
DECLARE temp_date varchar(32);
DECLARE plan_date_ varchar(32);
DECLARE year_rate_ DECIMAL(22,6) DEFAULT 0;
DECLARE temp_rate DECIMAL(22,6) DEFAULT 0;
DECLARE gtype int DEFAULT 0;
DECLARE day_flag int DEFAULT 0;
DECLARE rate_year_days_ int DEFAULT 360;#
DECLARE remcorpus DECIMAL(22,2);
DECLARE days int DEFAULT 0;
declare done boolean default false;
DECLARE outer_cursor CURSOR FOR select tab.plan_date,tab.rate,tab.gtype from (
select plan_date,0 as rate,0 as gtype from loan_fund_plan
where bill_id=bill_id_ and plan_date>=start_date_
and plan_date<=end_date_ and ifnull(corpus,0)>0
union
select adjust_date as plan_date,rate_new as rate,1 as gtype from loan_rate_adjust
where bill_id=bill_id_ and status_='rate_adjust' and mod_reason='his_rate_change'
and adjust_date>=start_date_ and adjust_date<=end_date_
union
select end_date_ as plan_date,0 as rate,0 as gtype from dual) tab order by tab.plan_date;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done=TRUE;
set temp_date = start_date_;
#
SELECT GREATEST(start_date_,loan_start_date) INTO real_start_date FROM loan_bill_info WHERE id=bill_id_;
SET temp_date = real_start_date;
SELECT tmp.rate_new INTO temp_rate FROM (SELECT t.rate_new FROM
(SELECT adjust_date,rate_new,create_date FROM loan_rate_adjust WHERE bill_id=bill_id_ AND status_='rate_adjust' AND mod_reason='his_rate_change' AND adjust_date<=real_start_date
UNION
SELECT loan_start_date AS adjust_date,rate AS rate_new, create_date FROM loan_bill_info WHERE id=bill_id_
)t ORDER BY t.adjust_date DESC,t.create_date DESC LIMIT 1) tmp;
#
open outer_cursor;
myLoop:loop
FETCH outer_cursor INTO plan_date_,year_rate_,gtype;
IF done THEN LEAVE myLoop;
END IF;
#
SELECT rate_year_days INTO rate_year_days_ FROM loan_bill_info WHERE id=bill_id_;
#1
SELECT DATEDIFF(plan_date_,temp_date) + day_flag INTO days FROM DUAL;
IF days>=0 THEN
SET day_flag = 0;
SELECT SUM(IFNULL(corpus,0)) INTO remcorpus FROM loan_fund_plan WHERE bill_id=bill_id_ AND plan_date>=plan_date_;
SELECT accrued_interest + (days*remcorpus*(temp_rate/100/rate_year_days_)) INTO accrued_interest FROM DUAL;
IF gtype=1 THEN
SET temp_rate = year_rate_;
END IF;
SET temp_date = plan_date_;
end if;
end loop myLoop;
close outer_cursor;
set accrued_interest = round(accrued_interest,2);
RETURN accrued_interest;
end;