DatabaseItemToFunctionalSpecificationReference.xls - renamed METY_CODE to EXISTING_METY_CODE, included DISPLAY_SEQUENCE to be used in the generation of emails, etc.
Minor internal changes to operation of cout_assert.pck and cout_err.pck. mip_quotation.pck - made validation routines open to external processes. Added enquiry entry details to manual quotes. Schema - Removed data_items table and amended data_item_roles to support display_sequence requirements. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3407 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
@@ -23,6 +23,22 @@ CREATE OR REPLACE PACKAGE mip_quotation IS
|
||||
,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks
|
||||
,p_enquiry_is_ready OUT BOOLEAN);
|
||||
|
||||
/** Validate an enquiry row of date for mandatory fields
|
||||
Store the results for later retrieval (must be same transaction)
|
||||
|
||||
%param p_rec enquiry data to be validated
|
||||
*/
|
||||
PROCEDURE validate(p_rec IN mip_enquiries_helper.t_rec_enquiries);
|
||||
|
||||
/** Retrieve the results of a mandatory field validation for the given field
|
||||
Must be performed in the same transaction as the validate
|
||||
|
||||
%param p_field_name enquiry field who validation message is required
|
||||
%return validation error message or NULL if validation was successful
|
||||
*/
|
||||
FUNCTION validation_result(p_enqu_id IN enquiries.id%TYPE
|
||||
,p_field_name IN VARCHAR2) RETURN VARCHAR2;
|
||||
|
||||
/** Generate quotes in response to a 'request for quote' against an enquiry
|
||||
|
||||
%param p_enqu_id the id of the enquiry to be checked
|
||||
@@ -99,6 +115,7 @@ CREATE OR REPLACE PACKAGE mip_quotation IS
|
||||
,p_event_date IN DATE DEFAULT SYSDATE);
|
||||
|
||||
PROCEDURE lapse_quotes_job;
|
||||
|
||||
END mip_quotation;
|
||||
/
|
||||
CREATE OR REPLACE PACKAGE BODY mip_quotation IS
|
||||
@@ -124,7 +141,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
|
||||
|
||||
g_email_plain_body CLOB;
|
||||
g_email_html_body CLOB;
|
||||
gc_newline CONSTANT CHAR(1) DEFAULT chr(13);
|
||||
gc_newline CONSTANT CHAR(2) DEFAULT chr(10) || chr(13);
|
||||
|
||||
TYPE t_rec_additional_costs IS RECORD(
|
||||
adit_code additional_items.code%TYPE
|
||||
@@ -189,7 +206,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
|
||||
|
||||
PROCEDURE accept_quote(p_qute_id IN quotes.id%TYPE
|
||||
,p_prty_id IN parties.id%TYPE
|
||||
,p_owner_prty_id IN parties.id%TYPE
|
||||
,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL
|
||||
,p_description quote_events.description%TYPE DEFAULT NULL
|
||||
,p_event_date IN DATE DEFAULT SYSDATE) IS
|
||||
BEGIN
|
||||
@@ -618,6 +635,70 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
,'</body></html>');
|
||||
END close_body;
|
||||
|
||||
PROCEDURE produce_enquiry_entry_details(p_enqu_id IN enquiries.id%TYPE) IS
|
||||
l_enty_code enquiries.enty_code%TYPE;
|
||||
|
||||
FUNCTION return_value(p_enqu_id IN enquiries.id%TYPE
|
||||
,p_field_name IN VARCHAR2) RETURN VARCHAR2 IS
|
||||
l_sql VARCHAR2(240);
|
||||
l_cursor_id INTEGER;
|
||||
l_rows INTEGER;
|
||||
l_return VARCHAR2(80);
|
||||
BEGIN
|
||||
|
||||
l_cursor_id := dbms_sql.open_cursor;
|
||||
l_sql := 'select ' || p_field_name ||
|
||||
' from enquiries where id = :id';
|
||||
|
||||
dbms_sql.parse(l_cursor_id
|
||||
,l_sql
|
||||
,dbms_sql.native);
|
||||
|
||||
dbms_sql.bind_variable(l_cursor_id
|
||||
,':id'
|
||||
,p_enqu_id);
|
||||
|
||||
dbms_sql.define_column(l_cursor_id
|
||||
,1
|
||||
,l_return
|
||||
,80);
|
||||
|
||||
l_rows := dbms_sql.execute_and_fetch(l_cursor_id);
|
||||
|
||||
dbms_sql.column_value(l_cursor_id
|
||||
,1
|
||||
,l_return);
|
||||
|
||||
dbms_sql.close_cursor(l_cursor_id);
|
||||
|
||||
RETURN l_return;
|
||||
|
||||
END return_value;
|
||||
|
||||
BEGIN
|
||||
pl('produce_enquiry_entry_details');
|
||||
al(' ');
|
||||
al(' ');
|
||||
al(get_system_name ||
|
||||
' recorded the following details against this enquiry:');
|
||||
|
||||
SELECT enty_code
|
||||
INTO l_enty_code
|
||||
FROM enquiries
|
||||
WHERE id = p_enqu_id;
|
||||
|
||||
FOR l_rec IN (SELECT dir.field_name
|
||||
,dir.description
|
||||
FROM data_item_roles dir
|
||||
WHERE dir.enty_code = l_enty_code
|
||||
ORDER BY dir.display_sequence) LOOP
|
||||
|
||||
al(l_rec.description || ': ' ||
|
||||
return_value(p_enqu_id => p_enqu_id
|
||||
,p_field_name => l_rec.field_name));
|
||||
END LOOP;
|
||||
END produce_enquiry_entry_details;
|
||||
|
||||
PROCEDURE produce_reasoning_summary(p_enqu_id IN enquiries.id%TYPE) IS
|
||||
BEGIN
|
||||
pl('produce_reasoning_summary');
|
||||
@@ -751,10 +832,15 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
|
||||
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);
|
||||
BEGIN
|
||||
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);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('mip_email.send_email_clob returned ' || SQLERRM);
|
||||
END;
|
||||
|
||||
END email_quotes_available;
|
||||
|
||||
@@ -762,7 +848,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
l_agent_comt_code enquiries.agent_comt_code%TYPE;
|
||||
l_agent_contact_value enquiries.agent_contact_value%TYPE;
|
||||
l_email_recipient system_configuration.VALUE%TYPE;
|
||||
l_email_subject VARCHAR2(80);
|
||||
l_email_subject VARCHAR2(240);
|
||||
l_agent_first_name parties.first_name%TYPE;
|
||||
l_agent_last_name parties.last_name%TYPE;
|
||||
l_agent_prty_id parties.id%TYPE;
|
||||
@@ -784,15 +870,26 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
AND enquiry_events.enqu_id = enquiries.id
|
||||
AND enquiry_events.enst_code = 'SUBMITTED';
|
||||
|
||||
l_agent_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_enqu_id
|
||||
,p_rolecode => 'ENQ OWN');
|
||||
BEGIN
|
||||
l_agent_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_enqu_id
|
||||
,p_rolecode => 'ENQ OWN');
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('mip_enquiry.get_enquiry_role returned ' || SQLERRM);
|
||||
RAISE;
|
||||
END;
|
||||
|
||||
SELECT first_name
|
||||
,last_name
|
||||
INTO l_agent_first_name
|
||||
,l_agent_last_name
|
||||
FROM parties
|
||||
WHERE id = l_agent_prty_id;
|
||||
BEGIN
|
||||
SELECT first_name
|
||||
,last_name
|
||||
INTO l_agent_first_name
|
||||
,l_agent_last_name
|
||||
FROM parties
|
||||
WHERE id = l_agent_prty_id;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('Error finding agent - prty_id=' || l_agent_prty_id);
|
||||
END;
|
||||
|
||||
IF l_agent_comt_code = 'EMAIL' THEN
|
||||
l_email_recipient := l_agent_contact_value;
|
||||
@@ -833,10 +930,16 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
|
||||
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);
|
||||
BEGIN
|
||||
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);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('mip_email.send_email_clob returned ' || SQLERRM);
|
||||
RAISE;
|
||||
END;
|
||||
END email_rfq_submitted;
|
||||
|
||||
PROCEDURE email_request_for_mq(p_enqu_id IN enquiries.id%TYPE) IS
|
||||
@@ -868,16 +971,27 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
al(' ');
|
||||
al('Current Service Level Agreements dictate that a manual quote be provided within 6 days');
|
||||
|
||||
al('Data Entered:');
|
||||
|
||||
al('Enquiry type: ' || get_enty_description(p_enqu_id));
|
||||
|
||||
produce_enquiry_entry_details(p_enqu_id);
|
||||
|
||||
produce_reasoning_summary(p_enqu_id);
|
||||
|
||||
close_body;
|
||||
|
||||
mip_email.send_email_clob(p_recipient => get_manual_quote_recipient
|
||||
,p_body => g_email_plain_body
|
||||
,p_body_html => g_email_html_body
|
||||
,p_subject => l_system_name ||
|
||||
': Request for a Manual Quote for Enquiry Reference Number: ' ||
|
||||
p_enqu_id);
|
||||
BEGIN
|
||||
mip_email.send_email_clob(p_recipient => get_manual_quote_recipient
|
||||
,p_body => g_email_plain_body
|
||||
,p_body_html => g_email_html_body
|
||||
,p_subject => l_system_name ||
|
||||
': Request for a Manual Quote for Enquiry Reference Number: ' ||
|
||||
p_enqu_id);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('mip_email.send_email_clob returned ' || SQLERRM);
|
||||
END;
|
||||
|
||||
END email_request_for_mq;
|
||||
|
||||
@@ -901,13 +1015,18 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
|
||||
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 Number: ' ||
|
||||
p_enqu_id);
|
||||
BEGIN
|
||||
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 Number: ' ||
|
||||
p_enqu_id);
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('mip_email.send_email_clob returned ' || SQLERRM);
|
||||
END;
|
||||
END email_support;
|
||||
|
||||
PROCEDURE request_manual_quote(p_enqu_id IN enquiries.id%TYPE
|
||||
@@ -930,7 +1049,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks
|
||||
,p_enquiry_is_ready OUT BOOLEAN) IS
|
||||
BEGIN
|
||||
pl('ready_for_quote(1)');
|
||||
pl('ready_for_quote(1) - enqu_id=' || p_enqu_id);
|
||||
|
||||
p_enquiry_is_ready := mip_enquiries_helper.check_mandatory(p_id => p_enqu_id
|
||||
,p_mandatory_checks => p_mandatory_checks);
|
||||
@@ -940,7 +1059,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
l_mandatory_checks mip_mandatory.t_mandatory_checks;
|
||||
l_enquiry_is_ready BOOLEAN;
|
||||
BEGIN
|
||||
pl('ready_for_quote(2)');
|
||||
pl('ready_for_quote(2) - enqu_id=' || p_enqu_id);
|
||||
|
||||
ready_for_quote(p_enqu_id => p_enqu_id
|
||||
,p_mandatory_checks => l_mandatory_checks
|
||||
@@ -948,6 +1067,61 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
RETURN l_enquiry_is_ready;
|
||||
END ready_for_quote;
|
||||
|
||||
PROCEDURE validate(p_rec IN mip_enquiries_helper.t_rec_enquiries) IS
|
||||
l_mandatory_checks mip_mandatory.t_mandatory_checks;
|
||||
l_idx NUMBER;
|
||||
BEGIN
|
||||
pl('validate enqu_id=' || p_rec.id || ', enty_code=' ||
|
||||
p_rec.enty_code);
|
||||
DELETE FROM validation_results
|
||||
WHERE enqu_id = p_rec.id;
|
||||
IF NOT
|
||||
mip_enquiries_helper.check_mandatory(p_rec => p_rec
|
||||
,p_mandatory_checks => l_mandatory_checks) THEN
|
||||
l_idx := l_mandatory_checks.FIRST;
|
||||
LOOP
|
||||
EXIT WHEN l_idx IS NULL;
|
||||
INSERT INTO validation_results
|
||||
(enqu_id
|
||||
,field_name
|
||||
,error_message)
|
||||
VALUES
|
||||
(p_rec.id
|
||||
,l_mandatory_checks(l_idx).field_name
|
||||
,l_mandatory_checks(l_idx).error_message);
|
||||
l_idx := l_mandatory_checks.NEXT(l_idx);
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
pl('validate:' || SQLERRM);
|
||||
RAISE;
|
||||
END validate;
|
||||
|
||||
FUNCTION validation_result(p_enqu_id IN enquiries.id%TYPE
|
||||
,p_field_name IN VARCHAR2) RETURN VARCHAR2 IS
|
||||
l_error_message gtt_mandatory_checks.error_message%TYPE;
|
||||
BEGIN
|
||||
pl('validation_result enqu_id=' || p_enqu_id || ', field_name=' ||
|
||||
p_field_name);
|
||||
|
||||
SELECT error_message
|
||||
INTO l_error_message
|
||||
FROM validation_results
|
||||
WHERE field_name = upper(p_field_name)
|
||||
AND enqu_id = p_enqu_id;
|
||||
pl('returning ' || l_error_message);
|
||||
RETURN l_error_message;
|
||||
EXCEPTION
|
||||
WHEN no_data_found THEN
|
||||
pl('Nothing found');
|
||||
RETURN NULL;
|
||||
WHEN OTHERS THEN
|
||||
pl('validation_result:' || SQLERRM);
|
||||
RAISE;
|
||||
END validation_result;
|
||||
|
||||
FUNCTION return_mandatory_messages(p_enqu_id IN enquiries.id%TYPE)
|
||||
RETURN VARCHAR2 IS
|
||||
l_mandatory_messages VARCHAR2(4000);
|
||||
@@ -1052,17 +1226,19 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
-- Site survey required for:
|
||||
-- Relocation
|
||||
-- Exchange where upgrade is greater than 1 'U' size
|
||||
SELECT svcpt_code
|
||||
INTO l_svcpt_code
|
||||
FROM service_pressures
|
||||
WHERE code = p_enqu.required_svcp_code;
|
||||
IF l_svcpt_code = 'LP' THEN
|
||||
IF p_enqu.enty_code = 'ALTERATION' THEN
|
||||
p_manual_or_automatic_quote := gc_manual_quote;
|
||||
add_quote_reason(p_enqu.id
|
||||
,'Site Survey is required for alteration (relocation or reposition) of an existing meter.');
|
||||
END IF; -- RELOCATE
|
||||
IF p_enqu.enty_code IN ('EXCHANGE', 'STD EXCHANGE') THEN
|
||||
|
||||
IF p_enqu.enty_code = 'ALTERATION' THEN
|
||||
p_manual_or_automatic_quote := gc_manual_quote;
|
||||
add_quote_reason(p_enqu.id
|
||||
,'Site Survey is required for alteration (relocation or reposition) of an existing meter.');
|
||||
END IF; -- RELOCATE
|
||||
|
||||
IF p_enqu.enty_code IN ('EXCHANGE', 'STD EXCHANGE') THEN
|
||||
-- SELECT svcpt_code
|
||||
-- INTO l_svcpt_code
|
||||
-- FROM service_pressures
|
||||
-- WHERE code = p_enqu.required_svcp_code;
|
||||
-- IF l_svcpt_code = 'LP' THEN
|
||||
l_existing_meter_size_code := p_enqu.existing_mesc_code;
|
||||
l_required_meter_size_code := p_enqu.required_mesc_code;
|
||||
IF l_required_meter_size_code IS NULL THEN
|
||||
@@ -1077,8 +1253,9 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
l_existing_meter_size_code || ' to ' ||
|
||||
l_required_meter_size_code || '.');
|
||||
END IF;
|
||||
END IF; -- EXCHANGE
|
||||
END IF; -- svcpt_code = 'LP'
|
||||
-- END IF; -- svcpt_code = 'LP'
|
||||
END IF; -- EXCHANGE
|
||||
|
||||
END survey_required;
|
||||
|
||||
FUNCTION tripartite_agreement_satisfied(p_enqu_id IN enquiries.id%TYPE)
|
||||
@@ -2458,6 +2635,10 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
l_enqu t_enqu;
|
||||
BEGIN
|
||||
pl('produce_quotes');
|
||||
IF NOT ready_for_quote(p_enqu_id) THEN
|
||||
pl('Not all mandatory fields for Enquiry ID=' || p_enqu_id ||
|
||||
' have been completed');
|
||||
END IF;
|
||||
cout_assert.istrue(ready_for_quote(p_enqu_id)
|
||||
,'Not all mandatory fields for Enquiry ID=' ||
|
||||
p_enqu_id || ' have been completed');
|
||||
@@ -2508,6 +2689,6 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.');
|
||||
|
||||
BEGIN
|
||||
-- Initialization
|
||||
NULL;
|
||||
pl('mip_quotation');
|
||||
END mip_quotation;
|
||||
/
|
||||
|
||||
Reference in New Issue
Block a user