CREATE OR REPLACE PACKAGE mip_tripartite IS -- Author : HARDYA -- Created : 22/01/2008 11:02:06 -- Purpose : Handle Tripartite queries TYPE t_tab_messages IS TABLE OF VARCHAR(240) INDEX BY BINARY_INTEGER; /** Is the given postcode within a Tripartite region? %param p_postcode the postcode to be checked %return TRUE if within a Tripartite region */ FUNCTION tripartite_region(p_postcode IN VARCHAR2) RETURN BOOLEAN; /** Is the given supplier (party) a Tripartite member? %param p_prty_id the prty_id of the supplier to be checked %return TRUE if a Tripartite member */ FUNCTION tripartite_member(p_supp_prty_id IN parties.id%TYPE) RETURN BOOLEAN; /** Is the given supplier (party) allowed to submit a particular enquiry type for the given region? %param p_supp_prty_id the id of the supplier to be checked %param p_enty_code the enquiry type to be checked %param p_regi_code the region to be checked against %return TRUE if the enquiry is allowed */ FUNCTION enquiry_allowed(p_supp_prty_id IN parties.id%TYPE ,p_enty_code IN enquiry_types.code%TYPE ,p_regi_code IN regions.code%TYPE) RETURN BOOLEAN; /** Is the given enquiry allowed under Tripartite arrangements? %param p_enqu_id the id of the enquiry to be checked %return TRUE if the enquiry is allowed */ FUNCTION enquiry_allowed(p_enqu_id IN enquiries.id%TYPE) RETURN BOOLEAN; /** Is the given enquiry allowed to request the addons under Tripartite arrangements? %param p_enqu_id the id of the enquiry to be checked %return TRUE if the enquiry is allowed */ FUNCTION addons_allowed(p_enqu_id IN enquiries.id%TYPE ,p_tab_messages IN OUT t_tab_messages) RETURN BOOLEAN; /** Is the given addon allowed to non-Tripartite members %param p_addit_code the addon to be checked %param p_regi_code the region to be checked against %return TRUE if the addon is allowed */ FUNCTION addon_allowed(p_adit_code IN additional_items.code%TYPE ,p_regi_code IN regions.code%TYPE) RETURN BOOLEAN; /** Is the given enquiry valid with respect to the Tripartite arrangements? %param p_enqu_id the id of the enquiry to be checked %param p_tab_messages reasons for the enquiry not being valid %return TRUE if the enquiry is valid */ FUNCTION valid_enquiry(p_enqu_id IN enquiries.id%TYPE ,p_tab_messages OUT t_tab_messages) RETURN BOOLEAN; /** Is the given enquiry valid with respect to the Tripartite arrangements? %param p_rec a record containing details of the enquiry to be checked %param p_tab_messages reasons for the enquiry not being valid %return TRUE if the enquiry is valid */ FUNCTION valid_enquiry(p_rec IN mip_enquiries_helper.t_rec_enquiries ,p_tab_messages OUT t_tab_messages) RETURN BOOLEAN; END mip_tripartite; / CREATE OR REPLACE PACKAGE BODY mip_tripartite IS PROCEDURE pl(p_in VARCHAR2 ,p_line IN NUMBER DEFAULT NULL) IS BEGIN NULL; /* $IF mip_debug_constants.debugging OR mip_debug_constants.tripartite $THEN*/ mip_debug.pl(p_unit => $$PLSQL_UNIT ,p_line => p_line ,p_in => p_in); /* $END*/ END pl; PROCEDURE al(p_in IN VARCHAR2 ,p_tab_messages IN OUT t_tab_messages) IS BEGIN p_tab_messages(p_tab_messages.COUNT + 1) := p_in; END al; FUNCTION tripartite_region(p_postcode IN VARCHAR2) RETURN BOOLEAN IS l_regi_code regions.code%TYPE; l_rec_found NUMBER DEFAULT 0; BEGIN pl('tripartite_region:entry:' || p_postcode ,$$PLSQL_LINE); cout_assert.istrue(mip_regions.valid_postcode_format(p_postcode => p_postcode) ,'Invalid Postcode format'); l_regi_code := mip_regions.get_region_for_postcode(p_postcode => p_postcode); BEGIN SELECT 1 INTO l_rec_found FROM regi_enqu_exclusions reee WHERE reee.regi_code = l_regi_code AND rownum < 2; EXCEPTION WHEN no_data_found THEN NULL; END; pl('tripartite_region:exit:' || CASE l_rec_found WHEN 0 THEN 'FALSE' ELSE 'TRUE' END ,$$PLSQL_LINE); RETURN(CASE l_rec_found WHEN 0 THEN FALSE ELSE TRUE END); EXCEPTION WHEN OTHERS THEN pl('tripartite_region:EXCEPTION:' || SQLERRM ,$$PLSQL_LINE); RAISE; END tripartite_region; FUNCTION tripartite_member(p_supp_prty_id IN parties.id%TYPE) RETURN BOOLEAN IS l_rec_found NUMBER DEFAULT 0; BEGIN pl('tripartite_member:entry:' || p_supp_prty_id ,$$PLSQL_LINE); BEGIN SELECT 1 INTO l_rec_found FROM parties WHERE id = p_supp_prty_id AND tripartite_member = 'YES'; EXCEPTION WHEN no_data_found THEN NULL; END; pl('tripartite_member:exit:' || CASE l_rec_found WHEN 0 THEN 'FALSE' ELSE 'TRUE' END ,$$PLSQL_LINE); RETURN(CASE l_rec_found WHEN 0 THEN FALSE ELSE TRUE END); END tripartite_member; FUNCTION enquiry_allowed(p_supp_prty_id IN parties.id%TYPE ,p_enty_code enquiry_types.code%TYPE ,p_regi_code IN regions.code%TYPE) RETURN BOOLEAN IS l_rec_found NUMBER DEFAULT 0; BEGIN IF NOT tripartite_member(p_supp_prty_id) THEN BEGIN SELECT 1 INTO l_rec_found FROM regi_enqu_exclusions WHERE regi_code = p_regi_code AND enty_code = p_enty_code; EXCEPTION WHEN no_data_found THEN NULL; END; END IF; RETURN(CASE l_rec_found WHEN 0 THEN TRUE ELSE FALSE END); END enquiry_allowed; FUNCTION enquiry_allowed(p_enqu_id IN enquiries.id%TYPE) RETURN BOOLEAN IS l_regi_code regions.code%TYPE; l_postcode enquiries.install_postcode%TYPE; l_supp_prty_id parties.id%TYPE; l_enty_code enquiry_types.code%TYPE; BEGIN SELECT install_postcode ,enty_code INTO l_postcode ,l_enty_code FROM enquiries WHERE id = p_enqu_id; l_regi_code := mip_regions.get_region_for_postcode(p_postcode => l_postcode); l_supp_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_enqu_id ,p_rolecode => 'ENQ SUPP'); RETURN enquiry_allowed(p_supp_prty_id => l_supp_prty_id ,p_enty_code => l_enty_code ,p_regi_code => l_regi_code); END enquiry_allowed; FUNCTION addon_allowed(p_adit_code IN additional_items.code%TYPE ,p_regi_code IN regions.code%TYPE) RETURN BOOLEAN IS l_rec_found NUMBER DEFAULT 0; BEGIN BEGIN SELECT 1 INTO l_rec_found FROM regi_enqu_exclusions WHERE regi_code = p_regi_code AND adit_code = p_adit_code; EXCEPTION WHEN no_data_found THEN NULL; END; RETURN(CASE l_rec_found WHEN 0 THEN TRUE ELSE FALSE END); END addon_allowed; FUNCTION addons_allowed(p_amr_required IN enquiries.amr_required%TYPE ,p_ems_required IN enquiries.ems_required%TYPE ,p_bypass_required IN enquiries.bypass_required%TYPE ,p_regi_code IN regions.code%TYPE ,p_tab_messages IN OUT t_tab_messages) RETURN BOOLEAN IS l_valid BOOLEAN DEFAULT TRUE; BEGIN IF p_amr_required = 'YES' AND NOT addon_allowed(p_adit_code => 'AMR' ,p_regi_code => p_regi_code) THEN l_valid := FALSE; al('Tripartite Agreement prevents AMR being requested. ' ,p_tab_messages); END IF; IF p_ems_required = 'YES' AND NOT addon_allowed(p_adit_code => 'EMS' ,p_regi_code => p_regi_code) THEN l_valid := FALSE; al('Tripartite Agreement prevents EMS being requested. ' ,p_tab_messages); END IF; IF p_bypass_required = 'YES' AND NOT addon_allowed(p_adit_code => 'BYPASS' ,p_regi_code => p_regi_code) THEN l_valid := FALSE; al('Tripartite Agreement prevents Bypass being requested. ' ,p_tab_messages); END IF; RETURN l_valid; END addons_allowed; FUNCTION addons_allowed(p_enqu_id IN enquiries.id%TYPE ,p_tab_messages IN OUT t_tab_messages) RETURN BOOLEAN IS l_amr_required enquiries.amr_required%TYPE; l_ems_required enquiries.ems_required%TYPE; l_bypass_required enquiries.bypass_required%TYPE; l_postcode enquiries.install_postcode%TYPE; l_regi_code regions.code%TYPE; l_valid BOOLEAN DEFAULT TRUE; BEGIN SELECT enqu.amr_required ,enqu.ems_required ,enqu.bypass_required ,enqu.install_postcode INTO l_amr_required ,l_ems_required ,l_bypass_required ,l_postcode FROM enquiries enqu WHERE id = p_enqu_id; l_regi_code := mip_regions.get_region_for_postcode(p_postcode => l_postcode); l_valid := addons_allowed(p_amr_required => l_amr_required ,p_ems_required => l_ems_required ,p_bypass_required => l_bypass_required ,p_regi_code => l_regi_code ,p_tab_messages => p_tab_messages); RETURN l_valid; END addons_allowed; FUNCTION valid_enquiry(p_rec IN mip_enquiries_helper.t_rec_enquiries ,p_tab_messages OUT t_tab_messages) RETURN BOOLEAN IS l_tab_messages t_tab_messages; l_valid BOOLEAN DEFAULT TRUE; l_regi_code regions.code%TYPE; l_supp_prty_id parties.id%TYPE; l_contact_text regions.contact_text%TYPE; BEGIN l_regi_code := mip_regions.get_region_for_postcode(p_postcode => p_rec.install_postcode); l_supp_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_rec.id ,p_rolecode => 'SUPP'); IF NOT enquiry_allowed(p_supp_prty_id => l_supp_prty_id ,p_enty_code => p_rec.enty_code ,p_regi_code => l_regi_code) THEN SELECT regions.contact_text INTO l_contact_text FROM regions WHERE code = l_regi_code; al('Unable to quote for the specified postcode due to Tripartite Agreement. Please contact ' || l_contact_text || ' metering services. ' ,l_tab_messages); l_valid := FALSE; ELSE l_valid := addons_allowed(p_amr_required => p_rec.amr_required ,p_ems_required => p_rec.ems_required ,p_bypass_required => p_rec.bypass_required ,p_regi_code => l_regi_code ,p_tab_messages => l_tab_messages); END IF; p_tab_messages := l_tab_messages; RETURN l_valid; END valid_enquiry; FUNCTION valid_enquiry(p_enqu_id IN enquiries.id%TYPE ,p_tab_messages OUT t_tab_messages) RETURN BOOLEAN IS l_tab_messages t_tab_messages; l_valid BOOLEAN DEFAULT TRUE; BEGIN IF NOT enquiry_allowed(p_enqu_id => p_enqu_id) THEN al('Tripartite agreement prevents this enquiry being processed.' ,l_tab_messages); l_valid := FALSE; ELSE l_valid := addons_allowed(p_enqu_id => p_enqu_id ,p_tab_messages => l_tab_messages); END IF; p_tab_messages := l_tab_messages; RETURN l_valid; END valid_enquiry; BEGIN -- Initialization NULL; END mip_tripartite; /