diff --git a/Modules/mip_helper_special_cases.pck b/Modules/mip_helper_special_cases.pck index 38ea9bd..1898b5e 100644 --- a/Modules/mip_helper_special_cases.pck +++ b/Modules/mip_helper_special_cases.pck @@ -55,7 +55,7 @@ CREATE OR REPLACE PACKAGE BODY mip_helper_special_cases IS IF p_rec.enty_code IN ('INSTALL', 'STD INSTALL') AND - (p_rec.required_ip_mbar IS NULL AND p_rec.required_ip_details IS NULL) THEN + (p_rec.mprn IS NULL AND p_rec.mprn_alt IS NULL) THEN mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks ,p_field_name => 'MPRN' ,p_error_message => 'Either MPRN or Additional Information must be completed.'); diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck index 02177eb..2fd26c7 100644 --- a/Modules/mip_quotation.pck +++ b/Modules/mip_quotation.pck @@ -42,37 +42,53 @@ CREATE OR REPLACE PACKAGE mip_quotation IS PROCEDURE make_quote_available(p_qute_id IN quotes.id%TYPE); /** Accept a quote %param p_qute_id id of the quote to be accepted + %param p_prty_id id of the person accepting the quote + %param p_owner_prty_id id of the person who owns the accepted quote (defaults to acceptor) %param p_description optional description to be recorded with the event %param p_event_date optional date for this event (defaults to now) */ - PROCEDURE accept_quote(p_qute_id IN quotes.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE); + 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 DEFAULT NULL + ,p_description quote_events.description%TYPE DEFAULT NULL + ,p_event_date IN DATE DEFAULT SYSDATE); /** Reject a quote %param p_qute_id id of the quote to be rejected + %param p_prty_id id of the person rejecting the quote + %param p_owner_prty_id id of the person who owns the rejected quote (defaults to rejector) %param p_description optional description to be recorded with the event %param p_event_date optional date for this event (defaults to now) */ - PROCEDURE reject_quote(p_qute_id IN quotes.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE); + PROCEDURE reject_quote(p_qute_id IN quotes.id%TYPE + ,p_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); /** Reject all quotes associated with enquiry %param p_enqu_id id of the enquiry for qhich all quotes are to be rejected + %param p_prty_id id of the person rejecting the quotes + %param p_owner_prty_id id of the person who owns the rejected quotes (defaults to rejector) %param p_description optional description to be recorded with the event %param p_event_date optional date for this event (defaults to now) */ - PROCEDURE reject_all_quotes(p_enqu_id IN enquiries.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE); + PROCEDURE reject_all_quotes(p_enqu_id IN enquiries.id%TYPE + ,p_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); /** Select a quote for detailed quotation %param p_qute_id id of the quote to be selected + %param p_prty_id id of the person selecting the quote + %param p_owner_prty_id id of the person who owns the selected quote (defaults to selector) %param p_description optional description to be recorded with the event %param p_event_date optional date for this event (defaults to now) */ - PROCEDURE select_quote(p_qute_id IN quotes.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE); + PROCEDURE select_quote(p_qute_id IN quotes.id%TYPE + ,p_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); /** Lapse a quote %param p_qute_id id of the quote to be selected %param p_description optional description to be recorded with the event @@ -87,8 +103,9 @@ END mip_quotation; / CREATE OR REPLACE PACKAGE BODY mip_quotation IS - PROCEDURE email_aq_generated(p_enqu_id IN enquiries.id%TYPE); + -- PROCEDURE email_aq_generated(p_enqu_id IN enquiries.id%TYPE); PROCEDURE email_quotes_available(p_enqu_id IN enquiries.id%TYPE); + PROCEDURE email_rfq_submitted(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); @@ -119,6 +136,20 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS SUBTYPE t_quote_row IS quotes%ROWTYPE; + PROCEDURE pl(p_in VARCHAR2) IS + l_fh utl_file.file_type; + BEGIN + dbms_application_info.set_module('MIP_QUOTATION' + ,p_in); + l_fh := utl_file.fopen(location => 'WEBMIP_BULK_LOAD' + ,filename => 'MIP_QUOTATION.txt' + ,open_mode => 'A'); + utl_file.put_line(l_fh + ,to_char(SYSDATE + ,'DD/MM/YYYY HH24:MI:SS') || ',' || p_in); + utl_file.fclose(l_fh); + END pl; + PROCEDURE add_quote_event(p_qute_id IN quotes.id%TYPE ,p_qust_code quote_statuses.code%TYPE ,p_description quote_events.description%TYPE DEFAULT NULL @@ -136,25 +167,71 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_description); END add_quote_event; - PROCEDURE accept_quote(p_qute_id IN quotes.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE) IS + PROCEDURE add_quote_role(p_qute_id IN quotes.id%TYPE + ,p_prty_id IN parties.id%TYPE + ,p_rt_code quote_roles.rt_code%TYPE + ,p_description quote_events.description%TYPE DEFAULT NULL + ,p_start_date DATE DEFAULT SYSDATE) IS + BEGIN + INSERT INTO quote_roles + (qute_id + ,prty_id + ,rt_code + ,start_date + ,description) + VALUES + (p_qute_id + ,p_prty_id + ,p_rt_code + ,p_start_date + ,p_description); + END add_quote_role; + + 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_description quote_events.description%TYPE DEFAULT NULL + ,p_event_date IN DATE DEFAULT SYSDATE) IS BEGIN add_quote_event(p_qute_id => p_qute_id ,p_qust_code => 'ACCEPTED' ,p_event_date => p_event_date ,p_description => p_description); + add_quote_role(p_qute_id => p_qute_id + ,p_prty_id => nvl(p_owner_prty_id + ,p_prty_id) + ,p_rt_code => 'Q ACC' + ,p_start_date => p_event_date); + + add_quote_role(p_qute_id => p_qute_id + ,p_prty_id => p_prty_id + ,p_rt_code => 'Q SUBACC' + ,p_start_date => p_event_date); END accept_quote; - PROCEDURE reject_quote(p_qute_id IN quotes.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE) IS + PROCEDURE reject_quote(p_qute_id IN quotes.id%TYPE + ,p_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 add_quote_event(p_qute_id => p_qute_id ,p_qust_code => 'REJECTED' ,p_event_date => p_event_date ,p_description => p_description); + + add_quote_role(p_qute_id => p_qute_id + ,p_prty_id => nvl(p_owner_prty_id + ,p_prty_id) + ,p_rt_code => 'Q REJ' + ,p_start_date => p_event_date); + + add_quote_role(p_qute_id => p_qute_id + ,p_prty_id => p_prty_id + ,p_rt_code => 'Q SUBREJ' + ,p_start_date => p_event_date); + END reject_quote; PROCEDURE lapse_quote(p_qute_id IN quotes.id%TYPE @@ -167,23 +244,30 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_description => p_description); END lapse_quote; - PROCEDURE reject_all_quotes(p_enqu_id IN enquiries.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE) IS + PROCEDURE reject_all_quotes(p_enqu_id IN enquiries.id%TYPE + ,p_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 FOR l_rec IN (SELECT id FROM quotes WHERE enqu_id = p_enqu_id) LOOP - add_quote_event(p_qute_id => l_rec.id - ,p_qust_code => 'REJECTED' - ,p_event_date => p_event_date - ,p_description => p_description); + + reject_quote(p_qute_id => l_rec.id + ,p_prty_id => p_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_event_date => p_event_date + ,p_description => p_description); + END LOOP; END reject_all_quotes; - PROCEDURE select_quote(p_qute_id IN quotes.id%TYPE - ,p_description quote_events.description%TYPE DEFAULT NULL - ,p_event_date IN DATE DEFAULT SYSDATE) IS + PROCEDURE select_quote(p_qute_id IN quotes.id%TYPE + ,p_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 add_quote_event(p_qute_id => p_qute_id ,p_qust_code => 'SELECTED' @@ -219,6 +303,22 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END LOOP; END lapse_quotes_job; + FUNCTION not_already_submitted(p_enqu_id IN enquiries.id%TYPE) + RETURN BOOLEAN IS + l_dummy NUMBER; + BEGIN + SELECT 1 + INTO l_dummy + FROM enquiry_events + WHERE enst_code = 'SUBMITTED' + AND enqu_id = p_enqu_id + AND rownum < 2; + RETURN FALSE; + EXCEPTION + WHEN no_data_found THEN + RETURN TRUE; + END not_already_submitted; + FUNCTION start_quote(p_enqu_id IN enquiries.id%TYPE ,p_manual_or_automatic IN VARCHAR2 DEFAULT gc_automatic_quote ,p_rfq_prty_id IN parties.id%TYPE @@ -285,6 +385,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE make_quote_available(p_qute_id IN quotes.id%TYPE) IS BEGIN + pl('make_quote_available'); INSERT INTO quote_events (event_date @@ -297,22 +398,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS 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 + pl('mark_enquiry_submitted'); + INSERT INTO enquiry_events (event_date ,enst_code @@ -321,6 +410,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS (SYSDATE ,'SUBMITTED' ,p_enqu_id); + + email_rfq_submitted(p_enqu_id); END mark_enquiry_submitted; PROCEDURE mark_enquiry_quoted(p_enqu_id IN enquiries.id%TYPE) IS @@ -334,6 +425,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,'QUOTED' ,p_enqu_id); + email_quotes_available(p_enqu_id); + END mark_enquiry_quoted; PROCEDURE mark_enquiry_invalid(p_enqu_id IN enquiries.id%TYPE) IS @@ -350,14 +443,17 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS FUNCTION get_system_configuration_value(p_parameter IN system_configuration.parameter%TYPE) RETURN system_configuration.VALUE%TYPE IS - l_recipient system_configuration.VALUE%TYPE; + l_value system_configuration.VALUE%TYPE; BEGIN SELECT VALUE - INTO l_recipient + INTO l_value FROM system_configuration WHERE parameter = p_parameter; - RETURN l_recipient; + RETURN l_value; + EXCEPTION + WHEN no_data_found THEN + RETURN 'SYSTEM_CONFIGURATION ERROR - PARAMETER ''' || p_parameter || ''' NOT FOUND'; END get_system_configuration_value; FUNCTION get_manual_quote_recipient RETURN system_configuration.VALUE%TYPE IS @@ -385,6 +481,13 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN get_system_configuration_value('SYSTEM_NAME'); END get_system_name; + FUNCTION get_customer_support_telephone + RETURN system_configuration.VALUE%TYPE IS + BEGIN + + RETURN get_system_configuration_value('TELEPHONE_CUSTOMER_SUPPORT'); + END get_customer_support_telephone; + FUNCTION get_enty_description(p_enqu_id IN enquiries.id%TYPE) RETURN enquiry_types.description%TYPE IS l_description enquiry_types.description%TYPE; @@ -413,19 +516,11 @@ 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 @@ -434,8 +529,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,length('') ,''); - al('This email has been produced automatically by the ' || - get_system_name || ' quotation system'); + al(' '); + al('THIS IS AN AUTOMATED EMAIL - PLEASE DO NOT REPLY AS EMAILS +RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); + al(' '); al(' '); END open_body; @@ -454,57 +551,61 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE produce_quote_summary(p_qute_id IN quotes.id%TYPE) IS l_quote_row t_quote_row; BEGIN + pl('produce_quote_summary'); l_quote_row := get_quote_row(p_qute_id); - al('Quote summary for Quote Reference: ' || p_qute_id); + al('Quote summary for Quote Reference Number: ' || p_qute_id); al('This quote is valid from ' || to_char(l_quote_row.valid_from ,'ddth Month YYYY') || ' to ' || to_char(l_quote_row.valid_until ,'ddth Month YYYY')); - FOR l_sum IN (SELECT * - FROM v_quote_details - WHERE quote_id = p_qute_id) LOOP - - IF l_sum.module_code IS NOT NULL THEN - al('Module code: ' || l_sum.module_code); - END IF; - IF l_sum.lead_time IS NOT NULL THEN - al('Lead time: ' || l_sum.lead_time || ' days'); - END IF; - IF l_sum.additional_items IS NOT NULL THEN - al('Additional items: ' || l_sum.additional_items); - END IF; - IF l_sum.bas_code IS NOT NULL THEN - al('Base code: ' || l_sum.bas_code); - END IF; - IF l_sum.hou_code IS NOT NULL THEN - al('Housing code: ' || l_sum.hou_code); - END IF; - IF l_sum.qmax IS NOT NULL THEN - al('Qmax: ' || l_sum.qmax); - END IF; - IF l_sum.qmin IS NOT NULL THEN - al('Qmin: ' || l_sum.qmin); - END IF; - IF l_sum.inlet_orientation IS NOT NULL THEN - al('Inlet orientation: ' || l_sum.inlet_orientation); - END IF; - IF l_sum.outlet_orientation IS NOT NULL THEN - al('Outlet orientation: ' || l_sum.outlet_orientation); - END IF; - IF l_sum.total_cost IS NOT NULL THEN - al('Total cost: £' || l_sum.total_cost); - END IF; - END LOOP; + IF l_quote_row.qute_type = 'AQ' THEN + FOR l_sum IN (SELECT * + FROM v_quote_details + WHERE quote_id = p_qute_id) LOOP + + IF l_sum.module_code IS NOT NULL THEN + al('Module code: ' || l_sum.module_code); + END IF; + IF l_sum.lead_time IS NOT NULL THEN + al('Lead time: ' || l_sum.lead_time || ' days'); + END IF; + IF l_sum.additional_items IS NOT NULL THEN + al('Additional items: ' || l_sum.additional_items); + END IF; + IF l_sum.bas_code IS NOT NULL THEN + al('Base code: ' || l_sum.bas_code); + END IF; + IF l_sum.hou_code IS NOT NULL THEN + al('Housing code: ' || l_sum.hou_code); + END IF; + IF l_sum.qmax IS NOT NULL THEN + al('Qmax: ' || l_sum.qmax); + END IF; + IF l_sum.qmin IS NOT NULL THEN + al('Qmin: ' || l_sum.qmin); + END IF; + IF l_sum.inlet_orientation IS NOT NULL THEN + al('Inlet orientation: ' || l_sum.inlet_orientation); + END IF; + IF l_sum.outlet_orientation IS NOT NULL THEN + al('Outlet orientation: ' || l_sum.outlet_orientation); + END IF; + IF l_sum.total_cost IS NOT NULL THEN + al('Total cost: £' || l_sum.total_cost); + END IF; + END LOOP; + ELSE + al('This quote was produced manually and we are unable to provide a summary, refer to the online quotation document for details.'); + END IF; + END produce_quote_summary; PROCEDURE close_body IS BEGIN - al(' '); - al('*** DO NOT REPLY TO THIS EMAIL ***'); dbms_lob.writeappend(g_email_html_body ,length('') ,''); @@ -512,6 +613,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE produce_reasoning_summary(p_enqu_id IN enquiries.id%TYPE) IS BEGIN + pl('produce_reasoning_summary'); al(' '); al(' '); al(get_system_name || @@ -526,7 +628,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END produce_reasoning_summary; - PROCEDURE email_aq_generated(p_enqu_id IN enquiries.id%TYPE) IS + /* PROCEDURE email_aq_generated(p_enqu_id IN enquiries.id%TYPE) IS BEGIN open_body; @@ -555,27 +657,32 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_subject => get_system_name || ': Notification of generation of automatic quotes for Enquiry reference: ' || p_enqu_id); - END email_aq_generated; + 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; + l_date_submitted DATE; BEGIN - + pl('email_quotes_available'); open_body; SELECT agent_comt_code ,agent_contact_value + ,event_date INTO l_agent_comt_code ,l_agent_contact_value + ,l_date_submitted FROM enquiries - WHERE enquiries.id = p_enqu_id; + ,enquiry_events + WHERE enquiries.id = p_enqu_id + 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'); @@ -590,51 +697,146 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS 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; + ': Confirmation of availability of quotation(s)'; + al('Confirmation of availability of quotation.'); + al(' '); + al('Thank you for using ' || get_system_name || + ' online. Your quotation(s) are now available.'); + al(' '); al('Enquiry refererence: ' || p_enqu_id || ' (' || get_enty_description(p_enqu_id) || ')'); + al('Request made on: ' || + to_char(l_date_submitted + ,'ddth Month YYYY HH24:MI:SS')); + al(' '); 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.'; + ': Confirmation of availability of quotation(s), Agent requires notification.'; al('Enquiry refererence: ' || p_enqu_id || ' (' || get_enty_description(p_enqu_id) || ')'); + al('Request made on: ' || + to_char(l_date_submitted + ,'ddth Month YYYY HH24:MI:SS')); + 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 || ')'); + END IF; + al(' '); + al('The following quotations are available:'); + + FOR l_qute IN (SELECT id + FROM quotes + ,v_quote_details v + ,v_current_quote_status s + WHERE enqu_id = p_enqu_id + AND v.quote_id = id + AND s.qute_id = id + AND s.qust_code = 'AV' + 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 email_quotes_available; + + PROCEDURE email_rfq_submitted(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_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; + l_date_submitted DATE; + BEGIN + pl('email_rfq_submitted'); + + open_body; + + SELECT agent_comt_code + ,agent_contact_value + ,event_date + INTO l_agent_comt_code + ,l_agent_contact_value + ,l_date_submitted + FROM enquiries + ,enquiry_events + WHERE enquiries.id = p_enqu_id + 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'); + + 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 || + ': Confirmation of Request for Quotation'; + al('Confirmation of Request for Quotation'); + al(' '); + al('Thank you for using ' || get_system_name || + ' online. Your request for quotation has been received.'); + al(' '); + al('Enquiry Refererence Number: ' || p_enqu_id || ' (' || + get_enty_description(p_enqu_id) || ')'); + al('Request made on: ' || + to_char(l_date_submitted + ,'ddth Month YYYY HH24:MI:SS')); + al(' '); + al('You should receive notification of your quotation(s) within 6 days.'); + al(' '); + al('Should notification of your quotation(s) not arrive after 6 days, then please phone us on ' || + get_customer_support_telephone || + '. Be prepared to quote the Enquiry Reference Number.'); + ELSE + l_email_recipient := get_automatic_quote_recipient; + l_email_subject := get_system_name || + ': Confirmation of Request for Quotation, Agent requires notification.'; + + al('Enquiry Refererence Number: ' || p_enqu_id || ' (' || + get_enty_description(p_enqu_id) || ')'); + al('Request made on: ' || + to_char(l_date_submitted + ,'ddth Month YYYY HH24:MI:SS')); 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; + + 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 email_rfq_submitted; 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; BEGIN + pl('email_request_for_mq'); SELECT * INTO l_quote_row @@ -643,13 +845,13 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS open_body; - al('This email has been produced in response to Enquiry refererence: ' || + al('This email has been produced in response to Enquiry Refererence Number: ' || p_enqu_id || ' (' || get_enty_description(p_enqu_id) || ')'); al(' '); al(l_system_name || ' was unable to produce an automatic quote for this Enquiry, therefore a ' || - 'Manual Quote is to be completed against Quote Reference: ' || + 'Manual Quote is to be completed against Quote Reference Number: ' || l_quote_row.id); al('This quote will be valid from ' || to_char(l_quote_row.valid_from @@ -657,7 +859,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS to_char(l_quote_row.valid_until ,'ddth Month YYYY')); al(' '); - al('Current Service Level Agreements dictate that a manual quote be provided with 6 days'); + al('Current Service Level Agreements dictate that a manual quote be provided within 6 days'); produce_reasoning_summary(p_enqu_id); @@ -667,7 +869,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,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: ' || + ': Request for a Manual Quote for Enquiry Reference Number: ' || p_enqu_id); END email_request_for_mq; @@ -675,6 +877,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE email_support(p_subject IN VARCHAR2 ,p_enqu_id IN enquiries.id%TYPE) IS BEGIN + pl('email_support'); + open_body; al('MIP_QUOTATION: Enquiry ' || p_enqu_id || ' (' || @@ -695,7 +899,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_body_html => g_email_html_body ,p_subject => get_system_name || ' : ' || p_subject || - ' : Enquiry reference: ' || + ' : Enquiry Reference Number: ' || p_enqu_id); END email_support; @@ -704,6 +908,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL) IS l_qute_id quotes.id%TYPE; BEGIN + pl('request_manual_quote'); l_qute_id := start_quote(p_enqu_id => p_enqu_id ,p_manual_or_automatic => gc_manual_quote @@ -717,8 +922,9 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE ready_for_quote(p_enqu_id IN enquiries.id%TYPE ,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks ,p_enquiry_is_ready OUT BOOLEAN) IS - l_mandatory_checks mip_mandatory.t_mandatory_checks; BEGIN + pl('ready_for_quote(1)'); + p_enquiry_is_ready := mip_enquiries_helper.check_mandatory(p_id => p_enqu_id ,p_mandatory_checks => p_mandatory_checks); END ready_for_quote; @@ -727,6 +933,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_mandatory_checks mip_mandatory.t_mandatory_checks; l_enquiry_is_ready BOOLEAN; BEGIN + pl('ready_for_quote(2)'); + ready_for_quote(p_enqu_id => p_enqu_id ,p_mandatory_checks => l_mandatory_checks ,p_enquiry_is_ready => l_enquiry_is_ready); @@ -740,6 +948,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_enquiry_is_ready BOOLEAN; l_idx INTEGER; BEGIN + pl('return_mandatory_messages'); ready_for_quote(p_enqu_id => p_enqu_id ,p_mandatory_checks => l_mandatory_checks @@ -780,6 +989,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN meter_size_codes.code%TYPE IS l_meter_size_code meter_size_codes.code%TYPE; BEGIN + pl('get_u_meter_size'); -- get the smallest meter code that will support the given Qmax SELECT code @@ -804,6 +1014,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN BOOLEAN IS l_dummy NUMBER; BEGIN + pl('valid_meter_size_upgrade'); + IF p_existing_meter_size_code = p_required_meter_size_code THEN RETURN TRUE; END IF; @@ -827,6 +1039,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_existing_meter_size_code meter_size_codes.code%TYPE; l_required_meter_size_code meter_size_codes.code%TYPE; BEGIN + pl('survey_required'); -- Low Pressure Rules -- Site survey required for: @@ -868,6 +1081,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_idx INTEGER; BEGIN + pl('tripartite_agreement_satisfied'); + l_valid := mip_tripartite.valid_enquiry(p_enqu_id => p_enqu_id ,p_tab_messages => l_tab_messages); @@ -895,6 +1110,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE manual_or_automatic_quote(p_enqu IN t_enqu ,p_manual_or_automatic_quote OUT t_manual_or_automatic_quote) IS BEGIN + pl('manual_or_automatic_quote'); p_manual_or_automatic_quote := gc_automatic_quote; IF p_enqu.enty_code IN ('OTHER', 'CHANGE CAPACITY') THEN @@ -998,6 +1214,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN t_rec_additional_costs IS l_rec_costs t_rec_additional_costs; BEGIN + pl('get_housing'); SELECT selling_price ,cost_price ,delivery_cost @@ -1035,6 +1252,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN t_rec_additional_costs IS l_rec_costs t_rec_additional_costs; BEGIN + pl('get_base'); SELECT selling_price ,cost_price ,delivery_cost @@ -1073,6 +1291,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN t_rec_additional_costs IS l_rec_costs t_rec_additional_costs; BEGIN + pl('get_aico'); SELECT lead_time ,selling_price ,cost_price @@ -1122,6 +1341,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN t_rec_additional_costs IS l_rec_costs t_rec_additional_costs; BEGIN + pl('get_laco'); SELECT selling_price ,cost_price ,delivery_cost @@ -1175,6 +1395,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_additional_costs t_rec_additional_costs; l_quote_document VARCHAR2(240); BEGIN + pl('produce_module_quotes'); cout_assert.istrue(p_enqu.enty_code IN ('INSTALL', 'STD INSTALL', 'EXCHANGE', 'CAPACITY CHANGE') ,'Attempted to produce an install or exchange quote for enquiry of type ' || @@ -1727,549 +1948,13 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END produce_module_quotes; - /*PROCEDURE produce_install_quotes(p_enqu IN t_enqu - ,p_rfq_prty_id IN parties.id%TYPE - ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL - ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS - l_produced_automatic_quote BOOLEAN; - l_this_is_automatic_quote BOOLEAN; - l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode); - l_qute_id quotes.id%TYPE; - l_additional_costs t_rec_additional_costs; - l_quote_document VARCHAR2(240); - BEGIN - cout_assert.istrue(p_enqu.enty_code IN ('INSTALL', 'STD INSTALL') - ,'Attempted to produce an install quote for enquiry of type ' || - p_enqu.enty_code); - - cout_assert.isnotnull(l_regi_code - ,'Attempted to produce an install quote for enquiry for a installation postcode (' || - p_enqu.install_postcode || ') without a region.'); - add_quote_reason(p_enqu.id - ,p_reason => 'Attempting an automatic installation quote for ' || - p_enqu.id || '.' || ' Required SVCP ' || - p_enqu.required_svcp_code || ', QMAX=' || - p_enqu.qmax || ', Outlet Pressure=' || - p_enqu.required_metering_pressure || '.' - ,p_internal_or_external => gc_internal_reason); - - FOR l_rec_module IN (SELECT modu.code AS modu_code - ,modu.selling_price AS modu_selling_price - ,modu.cost_price AS modu_cost_price - ,modu.delivery_cost AS modu_delivery_cost - ,modu.lead_time AS modu_lead_time - ,modu.hou_code AS hou_code - ,modu.inlet_orientation AS modu_inlet_orientation - ,modu.outlet_orientation AS modu_outlet_orientation - ,NULL AS hou_selling_price - ,NULL AS hou_cost_price - ,NULL AS hou_delivery_cost - ,modu.bas_code AS bas_code - ,NULL AS bas_selling_price - ,NULL AS bas_cost_price - ,NULL AS bas_delivery_cost - ,metr.code AS metr_code - ,metr.qnom - ,metr.qmax - ,metr.qmin - ,metr.selling_price AS metr_selling_price - ,metr.cost_price AS metr_cost_price - ,metr.delivery_cost AS metr_delivery_cost - ,metr.mety_code - ,NULL AS laco_mety_code - ,NULL AS laco_svcpt_code - ,NULL AS laco_mesc_code - ,NULL AS laco_selling_price - ,NULL AS laco_cost_price - ,NULL AS laco_delivery_cost - ,NULL AS amr_cost_id - ,NULL AS amr_selling_price - ,NULL AS amr_cost_price - ,NULL AS amr_delivery_cost - ,NULL AS amr_lead_time - ,NULL AS ems_cost_id - ,NULL AS ems_selling_price - ,NULL AS ems_cost_price - ,NULL AS ems_delivery_cost - ,NULL AS ems_lead_time - ,NULL AS bypass_cost_id - ,NULL AS bypass_selling_price - ,NULL AS bypass_cost_price - ,NULL AS bypass_delivery_cost - ,NULL AS bypass_lead_time - ,NULL AS lifting_gear_cost_id - ,NULL AS lifting_gear_selling_price - ,NULL AS lifting_gear_cost_price - ,NULL AS lifting_gear_delivery_cost - ,NULL AS lifting_gear_lead_time - FROM (SELECT modu.code - ,modu.metr_code - ,modu.hou_code - ,modu.bas_code - ,svcp_code - ,outlet_pressure - ,cnor_i.description AS inlet_orientation - ,cnor_o.description AS outlet_orientation - ,selling_price - ,cost_price - ,delivery_cost - ,lead_time - FROM modules modu - ,connection_orientations cnor_i - ,connection_orientations cnor_o - ,(SELECT modu_code - ,selling_price - ,cost_price - ,delivery_cost - FROM (SELECT row_number() over(PARTITION BY modu_code ORDER BY(decode(regi_code, l_regi_code, 1, 999))) AS accuracy - ,modu_code - ,selling_price - ,cost_price - ,delivery_cost - ,ROWID - FROM v_moco cost - WHERE SYSDATE BETWEEN - cost.effective_from AND - cost.effective_to - AND (regi_code = - l_regi_code OR - regi_code IS NULL)) - WHERE accuracy <= 1) cost - WHERE modu.code = cost.modu_code(+) - AND modu.inlet_cnor_code = cnor_i.code - AND modu.outlet_cnor_code = cnor_o.code) modu - ,(SELECT metr.code - ,metr.qmax - ,metr.qmin - ,metr.qnom - ,metr.mety_code - ,selling_price - ,cost_price - ,delivery_cost - FROM meters metr - ,(SELECT metr_code - ,selling_price - ,cost_price - ,delivery_cost - FROM (SELECT row_number() over(PARTITION BY metr_code ORDER BY(decode(regi_code, l_regi_code, 1, 999))) AS accuracy - ,metr_code - ,selling_price - ,cost_price - ,delivery_cost - ,ROWID - FROM v_meco cost - WHERE SYSDATE BETWEEN - cost.effective_from AND - cost.effective_to - AND (regi_code = - l_regi_code OR - regi_code IS NULL)) - WHERE accuracy <= 1) cost - WHERE metr.code = cost.metr_code(+)) metr - WHERE modu.svcp_code = p_enqu.required_svcp_code - AND modu.outlet_pressure = - p_enqu.required_metering_pressure - AND metr.code = modu.metr_code - AND metr.qmax >= p_enqu.qmax) LOOP - l_this_is_automatic_quote := TRUE; - add_quote_reason(p_enqu.id - ,p_reason => 'Considering module : ' || - l_rec_module.modu_code - ,p_internal_or_external => gc_internal_reason); - -- - -- check whether we have the required prices - -- if we do not, then we may need to produce a manual quote - -- - IF l_rec_module.modu_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for module ' || - l_rec_module.modu_code || CASE - l_regi_code WHEN NULL THEN '' ELSE ' for region code ' || l_regi_code END || '.' - ,p_internal_or_external => gc_internal_reason); - END IF; - IF l_rec_module.modu_lead_time IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find lead time for module ' || - l_rec_module.modu_code || '.' - ,p_internal_or_external => gc_internal_reason); - END IF; - - l_additional_costs := get_laco(p_enty_code => p_enqu.enty_code - ,p_regi_code => l_regi_code - ,p_mety_code => l_rec_module.mety_code - ,p_mesc_code => p_enqu.required_mesc_code - ,p_svcp_code => p_enqu.required_svcp_code); - l_rec_module.laco_svcpt_code := l_additional_costs.svcpt_code; - l_rec_module.laco_selling_price := l_additional_costs.selling_price; - l_rec_module.laco_cost_price := l_additional_costs.cost_price; - l_rec_module.laco_delivery_cost := l_additional_costs.delivery_cost; - IF l_rec_module.laco_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find Labour Cost (selling price) for this Enquiry Type Code: ' || - p_enqu.enty_code || - ', Meter Type Code:' || - l_rec_module.mety_code || - ', Meter Size Code:' || - p_enqu.required_mesc_code || - ', Service Pressure Code:' || - p_enqu.required_svcp_code || CASE - l_regi_code WHEN NULL THEN '' ELSE ' for region code ' || l_regi_code END || '.' - - ,p_internal_or_external => gc_internal_reason); - END IF; - - IF p_enqu.base_required = 'YES' THEN - IF l_rec_module.bas_code IS NOT NULL THEN - l_additional_costs := get_base(p_bas_code => l_rec_module.bas_code - ,p_regi_code => l_regi_code); - l_rec_module.bas_selling_price := l_additional_costs.selling_price; - l_rec_module.bas_cost_price := l_additional_costs.cost_price; - l_rec_module.bas_delivery_cost := l_additional_costs.delivery_cost; - IF l_rec_module.bas_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for base ' || - l_rec_module.bas_code || '.' - ,p_internal_or_external => gc_internal_reason); - END IF; - ELSE - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Module is not available with base.' - ,p_internal_or_external => gc_internal_reason); - END IF; - END IF; - - IF p_enqu.housing_required = 'YES' THEN - IF l_rec_module.hou_code IS NOT NULL THEN - l_additional_costs := get_housing(p_hou_code => l_rec_module.hou_code - ,p_regi_code => l_regi_code); - l_rec_module.hou_selling_price := l_additional_costs.selling_price; - l_rec_module.hou_cost_price := l_additional_costs.cost_price; - l_rec_module.hou_delivery_cost := l_additional_costs.delivery_cost; - IF l_rec_module.hou_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for housing ' || - l_rec_module.hou_code || '.' - ,p_internal_or_external => gc_internal_reason); - END IF; - ELSE - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Module is not available with housing.' - ,p_internal_or_external => gc_internal_reason); - END IF; - END IF; - - IF p_enqu.amr_required = 'YES' THEN - l_additional_costs := get_aico(p_adit_code => 'AMR' - ,p_regi_code => l_regi_code); - l_rec_module.amr_selling_price := l_additional_costs.selling_price; - l_rec_module.amr_cost_price := l_additional_costs.cost_price; - l_rec_module.amr_delivery_cost := l_additional_costs.delivery_cost; - l_rec_module.amr_lead_time := l_additional_costs.lead_time; - IF l_rec_module.amr_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for AMR.' - ,p_internal_or_external => gc_internal_reason); - END IF; - IF l_rec_module.amr_lead_time IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find lead time for AMR.' - ,p_internal_or_external => gc_internal_reason); - END IF; - END IF; - IF p_enqu.ems_required = 'YES' THEN - l_additional_costs := get_aico(p_adit_code => 'EMS' - ,p_regi_code => l_regi_code); - l_rec_module.ems_selling_price := l_additional_costs.selling_price; - l_rec_module.ems_cost_price := l_additional_costs.cost_price; - l_rec_module.ems_delivery_cost := l_additional_costs.delivery_cost; - l_rec_module.ems_lead_time := l_additional_costs.lead_time; - IF l_rec_module.ems_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for EMS.' - ,p_internal_or_external => gc_internal_reason); - END IF; - IF l_rec_module.ems_lead_time IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find lead time for EMS.' - ,p_internal_or_external => gc_internal_reason); - END IF; - END IF; - IF p_enqu.bypass_required = 'YES' THEN - l_additional_costs := get_aico(p_adit_code => 'BYPASS' - ,p_regi_code => l_regi_code); - l_rec_module.bypass_selling_price := l_additional_costs.selling_price; - l_rec_module.bypass_cost_price := l_additional_costs.cost_price; - l_rec_module.bypass_delivery_cost := l_additional_costs.delivery_cost; - l_rec_module.bypass_lead_time := l_additional_costs.lead_time; - IF l_rec_module.bypass_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for BYPASS.' - ,p_internal_or_external => gc_internal_reason); - END IF; - IF l_rec_module.bypass_lead_time IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find lead time for BYPASS.' - ,p_internal_or_external => gc_internal_reason); - END IF; - - END IF; - \* Always get costs for LIFTING GEAR *\ - - l_additional_costs := get_aico(p_adit_code => 'LIFTING GEAR' - ,p_regi_code => l_regi_code); - l_rec_module.lifting_gear_selling_price := l_additional_costs.selling_price; - l_rec_module.lifting_gear_cost_price := l_additional_costs.cost_price; - l_rec_module.lifting_gear_delivery_cost := l_additional_costs.delivery_cost; - l_rec_module.lifting_gear_lead_time := l_additional_costs.lead_time; - IF l_rec_module.lifting_gear_selling_price IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find selling price for LIFTING GEAR.' - ,p_internal_or_external => gc_internal_reason); - END IF; - IF l_rec_module.lifting_gear_lead_time IS NULL THEN - l_this_is_automatic_quote := FALSE; - add_quote_reason(p_enqu.id - ,p_reason => 'Unable to find lead time for LIFTING GEAR.' - ,p_internal_or_external => gc_internal_reason); - END IF; - - IF l_this_is_automatic_quote THEN - l_produced_automatic_quote := TRUE; - - add_quote_reason(p_enqu_id => p_enqu.id - ,p_reason => 'Producing an automatic quote.' - ,p_internal_or_external => gc_internal_reason); - - l_qute_id := start_quote(p_enqu_id => p_enqu.id - ,p_manual_or_automatic => gc_automatic_quote - ,p_rfq_prty_id => p_rfq_prty_id - ,p_owner_prty_id => p_owner_prty_id); - - INSERT INTO quote_items - (id - ,qute_id - ,enty_code - ,mety_code - ,svcpt_code - ,mesc_code - ,cost_price - ,selling_price - ,delivery_price - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,p_enqu.enty_code - ,l_rec_module.laco_mety_code - ,l_rec_module.laco_svcpt_code - ,l_rec_module.laco_mesc_code - ,l_rec_module.laco_cost_price - ,l_rec_module.laco_selling_price - ,l_rec_module.laco_delivery_cost - ,'LQI'); - - INSERT INTO quote_items - (id - ,qute_id - ,modu_code - ,qmax - ,qmin - ,inlet_orientation - ,outlet_orientation - ,cost_price - ,selling_price - ,delivery_price - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,l_rec_module.modu_code - ,l_rec_module.qmax - ,l_rec_module.qmin - ,l_rec_module.modu_inlet_orientation - ,l_rec_module.modu_outlet_orientation - ,l_rec_module.modu_cost_price - ,l_rec_module.modu_selling_price - ,l_rec_module.modu_delivery_cost - ,'MQI'); - - IF p_enqu.housing_required = 'YES' THEN - INSERT INTO quote_items - (id - ,qute_id - ,hou_code - ,cost_price - ,selling_price - ,delivery_price - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,l_rec_module.hou_code - ,l_rec_module.hou_cost_price - ,l_rec_module.hou_selling_price - ,l_rec_module.hou_delivery_cost - ,'HQI'); - END IF; - - IF p_enqu.base_required = 'YES' THEN - INSERT INTO quote_items - (id - ,qute_id - ,bas_code - ,cost_price - ,selling_price - ,delivery_price - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,l_rec_module.bas_code - ,l_rec_module.bas_cost_price - ,l_rec_module.bas_selling_price - ,l_rec_module.bas_delivery_cost - ,'BQI'); - END IF; - - IF p_enqu.amr_required = 'YES' THEN - INSERT INTO quote_items - (id - ,qute_id - ,adit_code - ,cost_price - ,selling_price - ,delivery_price - ,lead_time - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,'AMR' - ,l_rec_module.amr_cost_price - ,l_rec_module.amr_selling_price - ,l_rec_module.amr_delivery_cost - ,l_rec_module.amr_lead_time - ,'AQI'); - END IF; - - IF p_enqu.ems_required = 'YES' THEN - INSERT INTO quote_items - (id - ,qute_id - ,adit_code - ,cost_price - ,selling_price - ,delivery_price - ,lead_time - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,'EMS' - ,l_rec_module.ems_cost_price - ,l_rec_module.ems_selling_price - ,l_rec_module.ems_delivery_cost - ,l_rec_module.ems_lead_time - ,'AQI'); - END IF; - - IF p_enqu.bypass_required = 'YES' THEN - INSERT INTO quote_items - (id - ,qute_id - ,adit_code - ,cost_price - ,selling_price - ,delivery_price - ,lead_time - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,'BYPASS' - ,l_rec_module.bypass_cost_price - ,l_rec_module.bypass_selling_price - ,l_rec_module.bypass_delivery_cost - ,l_rec_module.bypass_lead_time - ,'AQI'); - END IF; - - \* Always include LIFTING GEAR *\ - - INSERT INTO quote_items - (id - ,qute_id - ,adit_code - ,cost_price - ,selling_price - ,delivery_price - ,lead_time - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,'LIFTING GEAR' - ,l_rec_module.lifting_gear_cost_price - ,l_rec_module.lifting_gear_selling_price - ,l_rec_module.lifting_gear_delivery_cost - ,l_rec_module.lifting_gear_lead_time - ,'AQI'); - - -- Generate the quote PDF - \*BEGIN*\ - l_quote_document := mip_quotation_document.generate_quote_pdf(p_quote_id => l_qute_id); - \* EXCEPTION - WHEN OTHERS THEN - cout_err.report_and_stop; - END; - *\ - add_quote_reason(p_enqu_id => p_enqu.id - ,p_reason => 'Produced Quote Document ' || - l_quote_document || '.' - ,p_internal_or_external => gc_internal_reason); - - make_quote_available(l_qute_id); - - END IF; -- automatic quote - - END LOOP; - - IF l_produced_automatic_quote THEN - p_manual_or_automatic_quote := gc_automatic_quote; - 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); - ELSE - p_manual_or_automatic_quote := gc_manual_quote; - add_quote_reason(p_enqu_id => p_enqu.id - ,p_reason => '-- Automatic quote failed - Manual quote required.' - ,p_internal_or_external => gc_internal_reason); - - END IF; - - END produce_install_quotes;*/ - PROCEDURE produce_install_quotes(p_enqu IN t_enqu ,p_rfq_prty_id IN parties.id%TYPE ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode); BEGIN + pl('produce_install_quotes'); cout_assert.istrue(p_enqu.enty_code IN ('STD INSTALL', 'INSTALL') ,'Attempted to produce an installation quote for enquiry of type ' || p_enqu.enty_code); @@ -2291,6 +1976,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode); BEGIN + pl('produce_exchange_quotes'); cout_assert.istrue(p_enqu.enty_code IN ('EXCHANGE') ,'Attempted to produce an exchange quote for enquiry of type ' || p_enqu.enty_code); @@ -2312,6 +1998,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode); BEGIN + pl('produce_change_capacity_quotes'); cout_assert.istrue(p_enqu.enty_code IN ('CHANGE CAPACITY') ,'Attempted to produce a change capacity quote for enquiry of type ' || p_enqu.enty_code); @@ -2338,6 +2025,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_additional_costs t_rec_additional_costs; l_quote_document VARCHAR2(240); BEGIN + pl('produce_labour_only_quotes'); cout_assert.istrue(p_enqu.enty_code IN ('REMOVE', 'STD REMOVE', 'ADVERSARIAL', 'OFMAT', 'ALTERATION') @@ -2431,7 +2119,6 @@ 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); ELSE p_manual_or_automatic_quote := gc_manual_quote; add_quote_reason(p_enqu_id => p_enqu.id @@ -2461,12 +2148,6 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_rfq_prty_id IN parties.id%TYPE ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS - l_produced_automatic_quote BOOLEAN; - l_this_is_automatic_quote BOOLEAN; - l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode); - l_qute_id quotes.id%TYPE; - l_additional_costs t_rec_additional_costs; - l_quote_document VARCHAR2(240); BEGIN cout_assert.istrue(p_enqu.enty_code IN ('OFMAT') ,'Attempted to produce an OFMAT quote for enquiry of type ' || @@ -2483,12 +2164,6 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_rfq_prty_id IN parties.id%TYPE ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS - l_produced_automatic_quote BOOLEAN; - l_this_is_automatic_quote BOOLEAN; - l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode); - l_qute_id quotes.id%TYPE; - l_additional_costs t_rec_additional_costs; - l_quote_document VARCHAR2(240); BEGIN cout_assert.istrue(p_enqu.enty_code IN ('ALTERATION') ,'Attempted to produce an ALTERATION quote for enquiry of type ' || @@ -2515,6 +2190,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_bypass_costs t_rec_additional_costs; l_quote_document VARCHAR2(240); BEGIN + pl('produce_addon_quotes'); + cout_assert.istrue(p_enqu.enty_code IN ('ADDON') ,'Attempted to produce an ADDON quote for enquiry of type ' || p_enqu.enty_code); @@ -2716,7 +2393,6 @@ 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); ELSE p_manual_or_automatic_quote := gc_manual_quote; add_quote_reason(p_enqu_id => p_enqu.id @@ -2732,6 +2408,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS BEGIN + pl('produce_automatic_quotes'); + cout_assert.istrue(p_manual_or_automatic_quote = gc_automatic_quote ,p_message => 'Attempted to produce automatic quote for enquiry marked as manual only'); @@ -2772,11 +2450,14 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_manual_or_automatic_quote t_manual_or_automatic_quote; l_enqu t_enqu; BEGIN - + pl('produce_quotes'); cout_assert.istrue(ready_for_quote(p_enqu_id) ,'Not all mandatory fields for Enquiry ID=' || p_enqu_id || ' have been completed'); + cout_assert.istrue(not_already_submitted(p_enqu_id) + ,'This enquiry has already been submitted for quotation'); + mark_enquiry_submitted(p_enqu_id); SELECT * @@ -2799,24 +2480,23 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,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); + mark_enquiry_quoted(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 - mark_enquiry_quoted(p_enqu_id); - END IF; -- tripartite agreement - /* EXCEPTION + pl('exit without error'); + EXCEPTION WHEN OTHERS THEN - cout_err.report_and_stop;*/ + pl(SQLERRM); + RAISE; END produce_quotes; BEGIN diff --git a/Modules/mip_regions.pck b/Modules/mip_regions.pck index 66ea7c4..75896a1 100644 --- a/Modules/mip_regions.pck +++ b/Modules/mip_regions.pck @@ -81,22 +81,23 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS FUNCTION valid_postcode_format(p_postcode IN VARCHAR2) RETURN BOOLEAN IS l_return BOOLEAN := TRUE; l_postcode_format VARCHAR2(8); + l_postcode VARCHAR2(80) := upper(p_postcode); BEGIN - IF p_postcode = 'GIR 0AA' THEN + IF l_postcode = 'GIR 0AA' THEN l_return := TRUE; - ELSIF length(p_postcode) NOT IN (6 + ELSIF length(l_postcode) NOT IN (6 ,7 ,8) THEN l_return := FALSE; ELSE - l_postcode_format := reformat_postcode_string(p_postcode); + l_postcode_format := reformat_postcode_string(l_postcode); IF l_postcode_format IS NULL THEN l_return := FALSE; ELSE IF instr('QVX' - ,substr(p_postcode + ,substr(l_postcode ,1 ,1)) > 0 THEN l_return := FALSE; @@ -104,7 +105,7 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS ,2 ,1) = 'A' AND instr('IJZ' - ,substr(p_postcode + ,substr(l_postcode ,2 ,1)) > 0 THEN l_return := FALSE; @@ -112,7 +113,7 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS ,3 ,1) = 'A' AND instr('ABCDEFGHJKSTUW' - ,substr(p_postcode + ,substr(l_postcode ,3 ,1)) = 0 THEN l_return := FALSE; @@ -120,7 +121,7 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS ,4 ,1) = 'A' AND instr('ABCDEFGHJKSTUW' - ,substr(p_postcode + ,substr(l_postcode ,4 ,1)) = 0 THEN l_return := FALSE; @@ -132,7 +133,7 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS ,l_idx ,1) = 'A' AND instr('CIKMOV' - ,substr(p_postcode + ,substr(l_postcode ,l_idx ,1)) > 0 THEN l_return := FALSE; @@ -153,6 +154,7 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS FUNCTION get_region_for_postcode(p_postcode IN VARCHAR2) RETURN postcodes.regi_code%TYPE IS l_regi_code postcodes.regi_code%TYPE; + l_postcode VARCHAR2(80) := upper(p_postcode); BEGIN SELECT regi_code INTO l_regi_code @@ -160,14 +162,14 @@ CREATE OR REPLACE PACKAGE BODY mip_regions IS ,outcode ,incode ,decode(outcode || ' ' || incode - ,p_postcode + ,l_postcode ,1 ,999) AS accuracy FROM postcodes t - WHERE (outcode || ' ' || incode = p_postcode) - OR (outcode = substr(p_postcode + WHERE (outcode || ' ' || incode = l_postcode) + OR (outcode = substr(l_postcode ,1 - ,instr(p_postcode + ,instr(l_postcode ,' ') - 1) AND incode IS NULL) ORDER BY 4) WHERE rownum < 2; diff --git a/Modules/mip_virus_check.pck b/Modules/mip_virus_check.pck new file mode 100644 index 0000000..05c2307 --- /dev/null +++ b/Modules/mip_virus_check.pck @@ -0,0 +1,77 @@ +CREATE OR REPLACE PACKAGE mip_virus_check IS + + -- Author : HARDYA + -- Created : 23/01/2008 09:55:52 + -- Purpose : Virus checking package + PROCEDURE write_file(p_name IN wwv_flow_files.NAME%TYPE + ,p_location IN VARCHAR2 DEFAULT 'WEBMIP_VIRUS' + ,p_fs_name IN VARCHAR2); +END mip_virus_check; +/ +CREATE OR REPLACE PACKAGE BODY mip_virus_check IS + + PROCEDURE write_file(p_name IN wwv_flow_files.NAME%TYPE + ,p_location IN VARCHAR2 DEFAULT 'WEBMIP_VIRUS' + ,p_fs_name IN VARCHAR2) IS + l_lob_loc BLOB; + l_buffer RAW(32767); + l_buffer_size BINARY_INTEGER; + l_amount BINARY_INTEGER; + l_offset NUMBER(38) := 1; + l_chunksize INTEGER; + l_out_file utl_file.file_type; + + BEGIN + + SELECT blob_content + INTO l_lob_loc + FROM wwv_flow_files + WHERE NAME = p_name; + + l_chunksize := dbms_lob.getchunksize(l_lob_loc); + + IF (l_chunksize < 32767) THEN + l_buffer_size := l_chunksize; + ELSE + l_buffer_size := 32767; + END IF; + + l_amount := l_buffer_size; + + dbms_lob.OPEN(l_lob_loc + ,dbms_lob.lob_readonly); + + l_out_file := utl_file.fopen(location => p_location + ,filename => p_fs_name + ,open_mode => 'wb' + ,max_linesize => 32767); + + WHILE l_amount >= l_buffer_size LOOP + + dbms_lob.READ(lob_loc => l_lob_loc + ,amount => l_amount + ,offset => l_offset + ,buffer => l_buffer); + + l_offset := l_offset + l_amount; + + utl_file.put_raw(file => l_out_file + ,buffer => l_buffer + ,autoflush => TRUE); + + --utl_file.fflush(file => l_out_file); + + END LOOP; + + utl_file.fflush(file => l_out_file); + + utl_file.fclose(l_out_file); + + dbms_lob.CLOSE(l_lob_loc); + END write_file; + +BEGIN + -- Initialization + NULL; +END mip_virus_check; +/ diff --git a/Schema/mipDirectories.sql b/Schema/mipDirectories.sql index c6c4906..133c131 100644 --- a/Schema/mipDirectories.sql +++ b/Schema/mipDirectories.sql @@ -1,3 +1,4 @@ --- Create directory create or replace directory WEBMIP_BULK_LOAD as 'c:\webmip\bulk_load'; +create or replace directory WEBMIP_VIRUS + as 'c:\webmip\virus';