create procedure proc_contract_discount_month_temp() BEGIN /* * */ -- 定义全局变量 DECLARE p_contract_id VARCHAR(32); -- 合同id DECLARE p_discount DECIMAL(22,2) ; -- 贴息金额 DECLARE tax_rate DECIMAL(22,2) ; -- 租息税率, 当前1.06(回租) DECLARE p_recive_date VARCHAR(32); -- 贴息导入日期 DECLARE p_lease_term VARCHAR(32); -- 最大期次 DECLARE v_discount DECIMAL(22,2) DEFAULT 0.00; -- 未计提贴息金额 DECLARE done BOOLEAN DEFAULT FALSE; -- 用于判断最外层循环是否结束 -- 开启游标 DECLARE contract_info CURSOR FOR SELECT lci.id, MAX(ld.discount_money), MAX(ld.discount_money), getTax(MIN(lci.leas_form),'租息',MIN(lcc.start_date)), DATE_FORMAT(MAX(ld.INPUTTIME),'%Y/%m/%d'), MAX(lcc.LEASE_TERM) FROM LB_DISCOUNT ld INNER JOIN lb_contract_info lci ON lci.contract_no=ld.contract_no INNER JOIN lc_calc_condition lcc ON lcc.contract_id=lci.id INNER JOIN contract_rent_month crm ON crm.contract_id=lci.id WHERE crm.discount IS NULL GROUP BY lci.id; -- 如果上边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_discount,v_discount,tax_rate,p_recive_date,p_lease_term; -- 如果done=true, 结束循环 IF done THEN LEAVE clyLoop; END IF; BEGIN -- 定义当前代码块全局变量 DECLARE al_discount DECIMAL(22,2) DEFAULT 0.00; -- 已计提贴息金额 DECLARE r_discount DECIMAL(22,2) DEFAULT 0.00; -- 当期贴息金额 DECLARE r_list VARCHAR(10); -- DECLARE r_date VARCHAR(10); -- DECLARE bilv DECIMAL(22,6) DEFAULT 0.00; -- DECLARE subdone BOOLEAN DEFAULT FALSE; -- 用于判断下方循环是否结束 -- 定义游标 DECLARE rent_info CURSOR FOR SELECT crm.formula, crm.rent_list, lrp.plan_date FROM contract_rent_month crm LEFT JOIN lc_rent_plan lrp ON lrp.contract_id=crm.contract_id AND lrp.plan_list=crm.rent_list WHERE crm.contract_id =p_contract_id ORDER BY crm.contract_id,rent_list; -- 判断上边SQL是否还有数据, 没有则变更subdone为true DECLARE CONTINUE HANDLER FOR NOT FOUND SET subdone = TRUE; -- 开启游标 OPEN rent_info; -- 控制循环 subLoop:LOOP -- 给全局变量赋值 FETCH rent_info INTO bilv,r_list,r_date; -- 如果没数据了, 关闭循环 IF subdone THEN LEAVE subLoop; END IF; BEGIN -- 如果最后一期, 贴息金额等于总金额-已分摊的所有金额 IF r_list=p_lease_term THEN UPDATE contract_rent_month SET discout_tax=p_discount-al_discount,discount=ROUND((p_discount-al_discount)/tax_rate,2),leftdiscount=0 WHERE contract_id=p_contract_id AND rent_list=r_list; SET v_discount=v_discount-r_discount; -- 导入之前的分摊金额都为0 ELSE IF DATE_FORMAT(r_date,'%Y%m%d')-DATE_FORMAT(p_recive_date,'%Y%m%d')<0 THEN UPDATE contract_rent_month SET discout_tax=0,discount=0,leftdiscount=p_discount WHERE contract_id=p_contract_id AND rent_list=r_list; SET r_discount=r_discount+ROUND(bilv*IFNULL(p_discount,0),2); ELSE -- 其他的每一期都按照一定的逻辑算 SET r_discount=r_discount+ROUND(bilv*IFNULL(p_discount,0),2); UPDATE contract_rent_month SET discout_tax=r_discount,discount=ROUND(r_discount/tax_rate,2),leftdiscount=v_discount-r_discount WHERE contract_id=p_contract_id AND rent_list=r_list; SET v_discount=v_discount-r_discount; SET al_discount=al_discount+r_discount; SET r_discount=0; END IF; END IF; END; END LOOP; CLOSE rent_info; END; END LOOP; CLOSE contract_info; END;