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) := '部门代码无效'; 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_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 decode(SUM(到期数), 0, 0, round(SUM(已续保累计) / SUM(到期数) * 100, 2)) INTO a_renewal_rate FROM 坐席续保统计 WHERE 部门 = 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_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, 坐席名称 as caller_name, 车非渗透率 as attaching_rate FROM (SELECT 坐席名称, round(decode(SUM(车险个人客户保费), 0, 0, (SUM(车非融合保费) / SUM(车险个人客户保费)) * 100), 2) 车非渗透率 FROM 坐席车非每日保费 WHERE 月份 = a_month AND 年份 = a_year AND 部门代码 = a_department_code GROUP BY 坐席名称 ORDER BY 车非渗透率 DESC); -- 续保率排行榜 OPEN a_renewal_ranking_list FOR SELECT rownum, 坐席名称 as caller_name, 续保率 as renewal_rate FROM (SELECT 坐席名称, round(nvl((SUM(已续保累计) / SUM(到期数)) * 100, 0), 2) 续保率 FROM 坐席续保统计 xb WHERE xb.部门 = l_department_name GROUP BY 坐席名称 ORDER BY 续保率 DESC); END; BEGIN NULL; END telsale_archievement_pkg; /