完成排行榜代码,还没测试

This commit is contained in:
Kane Wang 2023-06-05 18:09:40 +08:00
parent 6f65e18672
commit 4eec8a9f18
3 changed files with 176 additions and 37 deletions

View File

@ -6,6 +6,10 @@ CREATE OR REPLACE PACKAGE telsale_archievement_pkg IS
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,
@ -17,8 +21,11 @@ CREATE OR REPLACE PACKAGE telsale_archievement_pkg IS
PROCEDURE caller_arch_ranking_list
(
a_department_code IN VARCHAR2,
a_chefei_ranking_list OUT cur_type
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;
@ -46,11 +53,19 @@ CREATE OR REPLACE PACKAGE BODY telsale_archievement_pkg IS
l_firstday := 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;
-- 获取部门名称
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.车险个人客户保费),
@ -102,32 +117,55 @@ CREATE OR REPLACE PACKAGE BODY telsale_archievement_pkg IS
ORDER BY cf.月份;
END;
/*******************************************************/
-- 坐席排行榜
PROCEDURE caller_arch_ranking_list
(
a_department_code IN VARCHAR2,
a_chefei_ranking_list OUT cur_type
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_current_month VARCHAR2(10);
l_current_year VARCHAR2(4);
l_department_name VARCHAR2(100);
BEGIN
l_current_month := to_char(SYSDATE,
'mm');
l_current_year := to_char(SYSDATE,
'yyyy');
-- 获取部门名称
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_chefei_ranking_list FOR
-- 车非融合率排行榜
OPEN a_attaching_ranking_list FOR
SELECT 坐席名称,
round(SUM(车非融合保费) / SUM(车险个人客户保费) * 100,
round(nvl(SUM(车非融合保费) / SUM(车险个人客户保费),
0) * 100,
2) 车非渗透率
FROM 坐席车非每日保费
WHERE 月份 = l_current_month
AND 年份 = l_current_year
WHERE 月份 = a_month
AND 年份 = a_year
AND 部门代码 = a_department_code
GROUP BY 月份,
部门代码,
坐席名称
GROUP BY 坐席名称
--HAVING 月份 = '06月'
ORDER BY 车非渗透率 DESC;
-- 续保率排行榜
OPEN a_renewal_ranking_list FOR
SELECT 坐席名称,
round(nvl(已续保累计 / 到期数 * 100,
0),
2) 续保率
FROM 坐席续保统计 xb
WHERE xb.部门 = '续保业务部'
ORDER BY 续保率 DESC;
END;
BEGIN

View File

@ -15,6 +15,13 @@ public class CallerRankingItem
{
public CallerRankingItem() {}
public CallerRankingItem( int index, String callName, String appraiseValue )
{
this.index = index;
this.callerName = callName;
this.appraiseValue = appraiseValue;
}
public int getIndex()
{

View File

@ -9,17 +9,12 @@
*/
package com.cpic.xim.utils.ranking;
import java.util.Vector;
import com.fasterxml.jackson.annotation.JsonProperty;
import java.sql.CallableStatement;
import java.sql.Connection;
import java.sql.DriverManager;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.CallableStatement;
import java.util.Vector;
import com.fasterxml.jackson.annotation.JsonProperty;
import oracle.jdbc.OracleCallableStatement;
import oracle.jdbc.OracleTypes;
@ -30,9 +25,13 @@ public class CallerRankingList
private static String userName = "desktop_archievement_admin";
private static String password = "Cpic123456";
private CallerRankingList( Vector<CallerRankingItem> attachingRateRankingList,
private CallerRankingList( String departmentCode, String year, String month,
Vector<CallerRankingItem> attachingRateRankingList,
Vector<CallerRankingItem> renewalRateRankingList)
{
this.departmentCode = departmentCode;
this.year = year;
this.month = month;
this.attachingRateRankingList = attachingRateRankingList;
this.renewalRateRankingList = renewalRateRankingList;
}
@ -51,30 +50,77 @@ public class CallerRankingList
Connection connection = null;
CallableStatement statement = null;
ResultSet result = null;
ResultSet cur_attaching = null;
ResultSet cur_renewal = null;
String sql = """
{call telsale_archievement_pkg.caller_arch_ranking_list(?,?,?)}
""";
String monthRegx = "(0[1-9])|(1[0-2])";
String yearRegx = "20[0-2][0-0]";
Vector<CallerRankingItem> attachingRateRankingList = new Vector<>();
Vector<CallerRankingItem> renewalRateRankingList = new Vector<>();
int index = 1;
try
{
Class.forName( "oracle.jdbc.driver.OracleDriver" );
connection = DriverManager.getConnection( jdbcURL, userName, password );
statement = connection.prepareCall(sql);
statement = connection.prepareCall( sql );
statement.setString( 1, departmentCode );
statement.registerOutParameter(2, OracleTypes.CURSOR );
statement.registerOutParameter(3, OracleTypes.CURSOR );
statement.setString( 2, year );
statement.setString( 3, month );
statement.registerOutParameter( 4, OracleTypes.CURSOR );
statement.registerOutParameter( 5, OracleTypes.CURSOR );
statement.execute();
// 车非渗透率
cur_attaching = ((OracleCallableStatement) statement).getCursor( 4 );
index = 1;
while ( cur_attaching.next())
{
String callerName = cur_attaching.getString( 1 );
String appraiseValue = cur_attaching.getString( 2 );
CallerRankingItem caller =
new CallerRankingItem( index, callerName, appraiseValue );
attachingRateRankingList.add( caller );
index++;
}
// 续保率
cur_renewal = ((OracleCallableStatement) statement).getCursor( 5 );
index = 1;
while ( cur_renewal.next())
{
String callerName = cur_renewal.getString( 1 );
String appraiseValue = cur_renewal.getString( 2 );
CallerRankingItem caller =
new CallerRankingItem( index, callerName, appraiseValue );
attachingRateRankingList.add( caller );
index++;
}
rankingList = new CallerRankingList( departmentCode, year, month,
attachingRateRankingList, renewalRateRankingList );
}
finally
{
try
{
if ( result != null )
if ( cur_attaching != null )
{
result.close();
cur_attaching.close();
}
}
catch ( Exception exception )
@ -111,6 +157,56 @@ public class CallerRankingList
return rankingList;
}
public String getDepartmentCode()
{
return departmentCode;
}
public void setDepartmentCode( String departmentCode )
{
this.departmentCode = departmentCode;
}
public String getYear()
{
return year;
}
public void setYear( String year )
{
this.year = year;
}
public String getMonth()
{
return month;
}
public void setMonth( String month )
{
this.month = month;
}
public Vector<CallerRankingItem> getAttachingRateRankingList()
{
return attachingRateRankingList;
}
public void setAttachingRateRankingList( Vector<CallerRankingItem> attachingRateRankingList )
{
this.attachingRateRankingList = attachingRateRankingList;
}
public Vector<CallerRankingItem> getRenewalRateRankingList()
{
return renewalRateRankingList;
}
public void setRenewalRateRankingList( Vector<CallerRankingItem> renewalRateRankingList )
{
this.renewalRateRankingList = renewalRateRankingList;
}
// 部门代码
private String departmentCode;
@ -121,11 +217,9 @@ public class CallerRankingList
private String month;
// 车非融合率排行
@JsonProperty( "attachingRateRankingList" )
private Vector<CallerRankingItem> attachingRateRankingList;
// 续保率排行
@JsonProperty( "renewalRateRankingList" )
private Vector<CallerRankingItem> renewalRateRankingList;
}