CREATE OR REPLACE PACKAGE telsale_archievement_pkg IS -- Author : WANGWEI-202 -- Created : 2023/3/10 15:13:34 -- Purpose : 桌面霸屏项目基础数据生成包 PROCEDURE 车非基础数据 ( a_start_date IN DATE, a_end_date IN DATE ); PROCEDURE gen_车非临时数据 ( a_start_date IN DATE, a_end_date IN DATE ); END telsale_archievement_pkg; / CREATE OR REPLACE PACKAGE BODY telsale_archievement_pkg IS PROCEDURE 车非基础数据 ( a_start_date IN DATE, a_end_date IN DATE ) IS --l_count INTEGER; --已有记录的数量 BEGIN --产生临时数据 gen_车非临时数据(a_start_date, a_end_date); FOR caller_record IN (SELECT * FROM desktop_archievement_admin.车非每日保费_t) LOOP BEGIN DELETE desktop_archievement_admin.车非每日保费 cf WHERE cf.签单日期 = caller_record.签单日期 AND cf.部门 = caller_record.部门 AND cf.经办人n = caller_record.经办人n AND cf.坐席工号 = caller_record.坐席工号; EXCEPTION WHEN no_data_found THEN NULL; END; INSERT INTO desktop_archievement_admin.车非每日保费 VALUES caller_record; END LOOP; COMMIT; EXCEPTION WHEN OTHERS THEN NULL; END; PROCEDURE gen_车非临时数据 ( a_start_date IN DATE, a_end_date IN DATE ) IS BEGIN desktop_archievement_admin.clean_temp_data; INSERT INTO desktop_archievement_admin.车非每日保费_t WITH aa AS (SELECT to_char(t.signature_date, 'yyyy-mm-dd') 签单日期, (to_char(T.signature_date, 'mm')) || '月' mm, t.policy_no bdh, t.endorsement_no pdh, qt.t_cre tid, QT.B_CRE BTID, -----添加字段 e.inception_date qbsj, e.planned_end_date zzsj, pt.premium_amount - nvl(pt.tax_amount, 0) bf, nt.ecompensation_rate * (pt.premium_amount - nvl(pt.tax_amount, 0)) fxbf, z.department_name bm, CASE WHEN (et.telpartnercode LIKE '%HC%' OR zx.workerno IN (SELECT code FROM datacenter.dc_lsj_zx_hc)) THEN '海沧丰骏' ELSE '' END 是否丰骏, nvl(zx.workerno, et.telpartnercode) 坐席工号, (CASE WHEN nvl(zx.workerno, et.telpartnercode) = 'DX001' AND xx.staff_name LIKE '%建发凯迪%' THEN '林伟华' WHEN nvl(zx.workerno, et.telpartnercode) = 'DX001' AND xx.staff_name NOT LIKE '%建发凯迪%' THEN '其他' ELSE to_char(ys.坐席姓名) END) 坐席名称, YS.团队 坐席团队, nvl(YS.团队, y.section_office_name) 科室N, nvl((CASE WHEN nvl(zx.workerno, et.telpartnercode) = 'DX001' AND xx.staff_name LIKE '%建发凯迪%' THEN '林伟华' WHEN nvl(zx.workerno, et.telpartnercode) = 'DX001' AND xx.staff_name NOT LIKE '%建发凯迪%' THEN '其他' ELSE to_char(ys.坐席姓名) END), xx.staff_name) 经办人N FROM idst0.auto_agreement_request_t t LEFT JOIN idst0.auto_agreement_t e ON e.policy_no = t.policy_no LEFT JOIN idst0.motorised_vehicle_t v ON v.policy_no = e.policy_no LEFT JOIN idst0.auto_premium_t pt ON pt.policy_no = t.policy_no AND pt.endorsement_no = t.endorsement_no LEFT JOIN ywglxt.w_dxbd_i i ON e.policy_no = i.bdh LEFT JOIN idst0.rydm_t xx ON xx.staff_code = nvl(i.zhjywy, e.operator_code) LEFT JOIN idst0.ks_t y ON y.section_office_code = nvl(xx.section_office_code, e.section_office_code) LEFT JOIN idst0.bm_t z ON z.department_code = nvl(xx.department_code, e.department_code) --left join datacenter.dc_cx_csteam ct on ct.jbrcode = xx.staff_code LEFT JOIN idst0.auto_new_product_info_t nt ON nt.policy_no = t.policy_no AND nt.endorsement_no = t.endorsement_no --left join ywglxt.q_auto_agreement_extend_t qe on qe.policy_no = e.policy_no LEFT JOIN ywglxt.q_auto_agreement_t qt ON qt.policy_no = e.policy_no LEFT JOIN datacenter.dc_yangg_qdcode qd ON qd.code = e.selling_channel_type LEFT JOIN datacenter.dc_tb_jc_c_tag cl ON cl.保单号 = e.policy_no LEFT JOIN datacenter.dc_yangg_basecode_teams fg ON fg.bm = z.department_name AND fg.ks = y.section_office_name --left join idst0.t_sell_policy_autobase_t zx on zx.policy_no=e.policy_no --left join idst0.auto_agreement_extend_t et on et.policy_no = e.policy_no LEFT JOIN idst0.auto_agreement_extend_t et ON et.policy_no = e.policy_no LEFT JOIN idst0.t_sell_policy_autobase_t zx ON zx.policy_no = e.policy_no LEFT JOIN datacenter.dc_YZH_ZXYS YS ON YS.坐席工号 = nvl(zx.workerno, et.telpartnercode) WHERE t.signature_date >= to_date('2023-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND t.signature_date < to_date(to_char(SYSDATE - 1, 'yyyy-mm-dd') || ' 23:59:59', 'yyyy-mm-dd hh24:mi:ss') --and t.endorsement_no = '无' AND e.policy_status = '1' --条件:保单有效 AND qt.tflag = '0' --条件:类型为个人 AND qt.usage_xm = '家庭自用车' --条件:单程提车、摩托车、拖拉机 AND e.planned_end_date - e.inception_date >= 360 --条件:保单周期 ) -----添加字段 , dd2 AS (SELECT 签单日期, mm, bm, 坐席工号, 坐席名称, 坐席团队, 科室N, 经办人N, CASE WHEN pdh = '无' THEN tid END tid, to_number('1') 客户数, COUNT(DISTINCT CASE WHEN pdh = '无' THEN bdh END) 保单数, SUM(bf) 保费 FROM (SELECT DISTINCT * FROM aa) aa GROUP BY bm, CASE WHEN pdh = '无' THEN tid END, mm, BTID, 坐席工号, 坐席名称, 坐席团队, 签单日期, 科室N, 经办人N UNION SELECT 签单日期, mm, bm, 坐席工号, 坐席名称, 坐席团队, 科室N, 经办人N, CASE WHEN btid = tid THEN '' ELSE btid END btid, to_number('0') 客户数, to_number('0') 保单数, to_number('0') 保费 FROM (SELECT DISTINCT * FROM aa) aa), DD AS (SELECT * FROM DD2 WHERE TID IS NOT NULL) --select * from dd , bb AS (SELECT DISTINCT q.policy_no bdh, q.endorsement_no pdh, qna.t_cre tid, to_number(to_char(q.signature_date, 'yyyy')) || '年' nf, (to_char(q.signature_date, 'mm')) || '月' mm_f, to_char(q.signature_date, 'dd') || '日' dd, q.signature_date sj, round((pt.premium_amount - nvl(pt.taxamount, 0)) * c.rate / 100, 2) bf, z.department_name bm FROM idst0.nonauto_agreement_request_t q LEFT JOIN idst0.nonauto_agreement_t e ON e.policy_no = q.policy_no LEFT JOIN idst0.nonauto_premium_t pt ON pt.endorsement_no = q.endorsement_no AND pt.policy_no = q.policy_no LEFT JOIN idst0.reinsurance_t r ON r.reinsurance_policy_no = e.policy_no LEFT JOIN idst0.exrate_month_t c ON pt.currency_code = c.bzh AND to_char(q.signature_date, 'YYYY') = c.theyear AND to_char(q.signature_date, 'fmmm') = c.themonth LEFT JOIN idst0.rydm_t x ON x.staff_code = e.operator_code LEFT JOIN idst0.ks_t y ON y.section_office_code = x.section_office_code LEFT JOIN idst0.bm_t z ON z.department_code = x.department_code LEFT JOIN ywglxt.q_nonauto_agreement_t qna ON qna.policy_no = q.policy_no LEFT JOIN datacenter.dc_yangg_gkxzh gk ON gk.product_code = e.product_code --分散型险种 LEFT JOIN dd ON dd.tid = qna.t_cre WHERE qna.tflag = '0' AND (CASE WHEN q.endorsement_no != '无' AND round((pt.premium_amount - nvl(pt.taxamount, 0)) * c.rate / 100, 2) != 0 THEN '是' END) IS NULL AND e.policy_status = '1' AND gk.product_code IS NOT NULL AND (e.product_code LIKE '2%' OR e.product_code LIKE '1106%' --意健 --责任 OR e.product_code LIKE '1107%' OR e.product_code LIKE '1108%' OR e.product_code LIKE '1307%' OR e.product_code LIKE '1304A400%' --家财 ) AND q.signature_date >= to_date('2023-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND q.signature_date < to_date(to_char(SYSDATE - 1, 'yyyy-mm-dd') || ' 23:59:59', 'yyyy-mm-dd hh24:mi:ss') AND e.planned_end_date - e.inception_date >= 90 AND dd.tid IS NOT NULL --车险个人客户) ) --SELECT * FROM BB , cc AS (SELECT mm_f, tid 融合证件, COUNT(DISTINCT bdh) 融合保数, SUM(bf) 融合保费 FROM bb GROUP BY tid, mm_f), ff AS (SELECT dd.*, cc.* FROM dd LEFT JOIN cc ON cc.融合证件 = dd.tid AND cc.mm_f = dd.mm) SELECT to_date(签单日期, 'yyyy-mm-dd'), mm 月份, bm 部门, 科室N, 经办人N, 坐席工号, 坐席名称, 坐席团队, nvl(SUM(保费), 0) 车险个人客户保费, nvl(SUM(融合保费), 0) 车非融合保费 FROM ff WHERE ff.签单日期 >= to_char(a_start_date, 'yyyy-mm-dd') AND ff.签单日期 <= to_char(a_end_date, 'yyyy-mm-dd') AND bm IN ('续保业务部', '湖里支公司') GROUP BY 签单日期, mm, bm, 坐席工号, 坐席名称, 坐席团队, 科室N, 经办人N ORDER BY 部门, 坐席名称; END; BEGIN NULL; END telsale_archievement_pkg; /