desktop_task_schedule/code/db/pkg/telsale_archievement_dev_pk...

310 lines
11 KiB
Plaintext

CREATE OR REPLACE PACKAGE TELSALE_ARCHIEVEMENT_DEV_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_ATTACHING_RATE_TARGET OUT VARCHAR2,
A_RENEWAL_RATE OUT VARCHAR2,
A_RENEWAL_RATE_TARGET 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_DEV_PKG;
/
CREATE OR REPLACE PACKAGE BODY TELSALE_ARCHIEVEMENT_DEV_PKG IS
-- 部门业绩
PROCEDURE DEPARTMENT_ARCHIEVEMENT
(
A_DEPARTMENT_CODE IN VARCHAR2,
A_ATTACHING_RATE OUT VARCHAR2,
A_ATTACHING_RATE_TARGET OUT VARCHAR2,
A_RENEWAL_RATE OUT VARCHAR2,
A_RENEWAL_RATE_TARGET OUT VARCHAR2,
A_TOTAL OUT INTEGER,
A_MENSUAL_CUR OUT CUR_TYPE
) IS
L_FIRSTDAY DATE;
L_DEPARTMENT_NAME VARCHAR2(100);
L_RENEWAL_RATE_TARGET NUMBER;
BEGIN
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;
--车非渗透率&目标差距
BEGIN
SELECT ROUND(DEPT.当月保费渗透率,
2),
ROUND(DEPT.目标差距,
2)
INTO A_ATTACHING_RATE,
A_ATTACHING_RATE_TARGET
FROM DESKTOP_ARCHIEVEMENT_ADMIN.BI机构渗透率跟踪表 DEPT
WHERE DEPT.部门 = L_DEPARTMENT_NAME;
--解决round导致小数缺0的问题
SELECT DECODE(SUBSTR(A_ATTACHING_RATE_TARGET,
1,
1),
'.',
'0' || A_ATTACHING_RATE_TARGET,
A_ATTACHING_RATE_TARGET)
INTO A_ATTACHING_RATE_TARGET
FROM DUAL;
EXCEPTION
WHEN NO_DATA_FOUND THEN
A_ATTACHING_RATE := '0.0';
A_ATTACHING_RATE_TARGET := '0.0';
END;
--续保率&目标差距
BEGIN
SELECT ROUND(t."个车续保率(序时)(%)",
2),
ROUND(t."个车续保率(序时)(%)" - t."机构目标值1(%)",
2)
INTO A_RENEWAL_RATE,
A_RENEWAL_RATE_TARGET
FROM BI机构当月个车续保率跟踪表 T
WHERE T.责任部门 = L_DEPARTMENT_NAME;
--解决round导致小数缺0的问题
SELECT DECODE(SUBSTR(A_RENEWAL_RATE_TARGET,
1,
1),
'.',
'0' || A_RENEWAL_RATE_TARGET,
A_RENEWAL_RATE_TARGET)
INTO A_RENEWAL_RATE_TARGET
FROM DUAL;
EXCEPTION
WHEN NO_DATA_FOUND THEN
A_RENEWAL_RATE := '0.0';
A_RENEWAL_RATE_TARGET := '0.0';
END;
--总业绩
A_TOTAL := 0;
--每月业绩
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_YEAR VARCHAR2(4);
L_ROWNUM INTEGER;
BEGIN
--查询坐席名称,和部门名称,验证代码
BEGIN
SELECT ZX.人员姓名,
BM.DEPARTMENT_NAME
INTO L_CALLER_NAME,
L_DEPARTMENT_NAME
FROM TWR_TELSALER ZX,
TWR_TELSALER_TEAM T,
IDST0.BM_T BM
WHERE ZX.人员工号 = A_CALLER_CODE
AND ZX.团队名称 = T.TEAM_NAME
AND T.DEPARTMENT_CODE = BM.DEPARTMENT_CODE;
EXCEPTION
-- 如果没有查询到坐席名称,说明代码有误,抛出异常
WHEN NO_DATA_FOUND THEN
RAISE_APPLICATION_ERROR(CALLERCODE_EXCEPTION_CODE,
CALLERCODE_EXCEPTION_MSG);
END;
L_THIS_YEAR := TO_CHAR(SYSDATE,
'yyyy');
--总车险保费
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;
--渗透率
BEGIN
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;
EXCEPTION
WHEN NO_DATA_FOUND THEN
L_ROWNUM := 1;
A_ATTACHING_RATE := 0.0;
A_PRESENT_MONTH := 0.0;
END;
--续保率
BEGIN
SELECT ROWNUM,
ROUND(NVL(t."个车续保率(全月)(%)",
0),
2)
INTO L_ROWNUM,
A_RENEWAL_RATE
FROM BI电销坐席续保率跟踪表 T
WHERE T.责任人 = L_CALLER_NAME
AND ROWNUM = 1;
EXCEPTION
WHEN NO_DATA_FOUND THEN
L_ROWNUM := 1;
A_RENEWAL_RATE := 0.0;
END;
--每月业绩
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.XBL AS ATTACHING_RATE
FROM (SELECT T.经办,
ROUND(T.当月保费渗透率,
2) XBL
FROM BI电销坐席车非渗透率跟踪表 T
WHERE T.部门 = L_DEPARTMENT_NAME
ORDER BY T.当月保费渗透率 DESC) PAIHANG;
-- 续保率排行榜
OPEN A_RENEWAL_RANKING_LIST FOR
SELECT ROWNUM,
PAIHANG.责任人 AS CALLER_NAME,
PAIHANG.XBL AS RENEWAL_RATE
FROM (SELECT T.责任人,
ROUND(t."个车续保率(全月)(%)",
2) XBL
FROM BI电销坐席续保率跟踪表 T
WHERE T.责任部门 = L_DEPARTMENT_NAME
ORDER BY XBL DESC) PAIHANG;
END;
BEGIN
NULL;
END TELSALE_ARCHIEVEMENT_DEV_PKG;
/