CREATE OR REPLACE PACKAGE telsale_archievement_pkg IS -- Author : WANGWEI-202 -- Created : 2023/3/10 15:13:34 -- Purpose : 桌面霸屏项目基础数据生成包 TYPE cur_type IS REF CURSOR; -- 异常 DEPARTMENTCODE_EXCEPTION_CODE CONSTANT INTEGER := -20000; DEPARTMENTCODE_EXCEPTION_MSG CONSTANT VARCHAR2(100) := '部门代码无效。'; CALLERCODE_EXCEPTION_CODE CONSTANT INTEGER := -20001; CALLERCODE_EXCEPTION_MSG CONSTANT VARCHAR2(100) := '坐席工号无效。'; PROCEDURE department_archievement ( a_department_code IN VARCHAR2, a_attaching_rate OUT VARCHAR2, a_renewal_rate OUT VARCHAR2, a_total OUT INTEGER, a_mensual_cur OUT cur_type ); PROCEDURE caller_archievement ( a_caller_code IN VARCHAR2, a_attaching_rate OUT VARCHAR2, a_renewal_rate OUT VARCHAR2, a_total OUT INTEGER, a_present_month OUT NUMBER, a_mensual_cur OUT cur_type ); PROCEDURE caller_arch_ranking_list ( a_department_code IN VARCHAR2, a_year IN VARCHAR2, a_month IN VARCHAR2, a_attaching_ranking_list OUT cur_type, a_renewal_ranking_list OUT cur_type ); END telsale_archievement_pkg; / CREATE OR REPLACE PACKAGE BODY TELSALE_ARCHIEVEMENT_PKG IS -- 部门业绩 PROCEDURE DEPARTMENT_ARCHIEVEMENT ( A_DEPARTMENT_CODE IN VARCHAR2, A_ATTACHING_RATE OUT VARCHAR2, A_RENEWAL_RATE OUT VARCHAR2, A_TOTAL OUT INTEGER, A_MENSUAL_CUR OUT CUR_TYPE ) IS --L_THIS_MONTH VARCHAR2(4); --L_THIS_YEAR VARCHAR2(4); L_FIRSTDAY DATE; L_DEPARTMENT_NAME VARCHAR2(100); BEGIN /*L_THIS_MONTH := TO_CHAR(SYSDATE, 'mm'); L_THIS_YEAR := TO_CHAR(SYSDATE, 'yyyy');*/ L_FIRSTDAY := TO_DATE(TO_CHAR(SYSDATE, 'yyyy') || '-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss'); -- 获取部门名称 BEGIN SELECT DEPARTMENT_NAME INTO L_DEPARTMENT_NAME FROM IDST0.BM_T BM WHERE BM.DEPARTMENT_CODE = A_DEPARTMENT_CODE; EXCEPTION -- 如果没有找到部门名称,说明代码错误,抛出异常 WHEN NO_DATA_FOUND THEN RAISE_APPLICATION_ERROR(DEPARTMENTCODE_EXCEPTION_CODE, DEPARTMENTCODE_EXCEPTION_MSG); END; --车非渗透率 /*SELECT DECODE(SUM(CF.车险个人客户保费), 0, 0, ROUND((SUM(CF.车非融合保费) / SUM(CF.车险个人客户保费) * 100), 2)) INTO A_ATTACHING_RATE FROM 坐席车非每日保费 CF WHERE CF.月份 = L_THIS_MONTH AND CF.年份 = L_THIS_YEAR AND 部门代码 = A_DEPARTMENT_CODE;*/ SELECT round(dept.当月保费渗透率, 2) INTO A_ATTACHING_RATE FROM desktop_archievement_admin.BI机构渗透率跟踪表 dept WHERE dept.部门 = L_DEPARTMENT_NAME; --续保率 /*SELECT DECODE(SUM(到期数), 0, 0, ROUND(SUM(已续保累计) / SUM(到期数) * 100, 2)) INTO A_RENEWAL_RATE FROM 坐席续保统计 WHERE 部门 = L_DEPARTMENT_NAME;*/ SELECT round(t."个车续保率(全月)(%)", 2) INTO A_RENEWAL_RATE FROM BI机构当月个车续保率跟踪表 t WHERE t.责任部门 = L_DEPARTMENT_NAME; --总业绩 SELECT ROUND(NVL(SUM(CF.车险个人客户保费 + CF.车非融合保费), 0), 0) INTO A_TOTAL FROM 坐席车非每日保费 CF WHERE 部门代码 = A_DEPARTMENT_CODE AND 签单日期 >= L_FIRSTDAY AND 签单日期 <= SYSDATE; --每月业绩 OPEN A_MENSUAL_CUR FOR SELECT CF.月份 MM, ROUND(NVL(SUM(CF.车险个人客户保费 + CF.车非融合保费) / 10000, 0), 0) BF FROM 坐席车非每日保费 CF WHERE 部门代码 = A_DEPARTMENT_CODE AND 签单日期 >= TO_DATE(TO_CHAR(SYSDATE, 'yyyy') || '-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND 签单日期 < TO_DATE(TO_CHAR(SYSDATE, 'yyyy-mm') || '-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') GROUP BY CF.月份 ORDER BY CF.月份; END; /*******************************************************/ -- 坐席业绩 PROCEDURE caller_archievement ( a_caller_code IN VARCHAR2, a_attaching_rate OUT VARCHAR2, a_renewal_rate OUT VARCHAR2, a_total OUT INTEGER, a_present_month OUT NUMBER, a_mensual_cur OUT cur_type ) IS l_caller_name VARCHAR2(100); l_department_name VARCHAR2(100); --l_this_month VARCHAR2(4); l_this_year VARCHAR2(4); --l_firstday DATE; l_rownum INTEGER; BEGIN --查询坐席名称,和部门名称,验证代码 BEGIN SELECT zx.saler_name, bm.department_name INTO l_caller_name, l_department_name FROM tele_saler zx, tele_saler_team team, idst0.bm_t bm WHERE zx.saler_code = a_caller_code AND zx.team_code = team.team_code AND team.department_code = bm.department_code; /* SELECT saler_name INTO l_caller_name FROM tele_saler WHERE saler_code = a_caller_code;*/ EXCEPTION -- 如果没有查询到坐席名称,说明代码有误,抛出异常 WHEN no_data_found THEN raise_application_error(CALLERCODE_EXCEPTION_CODE, CALLERCODE_EXCEPTION_MSG); END; --l_this_month := to_char(SYSDATE, -- 'mm'); l_this_year := to_char(SYSDATE, 'yyyy'); --l_firstday := to_date(l_this_year || '-01-01 00:00:00', -- 'yyyy-mm-dd hh24:mi:ss'); --总车险保费 SELECT round(nvl(SUM(cf.车险个人客户保费), 0), 2) bf INTO a_total FROM 坐席车非每日保费 cf WHERE cf.坐席名称 = l_caller_name AND cf.部门 = l_department_name AND cf.年份 = l_this_year; --渗透率 SELECT rownum, round(nvl(t.当月保费渗透率, 0), 2), round(nvl(t."车险保费(万)" * 10000, 0), 2) INTO l_rownum, a_attaching_rate, a_present_month FROM BI电销坐席车非渗透率跟踪表 t WHERE t.经办 = l_caller_name AND rownum = 1; --续保率 SELECT rownum, round(nvl(t."个车续保率(全月)(%)", 0), 2) INTO l_rownum, a_renewal_rate FROM BI电销坐席续保率跟踪表 t WHERE t.责任人 = l_caller_name AND rownum = 1; --每月业绩 OPEN A_MENSUAL_CUR FOR SELECT CF.月份 MM, ROUND(NVL(SUM(CF.车险个人客户保费), 0), 0) BF FROM 坐席车非每日保费 CF WHERE cf.坐席名称 = l_caller_name AND cf.部门 = l_department_name AND 签单日期 >= TO_DATE(TO_CHAR(SYSDATE, 'yyyy') || '-01-01 00:00:00', 'yyyy-mm-dd hh24:mi:ss') AND 签单日期 <= SYSDATE GROUP BY CF.月份 ORDER BY CF.月份; END; /*******************************************************/ -- 坐席排行榜 PROCEDURE CALLER_ARCH_RANKING_LIST ( A_DEPARTMENT_CODE IN VARCHAR2, A_YEAR IN VARCHAR2, A_MONTH IN VARCHAR2, A_ATTACHING_RANKING_LIST OUT CUR_TYPE, A_RENEWAL_RANKING_LIST OUT CUR_TYPE ) IS L_DEPARTMENT_NAME VARCHAR2(100); BEGIN -- 获取部门名称 BEGIN SELECT DEPARTMENT_NAME INTO L_DEPARTMENT_NAME FROM IDST0.BM_T BM WHERE BM.DEPARTMENT_CODE = A_DEPARTMENT_CODE; EXCEPTION -- 如果没有找到部门名称,说明代码错误,抛出异常 WHEN NO_DATA_FOUND THEN RAISE_APPLICATION_ERROR(DEPARTMENTCODE_EXCEPTION_CODE, DEPARTMENTCODE_EXCEPTION_MSG); END; -- 车非融合率排行榜 OPEN A_ATTACHING_RANKING_LIST FOR SELECT rownum, paihang.经办 AS caller_name, paihang.attaching_rate FROM (SELECT DISTINCT * FROM (SELECT t.经办, round(t.当月保费渗透率, 2) attaching_rate, zuoxi.department_name FROM BI电销坐席车非渗透率跟踪表 t, (SELECT DISTINCT t.saler_code, t.saler_name, t.team_code, team.team, bm.department_name FROM tele_saler t, tele_saler_team team, idst0.bm_t bm WHERE t.team_code = team.team_code AND team.department_code = bm.department_code AND bm.department_name = L_DEPARTMENT_NAME) zuoxi WHERE t.经办 = zuoxi.saler_name) st ORDER BY st.department_name, st.attaching_rate DESC) paihang; -- 续保率排行榜 OPEN A_RENEWAL_RANKING_LIST FOR SELECT rownum, paihang.责任人 AS CALLER_NAME, paihang.xbl AS RENEWAL_RATE FROM (SELECT DISTINCT * FROM (SELECT t.责任人, round(t."个车续保率(全月)(%)", 2) xbl, zuoxi.department_name FROM BI电销坐席续保率跟踪表 t, (SELECT DISTINCT t.saler_code, t.saler_name, t.team_code, team.team, bm.department_name FROM tele_saler t, tele_saler_team team, idst0.bm_t bm WHERE t.team_code = team.team_code AND team.department_code = bm.department_code AND bm.department_name = L_DEPARTMENT_NAME) zuoxi WHERE t.责任人 = zuoxi.saler_name) xb ORDER BY xb.department_name, xb.xbl DESC) paihang; END; BEGIN NULL; END TELSALE_ARCHIEVEMENT_PKG; /