desktop_task_schedule/code/db/pkg/telsale_archievement_pkg.pck

130 lines
4.0 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;
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_chefei_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 DATE;
l_department_name VARCHAR2(100);
BEGIN
l_this_month := to_char(SYSDATE,
'mm') || '月';
l_this_year := to_date(to_char(SYSDATE,
'yyyy') || '-01-01 00:00:00',
'yyyy-mm-dd hh24:mi:ss');
SELECT bm.department_name
INTO l_department_name
FROM idst0.bm_t bm
WHERE bm.department_code = a_department_code;
--车非渗透率
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 部门代码 = 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_this_year
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_chefei_ranking_list OUT cur_type
) IS
l_current_month VARCHAR2(10);
BEGIN
l_current_month := to_char(SYSDATE,
'mm') || '月';
OPEN a_chefei_ranking_list FOR
SELECT 坐席名称,
round(SUM(车非融合保费) / SUM(车险个人客户保费) * 100,
2) 车非渗透率
FROM 车非每日保费
WHERE 月份 = l_current_month
AND 部门代码 = a_department_code
GROUP BY 月份,
部门代码,
坐席名称
HAVING 月份 = '06月'
ORDER BY 车非渗透率 DESC;
END;
BEGIN
NULL;
END telsale_archievement_pkg;
/