apzl_leasing/src_sql/procedure/proc_card_income.sql

206 lines
11 KiB
SQL

create procedure proc_card_income(IN l_deduct_docid varchar(32), IN userid varchar(32), IN orgid varchar(32))
begin
declare use_money decimal(22,10) default 0;
declare l_mayope_money decimal(22,10);
declare l_contract_number varchar(32);
declare r_payment_number varchar(32);
declare l_card_data_id varchar(32);
declare l_own_bank varchar(100) default '';
declare l_own_account varchar(100) default '';
declare l_own_number varchar(100) default '';
declare l_client_acc_number varchar(100);
declare l_client_account varchar(100);
declare l_client_bank varchar(100);
declare l_deduct_info_id varchar(32);
declare l_import_date varchar(32);
declare l_export_date varchar(32);
declare done boolean default false;
DECLARE sql_error INT DEFAULT 0;
declare card_data cursor for
select id,mayope_money,client_acc_number,client_account,client_bank,contract_number,payment_number from lc_card_deduct_data where deduct_docid = l_deduct_docid and mayope_money > 0;
declare continue handler for not found set done = true;
open card_data;
myLoop:loop
fetch card_data into l_card_data_id,l_mayope_money,l_client_acc_number,l_client_account,l_client_bank, l_contract_number,r_payment_number;
if done then leave myLoop;
end if;
begin
declare l_payment_number varchar(32);
declare l_plan_list varchar(32);
declare l_rent decimal;
declare l_corpus decimal;
declare l_interest decimal;
declare l_penalty decimal;
declare l_hire_list decimal;
declare subdone boolean default false;
declare rent_plan cursor for
select vlrp.payment_number,vlrp.plan_list,vlrp.rent_over,vlrp.corpus_over,vlrp.interest_over,
vlrp.penalty_over,ifnull(lri.ihire_list, 0) + ifnull(lrit.thire_list, 0) hire_list from vi_lc_rent_plan vlrp left join (select payment_number,plan_list,
count(1) ihire_list from lc_rent_income where roll_back = '0' group by payment_number,plan_list) lri on lri.payment_number = vlrp.payment_number and lri.plan_list = vlrp.plan_list left join
(select payment_number, plan_list,count(1) thire_list from lc_rent_income_temp where roll_back = '0' and is_flowing = '0' group by payment_number,plan_list) lrit on lrit.payment_number = vlrp.payment_number and lrit.plan_list = vlrp.plan_list where vlrp.contract_number = l_contract_number order by plan_list;
declare continue handler for not found set subdone = true;
open rent_plan;
subLoop:loop
fetch rent_plan into l_payment_number,l_plan_list,l_rent,l_corpus,l_interest,l_penalty,l_hire_list;
if subdone then leave subLoop;
end if;
if l_mayope_money > 0 and l_rent + l_penalty > 0 then
insert into lc_rent_income(id,
quot_id,
cust_id,
project_id,
project_plan_number,
contract_id,
contract_plan_number,
payment_number,
plan_id,
plan_list,
hire_list,
hire_date,
rent,
corpus,
interest,
penalty,
corpus_adjust,
interest_adjust,
penalty_adjust,
settle_method,
carddeduct_id,
carddeduct_status,
hire_object,
hire_bank,
hire_account,
hire_number,
own_bank,
own_account,
own_number,
roll_back,
inputuserid,
inputorgid,
inputtime)
select replace(UUID(), '-', ''),
lrp.quot_id,
lrp.cust_id,
lrp.project_id,
lrp.project_plan_number,
lrp.contract_id,
lrp.contract_plan_number,
lrp.payment_number,
lrp.id,
lrp.plan_list,
l_hire_list +1,
date_format(now(), '%Y/%m/%d %H:%i:%s'),
round(case when lio.first='PENALTY' then
case when l_mayope_money - l_penalty >= l_rent then l_rent else
case when l_mayope_money > l_penalty
then l_mayope_money - l_penalty else 0 end end
else
case when l_mayope_money >= l_rent then l_rent else l_mayope_money end
end,2),
round(case when lio.first='CORPUS' then
case when l_mayope_money >= l_corpus
then l_corpus else l_mayope_money end
when lio.second='CORPUS' and lio.first='INTEREST' then
case when l_mayope_money > l_interest then
case when l_mayope_money - l_interest >=
l_corpus then l_corpus else l_mayope_money - l_interest end
else 0 end
when lio.second='CORPUS' and lio.first='PENALTY' then
case when l_mayope_money > l_penalty then
case when l_mayope_money - l_penalty >=
l_corpus then l_corpus else l_mayope_money - l_penalty end
else 0 end
else
case when l_mayope_money > l_interest +
l_penalty then
case when l_mayope_money - l_interest -
l_penalty >= l_corpus
then l_corpus else l_mayope_money -
l_interest - l_penalty end
else 0 end
end,2),
round(case when lio.first='INTEREST' then
case when l_mayope_money >= l_interest
then l_interest else l_mayope_money end
when lio.second='INTEREST' and lio.first='CORPUS' then
case when l_mayope_money>l_corpus then
case when l_mayope_money-l_corpus >=
l_interest then l_interest else l_mayope_money-l_corpus end
else 0 end
when lio.second='INTEREST' and lio.first='PENALTY' then
case when l_mayope_money > l_penalty then
case when l_mayope_money - l_penalty >=
l_interest then l_interest else l_mayope_money - l_penalty end
else 0 end
else
case when l_mayope_money>l_corpus + l_penalty then
case when l_mayope_money-l_corpus - l_penalty >= l_interest then l_interest else l_mayope_money - l_corpus -
l_penalty end
else 0 end
end,2),
round(case when lio.first='PENALTY' then
case when l_mayope_money >= l_penalty
then l_penalty else l_mayope_money end
when lio.second='PENALTY' and lio.first='CORPUS' then
case when l_mayope_money > l_corpus then
case when l_mayope_money - l_corpus >=
l_penalty then l_penalty else l_mayope_money - l_corpus end
else 0 end
when lio.second='PENALTY' and lio.first='INTEREST' then
case when l_mayope_money > l_interest then
case when l_mayope_money - l_interest >=
l_penalty then l_penalty else l_mayope_money - l_interest end
else 0 end
else
case when l_mayope_money > l_corpus +
l_interest then
case when l_mayope_money - l_corpus -
l_interest >= l_penalty
then l_penalty else l_mayope_money - l_corpus - l_interest end
else 0 end
end,2),
0,0,0,
'settlemethod13',
l_card_data_id,
'have_income',
lul.customer_id,
l_client_bank,
l_client_account,
l_client_acc_number,
l_own_bank,
l_own_account,
l_own_number,
'0',
userid,
orgid,
date_format(now(),'%Y/%m/%d %H:%i:%s')
from lc_rent_plan lrp left join lc_calc_condition lcc on lcc.payment_number = l_payment_number
left join lc_income_order lio on 1 = 1 and
lio.repayment_type=(case when curdate()-
str_to_date(lrp.plan_date,'%Y/%m/%d')>cast(lcc.free_defa_inter_day as
decimal(5,0)) then 'over_income' else 'normal_income' end)
left join lb_union_lessee lul on lul.contract_id = lcc.contract_id
and is_main='Y' where lrp.payment_number = l_payment_number
and lrp.plan_list = l_plan_list;
-- 更新卡扣数据
update lc_card_deduct_data set had_money = had_money + (case when l_mayope_money >= l_rent + l_penalty then l_rent + l_penalty else l_mayope_money end),
mayope_money = mayope_money - (case when l_mayope_money >= l_rent + l_penalty
then l_rent + l_penalty else l_mayope_money end)
where id = l_card_data_id;
-- 更新已核销金额
set use_money = use_money + (case when l_mayope_money >= l_rent + l_penalty then l_rent + l_penalty else l_mayope_money end);
-- 更新可核销金额
set l_mayope_money = l_mayope_money - (case when l_mayope_money >= l_rent +
l_penalty then l_rent + l_penalty else l_mayope_money end);
elseif l_mayope_money = 0 then
leave subLoop;
end if;
end loop subLoop;
end;
delete from lc_occupy_rent_list where payment_number = r_payment_number and flow_name = '卡扣核销';
end loop myLoop;
update lc_card_deduct_doc set allhad_money = allhad_money + use_money,allmayope_money = allmayope_money - use_money,status = (case when allhad_money - use_money <= 0 then 'have_income' else case when use_money = 0 then status else 'part_icome' end end) where id = l_deduct_docid;
close card_data;
end;