70 lines
3.8 KiB
SQL
70 lines
3.8 KiB
SQL
create procedure proc_contract_rent_month_new()
|
|
BEGIN
|
|
DECLARE p_handl_tax_rate VARCHAR(32);
|
|
DECLARE p_rent_tax_rate VARCHAR(32);
|
|
DECLARE p_contid VARCHAR(32);
|
|
DECLARE p_paymentnum VARCHAR(32);
|
|
DECLARE p_handl_money DECIMAL(20,2);
|
|
DECLARE p_sum_interest DECIMAL(20,2);
|
|
DECLARE rent_time_limit DECIMAL(20);
|
|
DECLARE done BOOLEAN DEFAULT FALSE;
|
|
DECLARE contract_info CURSOR FOR
|
|
SELECT lci.id,lcc.payment_number,IF(lcc.HANDLING_CHARGE_MONEY_TYPE='0020',lcc.HANDLING_CHARGE_MONEY_TYPE,0) AS HANDLING_CHARGE_MONEY,getTax(lci.leas_form,'租息',lcc.start_date) AS zuxintax,getTax(lci.leas_form,'手续费',lcc.start_date) AS handlmoneytax,lr.interest,lcc.income_number FROM lb_contract_info lci LEFT JOIN lc_calc_condition lcc ON lcc.contract_id=lci.id LEFT JOIN (SELECT lrp.contract_id,SUM(ROUND(interest/getTax(lci.leas_form,'租息',lcc.start_date),2)) interest 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 contract_id) lr ON lr.contract_id=lci.id WHERE NOT EXISTS (SELECT 1 FROM contract_rent_month WHERE contract_id = lcc.contract_id) AND lr.interest>0 AND lci.contract_status BETWEEN 31 AND 100 AND lci.id NOT IN (SELECT contract_id FROM lc_fund_rent_adjust);
|
|
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
|
|
|
|
|
OPEN contract_info;
|
|
clyLoop:LOOP
|
|
FETCH contract_info INTO p_contid,p_paymentnum,p_handl_money,p_rent_tax_rate,p_handl_tax_rate,p_sum_interest,rent_time_limit;
|
|
|
|
IF done THEN LEAVE clyLoop;
|
|
END IF;
|
|
BEGIN
|
|
DECLARE al_handling_money DECIMAL(22,2) DEFAULT 0.00;
|
|
DECLARE al_interest_money DECIMAL(22,2) DEFAULT 0.00;
|
|
DECLARE al_sum_handl_money DECIMAL(22,2) DEFAULT 0.00;
|
|
DECLARE n_handlmoney DECIMAL(22,2) DEFAULT 0.00;
|
|
DECLARE n_interest DECIMAL(22,2) DEFAULT 0.00;
|
|
IF p_handl_money>0 THEN
|
|
SET al_handling_money=ROUND(p_handl_money/p_handl_tax_rate,2);
|
|
END IF;
|
|
BEGIN
|
|
DECLARE r_interest DECIMAL(20,2);
|
|
DECLARE r_plan_date VARCHAR(32);
|
|
DECLARE r_plan_list VARCHAR(32);
|
|
DECLARE subdone BOOLEAN DEFAULT FALSE;
|
|
DECLARE rent_info CURSOR FOR
|
|
SELECT ROUND(interest/p_rent_tax_rate,2),plan_date,plan_list FROM lc_rent_plan WHERE contract_id = p_contid ORDER BY contract_id,plan_list;
|
|
DECLARE CONTINUE HANDLER FOR NOT FOUND SET subdone = TRUE;
|
|
OPEN rent_info;
|
|
subLoop:LOOP
|
|
FETCH rent_info INTO r_interest,r_plan_date,r_plan_list;
|
|
|
|
IF subdone THEN LEAVE subLoop;
|
|
END IF;
|
|
BEGIN
|
|
IF r_plan_list=rent_time_limit THEN
|
|
SET n_interest=p_sum_interest-al_interest_money;
|
|
SET n_handlmoney=al_handling_money-al_sum_handl_money;
|
|
ELSE SET n_interest=r_interest;
|
|
SET n_handlmoney=ROUND(al_handling_money*n_interest/p_sum_interest,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,n_interest,n_handlmoney,
|
|
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_contid,p_paymentnum);
|
|
SET al_interest_money = al_interest_money+n_interest;
|
|
SET al_sum_handl_money=al_sum_handl_money+n_handlmoney;
|
|
END;
|
|
END LOOP;
|
|
CLOSE rent_info;
|
|
END;
|
|
END;
|
|
END LOOP;
|
|
CLOSE contract_info;
|
|
END;
|
|
|