268 lines
9.4 KiB
Plaintext
268 lines
9.4 KiB
Plaintext
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_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_archievement
|
|
(
|
|
a_caller_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_caller_name VARCHAR2(100);
|
|
l_this_month VARCHAR2(4);
|
|
l_this_year VARCHAR2(4);
|
|
l_firstday DATE;
|
|
BEGIN
|
|
--查询坐席名称,验证代码
|
|
BEGIN
|
|
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(SUM(cf.车险个人客户保费),
|
|
2) bf
|
|
INTO a_total
|
|
FROM 坐席车非每日保费 cf
|
|
WHERE cf.坐席工号 = a_caller_code
|
|
AND cf.年份 = l_this_year;
|
|
|
|
--渗透率
|
|
SELECT decode(SUM(cf.车险个人客户保费),
|
|
0,
|
|
0,
|
|
round(SUM(cf.车非融合保费) / SUM(cf.车险个人客户保费) * 100,
|
|
2))
|
|
INTO a_attaching_rate
|
|
FROM 坐席车非每日保费 cf
|
|
WHERE cf.坐席工号 = a_caller_code
|
|
AND cf.年份 = l_this_year
|
|
AND cf.月份 = l_this_month;
|
|
|
|
--续保率
|
|
SELECT decode(SUM(xb.到期数),
|
|
0,
|
|
0,
|
|
round(SUM(xb.已续保累计) / SUM(xb.到期数) * 100,
|
|
2)) xbl
|
|
INTO a_renewal_rate
|
|
FROM 坐席续保统计 xb
|
|
WHERE xb.坐席工号 = a_caller_code;
|
|
|
|
--每月业绩
|
|
OPEN A_MENSUAL_CUR FOR
|
|
SELECT CF.月份 MM,
|
|
ROUND(NVL(SUM(CF.车险个人客户保费 + CF.车非融合保费) / 10000,
|
|
0),
|
|
0) BF
|
|
FROM 坐席车非每日保费 CF
|
|
WHERE cf.坐席工号 = a_caller_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;
|
|
/
|