apzl_leasing/src_sql/procedure/proc_contract_rent_month_tradition.sql

107 lines
6.2 KiB
SQL

create procedure proc_contract_rent_month_tradition()
BEGIN
DECLARE p_tax_rate DECIMAL(18,2) DEFAULT 1.06;
DECLARE p_interest DECIMAL(20,16);
DECLARE p_leas_form VARCHAR(32);
DECLARE n_interest DECIMAL(20,16);
DECLARE n_formula VARCHAR(32);
DECLARE l_formula VARCHAR(32);
DECLARE p_contract_id VARCHAR(32);
DECLARE p_payment_number VARCHAR(32);
DECLARE p_all_interest VARCHAR(32);
DECLARE p_handling_charge_money VARCHAR(32);
DECLARE p_remain_corpus VARCHAR(32);
DECLARE p_prev_plan_date VARCHAR(32);
DECLARE p_year_rate VARCHAR(32);
DECLARE p_day_rate VARCHAR(32);
DECLARE p_month_interest DECIMAL(20,16);
DECLARE income_number VARCHAR(32);
DECLARE done BOOLEAN DEFAULT FALSE;
DECLARE contract_info CURSOR FOR
SELECT
lci.leas_form,
lcc.contract_id ,
lcc.payment_number ,
IFNULL(lr.interest,0) ,
lcc.handling_charge_money/getTax(lci.leas_form,'手续费',lcc.start_date) ,
lcc.clean_lease_money ,
lcc.start_date ,
lcc.INCOME_NUMBER,
lrp.interest
FROM lc_calc_condition lcc
LEFT JOIN lb_contract_info lci ON lci.id = lcc.contract_id
left join (select lci.id,sum(round(nvl(lrp.interest,0)/getTax(lci.LEASE_FORM,'租息',lcc.START_DATE),2)) interest from lc_rent_plan lrp inner join lc_calc_condition lcc on lcc.contract_id=lrp.contract_id inner join lb_contract_info lci on lci.id=lrp.contract_id group by lci.id) lr on lr.id=lci.id
left join lc_rent_plan lrp on lrp.contract_id=lci.id and lrp.plan_list='1'
WHERE NOT EXISTS (SELECT 1 FROM contract_rent_month WHERE contract_id = lcc.contract_id) AND nvl(lr.interest,0) > 0 AND lci.contract_status BETWEEN 31 AND 100 AND lci.id NOT IN (SELECT contract_id FROM lc_fund_rent_adjust) and lci.BUSINESSTYPE<>'1' and lcc.INCOME_NUMBER_YEAR='income_1';
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
OPEN contract_info;
clyLoop:LOOP
FETCH contract_info INTO p_leas_form,p_contract_id,p_payment_number, p_all_interest, p_handling_charge_money,p_remain_corpus,p_prev_plan_date,income_number,p_month_interest;
IF done THEN LEAVE clyLoop;
END IF;
BEGIN
DECLARE al_apport_handling_money DECIMAL(22,16) DEFAULT 0.00;
DECLARE al_apport_interest_money DECIMAL(22,16) DEFAULT 0.00;
DECLARE rent_time_limit INT DEFAULT 0;
DECLARE hc_money DECIMAL(22,16) DEFAULT 0.00;
SET p_tax_rate=getTax(p_leas_form,'租息',p_prev_plan_date);
SET rent_time_limit=income_number;
set n_interest=round(p_month_interest/p_tax_rate,2)/30*datediff(last_day(p_prev_plan_date),p_prev_plan_date);
SET n_formula = '';
INSERT INTO contract_rent_month(id,rent_list,interest,fee,accrued_date,start_date,end_date,formula,hand_formula,create_date,contract_id,payment_number)
VALUES(REPLACE(UUID(),'-',''),'0',n_interest,
ROUND(CASE WHEN SIGN(p_handling_charge_money*n_interest-0)=1 THEN p_handling_charge_money*(n_interest/p_all_interest) ELSE 0 END,2),
DATE_FORMAT(p_prev_plan_date,'%Y/%m'),
DATE_ADD(p_prev_plan_date,INTERVAL -DAY(p_prev_plan_date)+1 DAY),
LAST_DAY(p_prev_plan_date),
n_formula,'',
DATE_FORMAT(NOW(),'%Y/%m/%d'),p_contract_id,p_payment_number);
SET al_apport_handling_money=al_apport_handling_money+ROUND(CASE WHEN SIGN(p_handling_charge_money*hc_money-0)=1 THEN p_handling_charge_money*(hc_money/p_all_interest) ELSE 0 END,2);
set al_apport_interest_money=al_apport_interest_money+hc_money;
SET n_formula = '';
BEGIN
DECLARE r_interest1 DECIMAL(20,16);
DECLARE r_plan_date1 VARCHAR(32);
DECLARE r_plan_list1 VARCHAR(32);
DECLARE r_interest2 DECIMAL(20,16);
DECLARE r_plan_date2 VARCHAR(32);
DECLARE r_plan_list2 VARCHAR(32);
DECLARE subdone BOOLEAN DEFAULT FALSE;
DECLARE rent_info CURSOR FOR
SELECT lrp1.interest,lrp1.plan_date,lrp1.plan_list ,lrp2.interest,lrp2.plan_date,lrp2.plan_list
FROM lc_rent_plan lrp1 LEFT JOIN lc_rent_plan lrp2 ON lrp1.contract_id=lrp2.contract_Id AND lrp1.PLAN_LIST+1=lrp2.plan_list WHERE lrp1.contract_id = p_contract_id ORDER BY lrp1.contract_id,lrp1.plan_list;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET subdone = TRUE;
OPEN rent_info;
subLoop:LOOP
FETCH rent_info INTO r_interest1,r_plan_date1,r_plan_list1,r_interest2,r_plan_date2,r_plan_list2;
IF subdone THEN LEAVE subLoop;
END IF;
BEGIN
SET p_interest = round((CASE WHEN r_interest = 0 THEN 0 ELSE r_interest END)/p_tax_rate,2)-n_interest;
SET n_interest = round(CASE WHEN nvl(r_interest2,0) = 0 THEN 0 ELSE r_interest2/p_tax_rate/30*datediff(last_day(r_plan_date1),r_plan_date1) END,2);
SET l_formula = '';
IF r_plan_list=rent_time_limit THEN
SET hc_money=p_handling_charge_money-al_apport_handling_money;
ELSE SET hc_money=ROUND((CASE WHEN SIGN(p_handling_charge_money*ROUND(p_interest+n_interest,2)-0)=1 THEN p_handling_charge_money*(p_interest+n_interest)/p_all_interest ELSE 0 END),2);
END IF;
INSERT INTO contract_rent_month(id,rent_list,interest,fee,accrued_date,start_date,end_date,formula,hand_formula,create_date,contract_id,payment_number)
VALUES(REPLACE(UUID(),'-',''),r_plan_list,ROUND(p_interest+n_interest,2),hc_money,
DATE_FORMAT(r_plan_date,'%Y/%m'),
DATE_ADD(r_plan_date,INTERVAL -DAY(r_plan_date)+1 DAY),
LAST_DAY(r_plan_date),
'','',DATE_FORMAT(NOW(),'%Y/%m/%d'),p_contract_id,p_payment_number);
SET n_formula = l_formula;
SET al_apport_handling_money=al_apport_handling_money+ROUND((CASE WHEN SIGN(p_handling_charge_money*ROUND(p_interest+n_interest,2)-0)=1 THEN p_handling_charge_money*(p_interest+n_interest)/p_all_interest ELSE 0 END),2);
END;
END LOOP;
CLOSE rent_info;
END;
END;
END LOOP;
CLOSE contract_info;
END;