apzl_leasing/src_sql/procedure/proc_insert_jlyj_his.sql

147 lines
5.3 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

create procedure proc_insert_jlyj_his(IN instart_date varchar(32), IN inend_date varchar(32))
BEGIN
WHILE instart_date<=inend_date
DO
SET instart_date = DATE_FORMAT(LAST_DAY(DATE_ADD(STR_TO_DATE(instart_date,'%Y/%m/%d'),INTERVAL 1 MONTH)),'%Y/%m/%d');
INSERT INTO `apzl`.`commission_interest` (
`ID`,
`distributor_name`,
`distri_relative`,
`telephone`,
`comm_months`,
`history_month`,
`loan_orders`,
`FIELD1`,
`FIELD2`,
`FIELD3`,
`FIELD4`,
`FIELD5`,
`INPUTUSERID`,
`INPUTORGID`,
`INPUTTIME`,
`UPDATEUSERID`,
`UPDATEORGID`,
`UPDATETIME`
) (
SELECT
REPLACE(UUID(), '-', ''),
t3.distributor_name,
t3.distributorer,
t3.distributor_tel,
t3.fact_date,
-- 统计月份统计数据未3月前数据
instart_date,
t3.danliang,
t3.fact_money,
t3.yuqinum,
t3.sumcorpus,
t3.yuqinum_jieqing,
t3.vtg,
'8009U00000002',
'8009001',
DATE_FORMAT(CURDATE(), '%Y/%m/%d'),
'',
'',
''
FROM (
SELECT
MAX(t.distributor_no) distributor_no,
MAX(t.distributor_name) distributor_name,
MAX(t.distributorer) distributorer,
MAX(t.distributor_tel) distributor_tel,
t.fact_date,
COUNT(1) danliang,
SUM(t.FACT_MONEY) FACT_MONEY,
SUM(IFNULL(t.yuqinum,0)) yuqinum,
CASE WHEN MAX(IFNULL(t.sumcorpus,0))=0 THEN 0 ELSE
SUM(t.FACT_MONEY-IFNULL(t.sumcorpus,0)) END sumcorpus,
SUM(IFNULL(t.yuqinum_jieqing,0)) yuqinum_jieqing,
(CASE WHEN MAX(IFNULL(t.sumcorpus,0))=0 THEN 0 ELSE
SUM(t.FACT_MONEY-IFNULL(t.sumcorpus,0)) END )/SUM(t.FACT_MONEY) vtg
FROM (
SELECT
lci.`CONTRACT_Number`,
lci.PRODUCT_ID,
SUBSTR(lci.`PROJECT_NAME`,10) cust_name,
LEFT(lfi.`FACT_DATE`,7) FACT_DATE,
lfi.`FACT_MONEY`,
di.distributor_no,
di.`distributor_name`,
di.`distributorer`,
di.`distributor_tel`,
vorp.yuqinum,
vorp.sumcorpus,
vorp.yuqinum_jieqing
FROM
lb_contract_info lci
LEFT JOIN distributor_info di ON lci.`distributor_id`=di.distributor_no
LEFT JOIN `lb_product_info` lpi ON lpi.PRODUCT_ID=lci.`PRODUCT_ID`
LEFT JOIN CONFIGURATE c ON lpi.`PRODUCT_ID`=c.`ATTR_ID` AND field5='产品佣金系数配置'
LEFT JOIN lc_fund_income lfi ON lfi.`CONTRACT_ID`=lci.`ID` AND lfi.`FEE_TYPE`='feetype10'
LEFT JOIN (
SELECT
v.contract_id,
-- 逾期30天及以上单量
CASE WHEN MAX(v.overdue_days)>=30
THEN 1 ELSE 0 END yuqinum,
-- 逾期30天及以上未偿本金总额
CASE WHEN MAX(v.overdue_days)>=30 THEN
SUM(v.fact_corpus) ELSE 0 END sumcorpus,
-- 逾期30天以上但已还款单量
CASE WHEN MAX(v.overdue_days)>=30 AND MAX(v.plan_status)<>'未结清'
THEN 1 ELSE 0 END yuqinum_jieqing
FROM (
-- 下面为逾期视图vi_overdue_rent_plan截止统计月份的逾期数据
SELECT
`lrp`.`ID` AS `ID`,
`lrp`.`QUOT_ID` AS `QUOT_ID`,
`lrp`.`CUST_ID` AS `CUST_ID`,
`lrp`.`PROJECT_ID` AS `PROJECT_ID`,
`lrp`.`PROJECT_PLAN_NUMBER` AS `PROJECT_PLAN_NUMBER`,
`lrp`.`CONTRACT_ID` AS `CONTRACT_ID`,
`lrp`.`CONTRACT_PLAN_NUMBER` AS `CONTRACT_PLAN_NUMBER`,
`lrp`.`PAYMENT_NUMBER` AS `PAYMENT_NUMBER`,
`lrp`.`PLAN_LIST` AS `PLAN_LIST`,
`lrp`.`PLAN_DATE` AS `PLAN_DATE`,
`lrp`.`RENT` AS `RENT`,
`lrp`.`CORPUS` AS `corpus`,
`income`.`hire_date` AS `HIRE_DATE`,
IFNULL(`income`.`fact_rent`,0) AS `fact_rent`,
IFNULL(`income`.`fact_corpus`,0) AS `fact_corpus`,
IFNULL(`income`.`fact_penalty`,0) AS `fact_penalty`,
(IFNULL(`lrp`.`RENT`,0) - IFNULL(`income`.`fact_rent`,0)) AS `overduerent`,
(CASE WHEN ((IFNULL(`income`.`fact_rent`,0) - IFNULL(`lrp`.`RENT`,0)) > 0) THEN (TO_DAYS(`income`.`hire_date`) - TO_DAYS(`lrp`.`PLAN_DATE`)) ELSE (TO_DAYS(instart_date) - TO_DAYS(`lrp`.`PLAN_DATE`)) END) AS `Overdue_days`,
(CASE WHEN ((IFNULL(`income`.`fact_rent`,0) - IFNULL(`lrp`.`RENT`,0)) > 0) THEN '已结清' ELSE '未结清' END) AS `PLAN_STATUS`
FROM (`apzl`.`lc_rent_plan` `lrp`
LEFT JOIN (SELECT
`apzl`.`lc_rent_income`.`PAYMENT_NUMBER` AS `payment_number`,
`apzl`.`lc_rent_income`.`PLAN_LIST` AS `plan_list`,
MAX(`apzl`.`lc_rent_income`.`HIRE_DATE`) AS `hire_date`,
IFNULL(SUM(`apzl`.`lc_rent_income`.`RENT`),0) AS `fact_rent`,
IFNULL(SUM(`apzl`.`lc_rent_income`.`CORPUS`),0) AS `fact_corpus`,
IFNULL(SUM(`apzl`.`lc_rent_income`.`INTEREST`),0) AS `fact_interest`,
IFNULL(SUM(`apzl`.`lc_rent_income`.`PENALTY`),0) AS `fact_penalty`
FROM `apzl`.`lc_rent_income`
WHERE (`apzl`.`lc_rent_income`.`PAYMENT_NUMBER` IS NOT NULL)
GROUP BY `apzl`.`lc_rent_income`.`PAYMENT_NUMBER`,`apzl`.`lc_rent_income`.`PLAN_LIST`) `income`
ON (((`lrp`.`PAYMENT_NUMBER` = `income`.`payment_number`)
AND (`lrp`.`PLAN_LIST` = `income`.`plan_list`))))
WHERE ((`lrp`.`PAYMENT_NUMBER` IS NOT NULL)
AND (`lrp`.`PLAN_DATE` <= instart_date
))
ORDER BY `lrp`.`PAYMENT_NUMBER`,`lrp`.`PLAN_LIST`
) v GROUP BY v.contract_id
) vorp ON vorp.contract_id=lci.id
-- 统计集团外经销商的激励佣金f_i_type02
WHERE lci.contract_status>=31 AND di.F_I_TYPE='f_i_type02'
) t
-- 统计数据为3月前数据
WHERE t.fact_date=LEFT(DATE_FORMAT(SUBDATE(instart_date,INTERVAL 3 MONTH),'%Y/%m'),7)
GROUP BY t.distributor_no,t.FACT_DATE ORDER BY t.FACT_DATE DESC,t.distributor_no
) t3);
END WHILE;
END;