184 lines
6.1 KiB
SQL
184 lines
6.1 KiB
SQL
create procedure proc_contract_rent_month_temp()
|
|
BEGIN
|
|
/*
|
|
* 利息及手续费分摊计提--月付
|
|
*/
|
|
-- 定义全局变量
|
|
DECLARE sum_interest DECIMAL(22,2); -- 利息总金额
|
|
DECLARE p_contract_id VARCHAR(32); -- 合同id
|
|
DECLARE p_payment_number VARCHAR(32);-- 投放编号
|
|
DECLARE p_handling_charge_money DECIMAL(22,2) DEFAULT 0.00; -- 手续费金额
|
|
DECLARE income_number VARCHAR(32);-- 租金总期次
|
|
DECLARE p_start_date VARCHAR(32); -- 起租时间
|
|
DECLARE p_leas_form VARCHAR(32); -- 租赁类型
|
|
DECLARE p_tax_rate DECIMAL(18,2) DEFAULT 1.06; -- 利息税率
|
|
DECLARE done BOOLEAN DEFAULT FALSE;-- 用于判断循环是否执行
|
|
-- 定义游标
|
|
DECLARE contract_info CURSOR FOR SELECT
|
|
lci.id,
|
|
lcc.PAYMENT_NUMBER,
|
|
lrp.suminterest,
|
|
lcc.HANDLING_CHARGE_MONEY,
|
|
lcc.INCOME_NUMBER,
|
|
lcc.start_date,
|
|
lci.leas_form,
|
|
getTax(lci.leas_form,'租息',lcc.start_date)
|
|
FROM
|
|
lc_calc_condition lcc
|
|
INNER JOIN lb_contract_info lci ON lci.id=lcc.contract_id
|
|
LEFT JOIN
|
|
(SELECT
|
|
lrp.contract_id,
|
|
SUM(lrp.interest) suminterest
|
|
FROM
|
|
lc_rent_plan lrp
|
|
LEFT JOIN
|
|
lb_Contract_info lci ON lci.id=lrp.CONTRACT_ID
|
|
LEFT JOIN
|
|
lc_calc_condition lcc ON lcc.contract_id=lci.id
|
|
GROUP BY
|
|
lrp.contract_id
|
|
) lrp ON lrp.contract_id=lci.id
|
|
WHERE
|
|
NOT EXISTS (SELECT 1 FROM contract_rent_month WHERE contract_id = lcc.contract_id)
|
|
AND
|
|
lci.contract_status ='31'
|
|
and
|
|
lcc.INCOME_NUMBER_YEAR='income_1'
|
|
AND
|
|
lci.id NOT IN (SELECT contract_id FROM lc_fund_rent_adjust);
|
|
-- 游标中的SQL没有数据, 将done设置为true
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
|
-- 开启游标
|
|
OPEN contract_info;
|
|
-- 嵌套循环
|
|
clyLoop:LOOP
|
|
-- 为变量赋值, 值为上边的SQL查询结果
|
|
FETCH contract_info INTO p_contract_id,p_payment_number,sum_interest,p_handling_charge_money,income_number,p_start_date,p_leas_form,p_tax_rate;
|
|
-- 如果done=true, 说明已经没有数据需要循环, 关闭循环
|
|
IF done THEN LEAVE clyLoop; END IF;
|
|
|
|
BEGIN
|
|
-- 定义当前代码块全局变量
|
|
DECLARE r_interest DECIMAL(22,2) DEFAULT 0.00; -- 利息
|
|
DECLARE r_fee DECIMAL(22,2) DEFAULT 0.00; -- 计提手续费
|
|
DECLARE interest_rate DECIMAL(22,6); -- 计提比率
|
|
DECLARE al_interest DECIMAL(22,2) DEFAULT 0.00; -- 当期以前前的利息总额
|
|
DECLARE al_fee DECIMAL(22,2) DEFAULT 0.00; -- 当期以前的手续费金额
|
|
DECLARE r_plan_date VARCHAR(32); -- 计划日期
|
|
DECLARE r_plan_list VARCHAR(32); -- 计划期次
|
|
|
|
DECLARE subdone BOOLEAN DEFAULT FALSE; -- 用于判断当前代码块中的循环是否结束
|
|
-- 创建游标
|
|
DECLARE rent_info CURSOR FOR SELECT
|
|
interest,
|
|
plan_date,
|
|
plan_list
|
|
FROM
|
|
lc_rent_plan
|
|
WHERE
|
|
contract_id = p_contract_id
|
|
ORDER BY contract_id,plan_list;
|
|
-- 如果上边的SQL查询结果为空, subdone改为true
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET subdone = TRUE;
|
|
-- 开启游标
|
|
OPEN rent_info;
|
|
-- 控制循环, 下方LEAVE subLoop表示结束循环
|
|
subLoop:LOOP
|
|
-- 将上边SQL查到的结果集赋值给当前代码块全局变量
|
|
FETCH rent_info INTO r_interest,r_plan_date,r_plan_list;
|
|
-- 如果上边的SQL查到的值为空, 结束循环
|
|
IF subdone THEN LEAVE subLoop; END IF;
|
|
|
|
BEGIN
|
|
-- 如果是最后一期执行此操作
|
|
IF r_plan_list=income_number THEN SET interest_rate=ROUND(r_interest/sum_interest,6);
|
|
SET r_fee=p_handling_charge_money-IFNULL(al_fee,0);
|
|
INSERT INTO contract_rent_month(
|
|
id,
|
|
rent_list,
|
|
interest_tax,
|
|
interest,
|
|
leftinterest,
|
|
fee_tax,
|
|
fee,
|
|
leftfee,
|
|
accrued_date,
|
|
start_date,
|
|
end_date,
|
|
formula,
|
|
hand_formula,
|
|
create_date,
|
|
contract_id,
|
|
payment_number)
|
|
VALUES(
|
|
REPLACE(UUID(),'-',''),
|
|
r_plan_list,
|
|
r_interest,
|
|
ROUND(r_interest/p_tax_rate,2),
|
|
sum_interest-IFNULL(al_interest,0),
|
|
r_fee,
|
|
ROUND(r_fee/p_tax_rate,2),
|
|
p_handling_charge_money-IFNULL(al_fee,0),
|
|
DATE_FORMAT(r_plan_date,'%Y/%m'),
|
|
DATE_ADD(r_plan_date,
|
|
INTERVAL -DAY(r_plan_date)+1 DAY),
|
|
LAST_DAY(r_plan_date),
|
|
interest_rate,
|
|
'',
|
|
DATE_FORMAT(NOW(),'%Y/%m/%d'),
|
|
p_contract_id,
|
|
'');
|
|
SET al_interest=al_interest+r_interest;
|
|
SET al_fee=al_fee+r_fee;
|
|
ELSE
|
|
-- 不是最后一期执行此操作
|
|
SET interest_rate=ROUND(r_interest/sum_interest,6);
|
|
SET r_fee=ROUND(interest_rate*IFNULL(p_handling_charge_money,0),2);
|
|
INSERT INTO contract_rent_month(
|
|
id,
|
|
rent_list,
|
|
interest_tax,
|
|
interest,
|
|
leftinterest,
|
|
fee_tax,
|
|
fee,
|
|
leftfee,
|
|
accrued_date,
|
|
start_date,
|
|
end_date,
|
|
formula,
|
|
hand_formula,
|
|
create_date,
|
|
contract_id,
|
|
payment_number)
|
|
VALUES(
|
|
REPLACE(UUID(),'-',''),
|
|
r_plan_list,
|
|
r_interest,
|
|
ROUND(r_interest/p_tax_rate,2),
|
|
sum_interest-IFNULL(al_interest,0),
|
|
r_fee,
|
|
ROUND(r_fee/p_tax_rate,2),
|
|
p_handling_charge_money-IFNULL(al_fee,0),
|
|
DATE_FORMAT(r_plan_date,'%Y/%m'),
|
|
DATE_ADD(r_plan_date,INTERVAL -DAY(r_plan_date)+1 DAY),
|
|
LAST_DAY(r_plan_date),
|
|
interest_rate,
|
|
'',
|
|
DATE_FORMAT(NOW(),'%Y/%m/%d'),
|
|
p_contract_id,
|
|
'');
|
|
|
|
SET al_interest=al_interest+r_interest;
|
|
SET al_fee=al_fee+r_fee;
|
|
END IF;
|
|
END;
|
|
END LOOP;
|
|
CLOSE rent_info;
|
|
END;
|
|
END LOOP;
|
|
CLOSE contract_info;
|
|
END;
|
|
|