CREATE OR REPLACE PACKAGE telsale_policy_check_pkg IS -- Author : 王炜 -- Created : 2021/6/21 10:18:01 -- Purpose : 电销保单数据验证 /***************************************************************************/ --定义异常 --保单号不存在 POLICYNO_NOT_EXIST_EXCEPT_CODE CONSTANT INTEGER := -20000; POLICYNO_NOT_EXIST_EXCEPT_TEXT CONSTANT VARCHAR2(100) := '保单号不存在。'; --保单号已存在 POLICYNO_IS_EXIST_EXCEPT_CODE CONSTANT INTEGER := -20001; POLICYNO_IS_EXIST_EXCEPT_TEXT CONSTANT VARCHAR2(100) := '保单号重复。'; --经办人不存在 OPERATOE_CODE_NOT_EXIST_EXCEPT_CODE CONSTANT INTEGER := -20002; OPERATOE_CODE_NOT_EXIST_EXCEPT_TEXT CONSTANT VARCHAR2(100) := '经办人工号不存在。'; --录入人不存在 ENTRY_STAFF_CODE_NOT_EXIST_EXCEPT_CODE CONSTANT INTEGER := -20003; ENTRY_STAFF_CODE_NOT_EXIST_EXCEPT_TEXT CONSTANT VARCHAR2(100) := '录入人工号不存在。'; --经办人工号所在科室与保单不匹配 OPERATOE_CODE_NOT_MATCH_EXCEPT_CODE CONSTANT INTEGER := -20004; OPERATOE_CODE_NOT_MATCH_EXCEPT_TEXT CONSTANT VARCHAR2(100) := '经办人工号所在科室与保单归属不匹配。'; /***************************************************************************/ FUNCTION policy_check(a_policy_no VARCHAR2) RETURN BOOLEAN; FUNCTION staff_check(a_stuff_code VARCHAR2) RETURN BOOLEAN; PROCEDURE save_policy ( a_policy_no IN VARCHAR2, a_operator_code IN VARCHAR2, a_operator_name OUT VARCHAR2, a_operator_sectionoffice_code OUT VARCHAR2, a_operator_sectionoffice_name OUT VARCHAR2, a_operator_department_code OUT VARCHAR2, a_operator_department_name OUT VARCHAR2, a_entry_staff_code IN VARCHAR2, a_entry_staff_name OUT VARCHAR2, a_entry_staff_sectionoffice_code OUT VARCHAR2, a_entry_staff_sectionoffice_name OUT VARCHAR2, a_entry_staff_department_code OUT VARCHAR2, a_entry_staff_department_name OUT VARCHAR2 ); END telsale_policy_check_pkg; / CREATE OR REPLACE PACKAGE BODY telsale_policy_check_pkg IS /*********************************************************************************/ FUNCTION staff_check(a_stuff_code VARCHAR2) RETURN BOOLEAN IS l_count INTEGER; BEGIN SELECT COUNT(*) INTO l_count FROM idst0.rydm_t@xmcx1.cpicxm ry WHERE ry.staff_code = a_stuff_code; IF l_count = 0 THEN RETURN FALSE; END IF; RETURN TRUE; END; /*********************************************************************************/ FUNCTION policy_check(a_policy_no VARCHAR2) RETURN BOOLEAN IS l_count INTEGER; BEGIN SELECT COUNT(*) INTO l_count FROM idst0.auto_agreement_t@xmcx1.cpicxm a WHERE a.policy_no = a_policy_no; IF l_count = 0 THEN RETURN FALSE; END IF; RETURN TRUE; END; /*********************************************************************************/ PROCEDURE save_policy ( a_policy_no IN VARCHAR2, a_operator_code IN VARCHAR2, a_operator_name OUT VARCHAR2, a_operator_sectionoffice_code OUT VARCHAR2, a_operator_sectionoffice_name OUT VARCHAR2, a_operator_department_code OUT VARCHAR2, a_operator_department_name OUT VARCHAR2, a_entry_staff_code IN VARCHAR2, a_entry_staff_name OUT VARCHAR2, a_entry_staff_sectionoffice_code OUT VARCHAR2, a_entry_staff_sectionoffice_name OUT VARCHAR2, a_entry_staff_department_code OUT VARCHAR2, a_entry_staff_department_name OUT VARCHAR2 ) IS l_policy_sectionoffice_code VARCHAR2(6); l_policy_department_code VARCHAR2(6); BEGIN NULL; --判断保单号是否存在,以及保单号的科室部门和经办人是否相同 --验证保单号是否存在,获取保单归属科室和部门 BEGIN SELECT bd.section_office_code, bd.department_code INTO l_policy_sectionoffice_code, l_policy_department_code FROM idst0.auto_agreement_t@xmcx1.cpicxm bd WHERE bd.policy_no = a_policy_no; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(POLICYNO_NOT_EXIST_EXCEPT_CODE, POLICYNO_NOT_EXIST_EXCEPT_TEXT); END; --验证经办人是否存在 BEGIN SELECT ry.staff_name, ksh.section_office_code, ksh.section_office_name, bm.department_code, bm.department_name INTO a_operator_name, a_operator_sectionoffice_code, a_operator_sectionoffice_name, a_operator_department_code, a_operator_department_name FROM idst0.rydm_t@xmcx1.cpicxm ry, idst0.ks_t@xmcx1.cpicxm ksh, idst0.bm_t@xmcx1.cpicxm bm WHERE ry.section_office_code = ksh.section_office_code AND ry.department_code = bm.department_code AND ry.staff_code = a_operator_code; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(OPERATOE_CODE_NOT_EXIST_EXCEPT_CODE, OPERATOE_CODE_NOT_EXIST_EXCEPT_TEXT); END; --验证录入人是否存在 IF a_entry_staff_code IS NOT NULL THEN BEGIN SELECT ry.staff_name, ksh.section_office_code, ksh.section_office_name, bm.department_code, bm.department_name INTO a_entry_staff_name, a_entry_staff_sectionoffice_code, a_entry_staff_sectionoffice_name, a_entry_staff_department_code, a_entry_staff_department_name FROM idst0.rydm_t@xmcx1.cpicxm ry, idst0.ks_t@xmcx1.cpicxm ksh, idst0.bm_t@xmcx1.cpicxm bm WHERE ry.section_office_code = ksh.section_office_code AND ry.department_code = bm.department_code AND ry.staff_code = a_entry_staff_code; EXCEPTION WHEN NO_DATA_FOUND THEN raise_application_error(OPERATOE_CODE_NOT_EXIST_EXCEPT_CODE, OPERATOE_CODE_NOT_EXIST_EXCEPT_TEXT); END; END IF; --判断保单归属和经办人所在部门是否匹配,不匹配视为错误 IF l_policy_sectionoffice_code != a_operator_sectionoffice_code OR l_policy_department_code != a_operator_department_code THEN raise_application_error(ENTRY_STAFF_CODE_NOT_EXIST_EXCEPT_CODE, ENTRY_STAFF_CODE_NOT_EXIST_EXCEPT_TEXT); END IF; --没错误后,保存记录 BEGIN INSERT INTO telsale.电销保单信息表 (保单号, 经办人代码, 经办人名称, 经办人科室代码, 经办人科室名称, 经办人部门代码, 经办人部门名称, 操作员代码, 操作员名称, 操作员科室代码, 操作员科室名称, 操作员部门代码, 操作员部门名称, 操作日期) VALUES (a_policy_no, a_operator_code, a_operator_name, a_operator_sectionoffice_code, a_operator_sectionoffice_name, a_operator_department_code, a_operator_department_name, a_entry_staff_code, a_entry_staff_name, a_entry_staff_sectionoffice_code, a_entry_staff_sectionoffice_name, a_entry_staff_department_code, a_entry_staff_department_name, SYSDATE); EXCEPTION --保单号重复 WHEN DUP_VAL_ON_INDEX THEN raise_application_error(POLICYNO_IS_EXIST_EXCEPT_CODE, POLICYNO_IS_EXIST_EXCEPT_TEXT); END; END; BEGIN NULL; END telsale_policy_check_pkg; /