Seed/enst.ctl - add INVALID status

Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls - add rule O-M5
Documentation/pldoc - regenerated
Modules/mip_helper_special_cases.pck - make reference to Tripartite rule O-M5 (handled by mip_quotation.pck and mip_tripartite.pck
Schema - removed DATA_ITEM_ROLES_IMPORT, added views of enquiries and quote statuses

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3354 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-01-22 17:59:56 +00:00
parent 374ba0aee9
commit 7311d92835
61 changed files with 9184 additions and 111 deletions

View File

@@ -22,5 +22,6 @@ exec gen_mandatory
@@mip_dirlist.jsp
@@get_quote_items.fnc
@@mip_bulk_Load.pck
@@mip_tripartite.pck
@@compile.sql
exit

View File

@@ -64,6 +64,9 @@ CREATE OR REPLACE PACKAGE BODY mip_helper_special_cases IS
,p_error_message => 'Either MPRN or Additional Information must be completed.');
END IF;
-- OM-5
-- Tripartite Agreement and AMR -- this is a specific example of the Tripartite and addons
-- This is handled through the mip_tripartite.addon functionality
END table_enquiries;

View File

@@ -87,7 +87,12 @@ END mip_quotation;
/
CREATE OR REPLACE PACKAGE BODY mip_quotation IS
SUBTYPE t_reason IS VARCHAR2(240);
PROCEDURE email_aq_generated(p_enqu_id IN enquiries.id%TYPE);
PROCEDURE email_quotes_available(p_enqu_id IN enquiries.id%TYPE);
PROCEDURE email_request_for_mq(p_enqu_id IN enquiries.id%TYPE);
PROCEDURE email_support(p_subject IN VARCHAR2
,p_enqu_id IN enquiries.id%TYPE);
SUBTYPE t_internal_or_external IS VARCHAR2(8);
gc_internal_reason CONSTANT t_internal_or_external := 'INTERNAL';
@@ -280,6 +285,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
PROCEDURE make_quote_available(p_qute_id IN quotes.id%TYPE) IS
BEGIN
INSERT INTO quote_events
(event_date
,qust_code
@@ -288,8 +294,60 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
(SYSDATE
,'AV' -- Available
,p_qute_id);
END make_quote_available;
PROCEDURE make_manual_quote_available(p_qute_id IN quotes.id%TYPE) IS
l_enqu_id enquiries.id%TYPE;
BEGIN
make_quote_available(p_qute_id);
SELECT enqu_id
INTO l_enqu_id
FROM quotes
WHERE id = p_qute_id;
email_quotes_available(l_enqu_id);
END make_manual_quote_available;
PROCEDURE mark_enquiry_submitted(p_enqu_id IN enquiries.id%TYPE) IS
BEGIN
INSERT INTO enquiry_events
(event_date
,enst_code
,enqu_id)
VALUES
(SYSDATE
,'SUBMITTED'
,p_enqu_id);
END mark_enquiry_submitted;
PROCEDURE mark_enquiry_quoted(p_enqu_id IN enquiries.id%TYPE) IS
BEGIN
INSERT INTO enquiry_events
(event_date
,enst_code
,enqu_id)
VALUES
(SYSDATE
,'QUOTED'
,p_enqu_id);
END mark_enquiry_quoted;
PROCEDURE mark_enquiry_invalid(p_enqu_id IN enquiries.id%TYPE) IS
BEGIN
INSERT INTO enquiry_events
(event_date
,enst_code
,enqu_id)
VALUES
(SYSDATE
,'INVALID'
,p_enqu_id);
END mark_enquiry_invalid;
FUNCTION get_system_configuration_value(p_parameter IN system_configuration.parameter%TYPE)
RETURN system_configuration.VALUE%TYPE IS
l_recipient system_configuration.VALUE%TYPE;
@@ -315,6 +373,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
RETURN get_system_configuration_value('EMAIL_ADDRESS_AUTOMATIC_QUOTE');
END get_automatic_quote_recipient;
FUNCTION get_support_recipient RETURN system_configuration.VALUE%TYPE IS
BEGIN
RETURN get_system_configuration_value('EMAIL_ADDRESS_SUPPORT');
END get_support_recipient;
FUNCTION get_system_name RETURN system_configuration.VALUE%TYPE IS
BEGIN
@@ -349,11 +413,19 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
PROCEDURE open_body IS
BEGIN
/* IF dbms_lob.ISOPEN(lob_loc => g_email_plain_body) <> 0 THEN
dbms_lob.freetemporary(lob_loc => g_email_plain_body);
END IF;*/
dbms_lob.createtemporary(lob_loc => g_email_plain_body
,cache => TRUE);
dbms_lob.OPEN(lob_loc => g_email_plain_body
,open_mode => dbms_lob.lob_readwrite);
/* IF dbms_lob.ISOPEN(lob_loc => g_email_html_body) <> 0 THEN
dbms_lob.freetemporary(lob_loc => g_email_html_body);
END IF;*/
dbms_lob.createtemporary(lob_loc => g_email_html_body
,cache => TRUE);
dbms_lob.OPEN(lob_loc => g_email_html_body
@@ -485,6 +557,80 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
p_enqu_id);
END email_aq_generated;
PROCEDURE email_quotes_available(p_enqu_id IN enquiries.id%TYPE) IS
l_agent_comt_code enquiries.agent_comt_code%TYPE;
l_agent_contact_value enquiries.agent_contact_value%TYPE;
l_enqu_id enquiries.id%TYPE;
l_email_recipient system_configuration.VALUE%TYPE;
l_email_subject VARCHAR2(80);
l_agent_first_name parties.first_name%TYPE;
l_agent_last_name parties.last_name%TYPE;
l_agent_prty_id parties.id%TYPE;
BEGIN
open_body;
SELECT agent_comt_code
,agent_contact_value
INTO l_agent_comt_code
,l_agent_contact_value
FROM enquiries
WHERE enquiries.id = p_enqu_id;
l_agent_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_enqu_id
,p_rolecode => 'ENQ OWN');
SELECT first_name
,last_name
INTO l_agent_first_name
,l_agent_last_name
FROM parties
WHERE id = l_agent_prty_id;
IF l_agent_comt_code = 'EMAIL' THEN
l_email_recipient := l_agent_contact_value;
l_email_subject := get_system_name ||
': Notification of availability of automatic quotes for Enquiry reference: ' ||
p_enqu_id;
al('Enquiry refererence: ' || p_enqu_id || ' (' ||
get_enty_description(p_enqu_id) || ')');
ELSE
l_email_recipient := get_automatic_quote_recipient;
l_email_subject := get_system_name ||
': Notification of availability of automatic quotes for Enquiry reference: ' ||
p_enqu_id || ', Agent requires notification.';
al('Enquiry refererence: ' || p_enqu_id || ' (' ||
get_enty_description(p_enqu_id) || ')');
al(' ');
al('The Agent, ' || l_agent_first_name || ' ' || l_agent_last_name ||
' has requested that they be contacted via ' || l_agent_comt_code || '(' ||
l_agent_contact_value || ')');
al(' ');
al('The following quotations are available:');
FOR l_qute IN (SELECT id
FROM quotes
,v_quote_details v
WHERE enqu_id = p_enqu_id
AND v.quote_id = id
ORDER BY total_cost) LOOP
produce_quote_summary(l_qute.id);
al(' ');
END LOOP;
close_body;
mip_email.send_email_clob(p_recipient => l_email_recipient
,p_body => g_email_plain_body
,p_body_html => g_email_html_body
,p_subject => l_email_subject);
END IF;
END email_quotes_available;
PROCEDURE email_request_for_mq(p_enqu_id IN enquiries.id%TYPE) IS
l_system_name system_configuration.VALUE%TYPE := get_system_name;
l_quote_row quotes%ROWTYPE;
@@ -526,6 +672,33 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END email_request_for_mq;
PROCEDURE email_support(p_subject IN VARCHAR2
,p_enqu_id IN enquiries.id%TYPE) IS
BEGIN
open_body;
al('MIP_QUOTATION: Enquiry ' || p_enqu_id || ' (' ||
get_enty_description(p_enqu_id) || ')' ||
' - processing error occurred');
FOR l_qure IN (SELECT reason
FROM quote_reasoning
WHERE enqu_id = p_enqu_id
ORDER BY id) LOOP
al(l_qure.reason);
END LOOP;
close_body;
mip_email.send_email_clob(p_recipient => get_support_recipient
,p_body => g_email_plain_body
,p_body_html => g_email_html_body
,p_subject => get_system_name || ' : ' ||
p_subject ||
' : Enquiry reference: ' ||
p_enqu_id);
END email_support;
PROCEDURE request_manual_quote(p_enqu_id IN enquiries.id%TYPE
,p_rfq_prty_id IN parties.id%TYPE
,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL) IS
@@ -565,20 +738,24 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
l_mandatory_messages VARCHAR2(4000);
l_mandatory_checks mip_mandatory.t_mandatory_checks;
l_enquiry_is_ready BOOLEAN;
l_idx INTEGER;
BEGIN
ready_for_quote(p_enqu_id => p_enqu_id
,p_mandatory_checks => l_mandatory_checks
,p_enquiry_is_ready => l_enquiry_is_ready);
FOR l_idx IN l_mandatory_checks.LAST .. l_mandatory_checks.LAST LOOP
l_idx := l_mandatory_checks.FIRST;
LOOP
EXIT WHEN l_idx IS NULL;
l_mandatory_messages := l_mandatory_checks(l_idx)
.field_name || ':' ||
l_mandatory_checks(l_idx).error_message;
l_idx := l_mandatory_checks.NEXT(l_idx);
END LOOP;
RETURN nvl(l_mandatory_messages
,'All mandatory fields have been completed');
RETURN l_mandatory_messages;
END return_mandatory_messages;
PROCEDURE add_quote_reason(p_enqu_id IN enquiries.id%TYPE
@@ -684,6 +861,37 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
END IF; -- svcpt_code = 'LP'
END survey_required;
FUNCTION tripartite_agreement_satisfied(p_enqu_id IN enquiries.id%TYPE)
RETURN BOOLEAN IS
l_tab_messages mip_tripartite.t_tab_messages;
l_valid BOOLEAN;
l_idx INTEGER;
BEGIN
l_valid := mip_tripartite.valid_enquiry(p_enqu_id => p_enqu_id
,p_tab_messages => l_tab_messages);
-- processing an enquiry that has not passed the tripartite agreement
-- infers a processing error
IF NOT l_valid THEN
l_idx := l_tab_messages.FIRST;
LOOP
EXIT WHEN l_idx IS NULL;
add_quote_reason(p_enqu_id => p_enqu_id
,p_reason => l_tab_messages(l_idx));
l_idx := l_tab_messages.NEXT(l_idx);
END LOOP;
mark_enquiry_invalid(p_enqu_id);
email_support(p_subject => 'MIP_QUOTATION: Tripartite failure with Enquiry ' ||
p_enqu_id
,p_enqu_id => p_enqu_id);
END IF;
RETURN l_valid;
END tripartite_agreement_satisfied;
PROCEDURE manual_or_automatic_quote(p_enqu IN t_enqu
,p_manual_or_automatic_quote OUT t_manual_or_automatic_quote) IS
BEGIN
@@ -729,7 +937,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,'Booster or compressor is present downstream of the meter module.');
END IF;
IF p_enqu.annual_quantity > 732 THEN
IF p_enqu.annual_quantity > 732 * 1000 THEN
p_manual_or_automatic_quote := gc_manual_quote;
add_quote_reason(p_enqu.id
,'Required Annual Quantity is in excess of 732MWh.');
@@ -1508,7 +1716,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => '-- Produced an automatic quote.'
,p_internal_or_external => gc_internal_reason);
-- email_aq_generated(p_enqu.id);
--email_aq_generated(p_enqu.id);
ELSE
p_manual_or_automatic_quote := gc_manual_quote;
add_quote_reason(p_enqu_id => p_enqu.id
@@ -2569,31 +2777,42 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,'Not all mandatory fields for Enquiry ID=' ||
p_enqu_id || ' have been completed');
mark_enquiry_submitted(p_enqu_id);
SELECT *
INTO l_enqu
FROM enquiries
WHERE id = p_enqu_id;
manual_or_automatic_quote(p_enqu => l_enqu
,p_manual_or_automatic_quote => l_manual_or_automatic_quote);
IF l_manual_or_automatic_quote = gc_manual_quote THEN
request_manual_quote(p_enqu_id => l_enqu.id
,p_rfq_prty_id => p_rfq_prty_id
,p_owner_prty_id => p_owner_prty_id);
ELSE
produce_automatic_quotes(p_enqu => l_enqu
,p_rfq_prty_id => p_rfq_prty_id
,p_owner_prty_id => p_owner_prty_id
,p_manual_or_automatic_quote => l_manual_or_automatic_quote);
IF tripartite_agreement_satisfied(p_enqu_id) THEN
manual_or_automatic_quote(p_enqu => l_enqu
,p_manual_or_automatic_quote => l_manual_or_automatic_quote);
IF l_manual_or_automatic_quote = gc_manual_quote THEN
request_manual_quote(p_enqu_id => l_enqu.id
,p_rfq_prty_id => p_rfq_prty_id
,p_owner_prty_id => p_owner_prty_id);
END IF;
ELSE
produce_automatic_quotes(p_enqu => l_enqu
,p_rfq_prty_id => p_rfq_prty_id
,p_owner_prty_id => p_owner_prty_id
,p_manual_or_automatic_quote => l_manual_or_automatic_quote);
IF l_manual_or_automatic_quote = gc_automatic_quote THEN
email_aq_generated(p_enqu_id);
email_quotes_available(p_enqu_id);
ELSE
request_manual_quote(p_enqu_id => l_enqu.id
,p_rfq_prty_id => p_rfq_prty_id
,p_owner_prty_id => p_owner_prty_id);
END IF;
--
END IF; -- manual or automatic quote
--
END IF; -- manual or automatic quote
mark_enquiry_quoted(p_enqu_id);
END IF; -- tripartite agreement
/* EXCEPTION
WHEN OTHERS THEN

245
Modules/mip_tripartite.pck Normal file
View File

@@ -0,0 +1,245 @@
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 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;
END mip_tripartite;
/
CREATE OR REPLACE PACKAGE BODY mip_tripartite IS
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
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;
EXCEPTION
WHEN no_data_found THEN
NULL;
END;
RETURN(CASE l_rec_found WHEN 0 THEN FALSE ELSE TRUE END);
END tripartite_region;
FUNCTION tripartite_member(p_supp_prty_id IN parties.id%TYPE)
RETURN BOOLEAN IS
l_rec_found NUMBER DEFAULT 0;
BEGIN
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;
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 => '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_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);
IF l_amr_required = 'YES'
AND NOT addon_allowed(p_adit_code => 'AMR'
,p_regi_code => l_regi_code) THEN
l_valid := FALSE;
al('Tripartite agreement prevents AMR being requested.'
,p_tab_messages);
END IF;
IF l_ems_required = 'YES'
AND NOT addon_allowed(p_adit_code => 'EMS'
,p_regi_code => l_regi_code) THEN
l_valid := FALSE;
al('Tripartite agreement prevents EMS being requested.'
,p_tab_messages);
END IF;
IF l_bypass_required = 'YES'
AND NOT addon_allowed(p_adit_code => 'BYPASS'
,p_regi_code => l_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 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;
/