diff --git a/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls b/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls index 846e429..af6d447 100644 Binary files a/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls and b/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls differ diff --git a/Modules/Modules.sql b/Modules/Modules.sql index 4a5bcda..be7340b 100644 --- a/Modules/Modules.sql +++ b/Modules/Modules.sql @@ -1,6 +1,7 @@ set scan off set define off +@@mip_helper_special_cases.pck @@gen_mandatory.prc exec gen_mandatory diff --git a/Modules/gen_mandatory.prc b/Modules/gen_mandatory.prc index 76053b9..ee23190 100644 --- a/Modules/gen_mandatory.prc +++ b/Modules/gen_mandatory.prc @@ -22,9 +22,9 @@ BEGIN ,table_name ,description) (SELECT DISTINCT field_name - ,table_name + ,'ENQUIRIES' as table_name ,description - FROM data_item_roles_import + FROM ext_dataitem_roles WHERE field_name IS NOT NULL); FOR l_enty IN (SELECT code @@ -51,7 +51,7 @@ BEGIN add_sql(l_sql ,'SELECT ''' || l_enty.code || ''''); add_sql(l_sql - ,' ,field_name'); + ,' ,''ENQUIRIES'' as field_name'); add_sql(l_sql ,' ,table_name'); add_sql(l_sql @@ -61,7 +61,7 @@ BEGIN add_sql(l_sql ,' ,diri.description'); add_sql(l_sql - ,' FROM data_item_roles_import diri'); + ,' FROM ext_dataitem_roles diri'); add_sql(l_sql ,' WHERE field_name IS NOT NULL AND substr(diri.' || REPLACE(l_enty.code @@ -303,6 +303,12 @@ BEGIN ,' '); END IF; END LOOP; + + add_sql(l_sql + ,' '); + + add_sql(l_sql, + ' MIP_HELPER_SPECIAL_CASES.table_'||l_tables.table_name||'(p_rec => l_rec, p_mandatory_checks=>l_mandatory_checks);'); add_sql(l_sql ,' '); diff --git a/Modules/mip_helper_special_cases.pck b/Modules/mip_helper_special_cases.pck new file mode 100644 index 0000000..b310c32 --- /dev/null +++ b/Modules/mip_helper_special_cases.pck @@ -0,0 +1,74 @@ +CREATE OR REPLACE PACKAGE mip_helper_special_cases IS + + -- Author : HARDYA + -- Created : 21/01/2008 11:40:25 + -- Purpose : helper package to support special cases not provided through mip_'tablename'_helper. + + PROCEDURE table_enquiries(p_rec IN enquiries%ROWTYPE + ,p_mandatory_checks IN OUT mip_mandatory.t_mandatory_checks); + +END mip_helper_special_cases; +/ +CREATE OR REPLACE PACKAGE BODY mip_helper_special_cases IS + + PROCEDURE table_enquiries(p_rec IN enquiries%ROWTYPE + ,p_mandatory_checks IN OUT mip_mandatory.t_mandatory_checks) IS + BEGIN + -- OM-1 + IF p_rec.install_building IS NULL + AND p_rec.install_sub_building IS NULL THEN + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'INSTALL_BUILDING' + ,p_error_message => 'At least one of Building or Sub-Building must be completed.'); + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'INSTALL_SUB_BUILDING' + ,p_error_message => 'At least one of Building or Sub-Building must be completed.'); + END IF; + + -- OM-2 + IF p_rec.enty_code IN ('STD INSTALL', 'STD EXCHANGE') + AND (p_rec.required_mesc_code IS NULL AND p_rec.qmax IS NULL) THEN + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'QMAX' + ,p_error_message => 'At least one of Qmax or Meter Size must be completed.'); + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'REQUIRED_MESC_CODE' + ,p_error_message => 'At least one of Qmax or Meter Size must be completed.'); + END IF; + + -- OM-3 + IF p_rec.enty_code IN + ('INSTALL', 'OFMAT', 'REMOVE', 'ADVERSARIAL', 'ALTERATION', + 'CAPACITY CHANGE', 'ADDON', 'OTHER') + AND p_rec.required_svcp_code = 'IP' + AND + (p_rec.required_ip_mbar IS NULL OR p_rec.required_ip_details IS NULL) THEN + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'REQUIRED_SVCP_CODE' + ,p_error_message => 'Required IP Details must be completed when a Service Pressure of ''IP'' is requested.'); + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'REQUIRED_IP_DETAILS' + ,p_error_message => 'Required IP Details must be completed when a Service Pressure of ''IP'' is requested.'); + END IF; + + -- OM-4 + 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 + 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.'); + mip_mandatory.add_error(p_mandatory_checks => p_mandatory_checks + ,p_field_name => 'MPRN_ALT' + ,p_error_message => 'Either MPRN or Additional Information must be completed.'); + END IF; + + + END table_enquiries; + +BEGIN + -- Initialization + NULL; +END mip_helper_special_cases; +/ diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck index 7edf111..c23696a 100644 --- a/Modules/mip_quotation.pck +++ b/Modules/mip_quotation.pck @@ -7,29 +7,35 @@ CREATE OR REPLACE PACKAGE mip_quotation IS /** Determines whether the given enquiry is ready to quote for i.e. have all the mandatory fields been completed - %param p_id the id of the enquiry to be checked + %param p_enqu_id the id of the enquiry to be checked %return TRUE if the enquiry can be quoted for */ - FUNCTION ready_for_quote(p_id IN enquiries.id%TYPE) RETURN BOOLEAN; + FUNCTION ready_for_quote(p_enqu_id IN enquiries.id%TYPE) RETURN BOOLEAN; /** Determines whether the given enquiry is ready to quote for i.e. have all the mandatory fields been completed - %param p_id the id of the enquiry to be checked + %param p_enqu_id the id of the enquiry to be checked %p_mandatory_checks contains reasons for the enquiry *not* being ready to quote for %p_quote_is_ready TRUE if the enquiry can be quoted for */ - PROCEDURE ready_for_quote(p_id IN enquiries.id%TYPE + PROCEDURE ready_for_quote(p_enqu_id IN enquiries.id%TYPE ,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks - ,p_quote_is_ready OUT BOOLEAN); + ,p_enquiry_is_ready OUT BOOLEAN); /** Generate quotes in response to a 'request for quote' against an enquiry - %param p_id the id of the enquiry to be checked + %param p_enqu_id the id of the enquiry to be checked + %param p_prty_id the id of the party that requested the quotes + %param p_owner_prty_id the id of party that owns the quotes (defaults to the requestor) */ PROCEDURE produce_quotes(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); + + FUNCTION return_mandatory_messages(p_enqu_id IN enquiries.id%TYPE) + RETURN VARCHAR2; + /** Make quote available %param p_qute_id id of the quote to be marked as available */ @@ -193,8 +199,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END select_quote; PROCEDURE lapse_quotes_job IS - l_current_date DATE := trunc(SYSDATE); - l_quote_expiry_date DATE; + l_current_date DATE := trunc(SYSDATE); BEGIN FOR cur_quote IN (SELECT v.qute_id FROM v_current_quote_status v @@ -457,10 +462,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS p_enqu_id || ' (' || get_enty_description(p_enqu_id) || ')'); FOR l_qute IN (SELECT id - FROM quotes, - v_quote_details v + FROM quotes + ,v_quote_details v WHERE enqu_id = p_enqu_id - AND v.QUOTE_ID = id + AND v.quote_id = id ORDER BY total_cost) LOOP produce_quote_summary(l_qute.id); @@ -536,25 +541,46 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END request_manual_quote; - PROCEDURE ready_for_quote(p_id IN enquiries.id%TYPE + PROCEDURE ready_for_quote(p_enqu_id IN enquiries.id%TYPE ,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks - ,p_quote_is_ready OUT BOOLEAN) IS + ,p_enquiry_is_ready OUT BOOLEAN) IS l_mandatory_checks mip_mandatory.t_mandatory_checks; BEGIN - p_quote_is_ready := mip_enquiries_helper.check_mandatory(p_id => p_id - ,p_mandatory_checks => p_mandatory_checks); + p_enquiry_is_ready := mip_enquiries_helper.check_mandatory(p_id => p_enqu_id + ,p_mandatory_checks => p_mandatory_checks); END ready_for_quote; - FUNCTION ready_for_quote(p_id IN enquiries.id%TYPE) RETURN BOOLEAN IS + FUNCTION ready_for_quote(p_enqu_id IN enquiries.id%TYPE) RETURN BOOLEAN IS l_mandatory_checks mip_mandatory.t_mandatory_checks; - l_quote_is_ready BOOLEAN; + l_enquiry_is_ready BOOLEAN; BEGIN - ready_for_quote(p_id => p_id + ready_for_quote(p_enqu_id => p_enqu_id ,p_mandatory_checks => l_mandatory_checks - ,p_quote_is_ready => l_quote_is_ready); - RETURN l_quote_is_ready; + ,p_enquiry_is_ready => l_enquiry_is_ready); + RETURN l_enquiry_is_ready; END ready_for_quote; + FUNCTION return_mandatory_messages(p_enqu_id IN enquiries.id%TYPE) + RETURN VARCHAR2 IS + l_mandatory_messages VARCHAR2(4000); + l_mandatory_checks mip_mandatory.t_mandatory_checks; + l_enquiry_is_ready BOOLEAN; + 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_mandatory_messages := l_mandatory_checks(l_idx) + .field_name || ':' || + l_mandatory_checks(l_idx).error_message; + END LOOP; + + RETURN nvl(l_mandatory_messages + ,'All mandatory fields have been completed'); + END return_mandatory_messages; + PROCEDURE add_quote_reason(p_enqu_id IN enquiries.id%TYPE ,p_reason IN quote_reasoning.reason%TYPE ,p_internal_or_external IN quote_reasoning.internal_or_external%TYPE DEFAULT gc_external_reason) IS @@ -634,14 +660,14 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS FROM service_pressures WHERE code = p_enqu.required_svcp_code; IF l_svcpt_code = 'LP' THEN - IF p_enqu.enty_code = 'RELOCATE' 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 relocation.'); + ,'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 l_existing_meter_size_code := p_enqu.existing_mesc_code; - l_required_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 l_required_meter_size_code := get_u_meter_size(p_enqu.qmax); END IF; @@ -662,6 +688,14 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_manual_or_automatic_quote OUT t_manual_or_automatic_quote) IS BEGIN p_manual_or_automatic_quote := gc_automatic_quote; + + IF p_enqu.enty_code IN ('OTHER', 'CHANGE CAPACITY') THEN + p_manual_or_automatic_quote := gc_manual_quote; + add_quote_reason(p_enqu.id + ,'Enquiry type is ''' || + get_enty_description(p_enqu.id) || '''.'); + END IF; + survey_required(p_enqu => p_enqu ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); @@ -701,6 +735,38 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,'Required Annual Quantity is in excess of 732MWh.'); END IF; + /* IF p_enqu.enty_code IN ('EXCHANGE') + AND NOT (p_enqu.existing_mety_code = 'DIAPHRAGM' AND + p_enqu.required_svcp_code = 'LP') THEN + p_manual_or_automatic_quote := gc_manual_quote; + add_quote_reason(p_enqu.id + ,'Exhange of a meter that is not an LP Diaphragm.'); + END IF;*/ + + IF p_enqu.existing_convertor = 'YES' + AND p_enqu.enty_code NOT IN ('REMOVE', 'STD REMOVE', 'ADVERSARIAL') THEN + p_manual_or_automatic_quote := gc_manual_quote; + add_quote_reason(p_enqu.id + ,'Convertor is present.'); + END IF; + + IF p_enqu.existing_logger = 'YES' + AND p_enqu.enty_code IN ('EXCHANGE', 'STD EXCHANGE') THEN + p_manual_or_automatic_quote := gc_manual_quote; + add_quote_reason(p_enqu.id + ,'Logger is present.'); + END IF; + + IF p_enqu.enty_code IN ('OFMAT') + AND NOT (p_enqu.existing_mety_code = 'DIAPHRAGM') + AND (substr(nvl(p_enqu.required_mesc_code + ,get_u_meter_size(p_enqu.qmax)) + ,1) <> 'U') THEN + p_manual_or_automatic_quote := gc_manual_quote; + add_quote_reason(p_enqu.id + ,'OFMAT request for a non-''U''-sized Diaphragm meter.'); + END IF; + -- check postcode IF NOT mip_regions.valid_postcode_format(p_enqu.install_postcode) THEN p_manual_or_automatic_quote := gc_manual_quote; @@ -890,10 +956,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN l_rec_costs; END get_laco; - PROCEDURE produce_inst_exch_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 + PROCEDURE produce_module_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); @@ -901,13 +967,13 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_additional_costs t_rec_additional_costs; l_quote_document VARCHAR2(240); BEGIN - cout_assert.istrue(p_enqu.enty_code IN - ('INSTALL', 'STD INSTALL', 'EXCHANGE') + 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 ' || p_enqu.enty_code); cout_assert.isnotnull(l_regi_code - ,'Attempted to produce an install or exchange quote for enquiry for a installation postcode (' || + ,'Attempted to produce an install, exchange or change of capacity quote for enquiry for a installation postcode (' || p_enqu.install_postcode || ') without a region.'); IF p_enqu.enty_code IN ('INSTALL', 'STD INSTALL') THEN @@ -927,7 +993,18 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS p_enqu.required_metering_pressure || '.' || 'Existing meter was a ' || p_enqu.existing_mesc_code || ' ' || - p_enqu.mety_code + p_enqu.existing_mety_code + ,p_internal_or_external => gc_internal_reason); + ELSIF p_enqu.enty_code IN ('CHANGE CAPACITY') THEN + add_quote_reason(p_enqu.id + ,p_reason => 'Attempting an automatic change capacity quote for ' || + p_enqu.id || '.' || ' Required SVCP ' || + p_enqu.required_svcp_code || ', QMAX=' || + p_enqu.qmax || ', Outlet Pressure=' || + p_enqu.required_metering_pressure || '.' || + 'Existing meter was a ' || + p_enqu.existing_mesc_code || ' ' || + p_enqu.existing_mety_code ,p_internal_or_external => gc_internal_reason); END IF; @@ -1431,7 +1508,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 @@ -1440,7 +1517,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END IF; - END produce_inst_exch_quotes; + END produce_module_quotes; /*PROCEDURE produce_install_quotes(p_enqu IN t_enqu ,p_rfq_prty_id IN parties.id%TYPE @@ -1993,10 +2070,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,'Attempted to produce an installation quote for enquiry for a installation postcode (' || p_enqu.install_postcode || ') without a region.'); - produce_inst_exch_quotes(p_enqu => p_enqu - ,p_rfq_prty_id => p_rfq_prty_id - ,p_owner_prty_id => p_owner_prty_id - ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + produce_module_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); END produce_install_quotes; @@ -2014,133 +2091,168 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,'Attempted to produce an exchange quote for enquiry for a installation postcode (' || p_enqu.install_postcode || ') without a region.'); - produce_inst_exch_quotes(p_enqu => p_enqu - ,p_rfq_prty_id => p_rfq_prty_id - ,p_owner_prty_id => p_owner_prty_id - ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + produce_module_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); END produce_exchange_quotes; + PROCEDURE produce_change_capacity_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 + 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); + + cout_assert.isnotnull(l_regi_code + ,'Attempted to produce a change capacity quote for enquiry for a installation postcode (' || + p_enqu.install_postcode || ') without a region.'); + + produce_module_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + + END produce_change_capacity_quotes; + + PROCEDURE produce_labour_only_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 + ('REMOVE', 'STD REMOVE', 'ADVERSARIAL', 'OFMAT', + 'ALTERATION') + ,'Attempted to produce a labour-only quote for enquiry of type ' || + p_enqu.enty_code); + + cout_assert.isnotnull(l_regi_code + ,'Attempted to produce 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 labour quote for ' || + p_enqu.id || '.' || 'Enquiry Code=' || + p_enqu.enty_code || ', SVCP ' || + p_enqu.required_svcp_code || + ', Meter Type Code=' || + p_enqu.existing_mety_code || + ', Meter Size Code=' || + p_enqu.existing_mesc_code || '.' + ,p_internal_or_external => gc_internal_reason); + + l_this_is_automatic_quote := TRUE; + + l_additional_costs := get_laco(p_enty_code => p_enqu.enty_code + ,p_regi_code => l_regi_code + ,p_mety_code => p_enqu.existing_mety_code + ,p_mesc_code => p_enqu.existing_mesc_code + ,p_svcp_code => p_enqu.required_svcp_code); + IF l_additional_costs.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:' || + p_enqu.existing_mety_code || + ', Meter Size Code:' || + p_enqu.existing_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 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 + ,svcpt_code + ,mesc_code + ,mety_code + ,cost_price + ,selling_price + ,delivery_price + ,quit_type) + VALUES + (quit_seq.NEXTVAL + ,l_qute_id + ,p_enqu.enty_code + ,l_additional_costs.svcpt_code + ,p_enqu.existing_mesc_code + ,p_enqu.existing_mety_code + ,l_additional_costs.cost_price + ,l_additional_costs.selling_price + ,l_additional_costs.delivery_cost + ,'LQI'); + + -- Generate the quote PDF + l_quote_document := mip_quotation_document.generate_quote_pdf(p_quote_id => l_qute_id); + 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 + + 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_labour_only_quotes; + PROCEDURE produce_removal_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 ('REMOVE', 'STD REMOVE') + cout_assert.istrue(p_enqu.enty_code IN + ('REMOVE', 'STD REMOVE', 'ADVERSARIAL') ,'Attempted to produce a removal quote for enquiry of type ' || p_enqu.enty_code); - - cout_assert.isnotnull(l_regi_code - ,'Attempted to produce an removal 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 removal quote for ' || - p_enqu.id || '.' || ' Required SVCP ' || - p_enqu.required_svcp_code || - ', Meter Type Code=' || p_enqu.mety_code || - ', Meter Size Code=' || - p_enqu.existing_mesc_code || '.' - ,p_internal_or_external => gc_internal_reason); - - l_this_is_automatic_quote := TRUE; - - l_additional_costs := get_laco(p_enty_code => p_enqu.enty_code - ,p_regi_code => l_regi_code - ,p_mety_code => p_enqu.mety_code - ,p_mesc_code => p_enqu.existing_mesc_code - ,p_svcp_code => p_enqu.required_svcp_code); - IF l_additional_costs.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:' || - p_enqu.mety_code || ', Meter Size Code:' || - p_enqu.existing_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 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 - ,svcpt_code - ,mesc_code - ,mety_code - ,cost_price - ,selling_price - ,delivery_price - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,l_qute_id - ,p_enqu.enty_code - ,l_additional_costs.svcpt_code - ,p_enqu.existing_mesc_code - ,p_enqu.mety_code - ,l_additional_costs.cost_price - ,l_additional_costs.selling_price - ,l_additional_costs.delivery_cost - ,'LQI'); - - -- 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 - - 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; - + produce_labour_only_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); END produce_removal_quotes; - PROCEDURE produce_gash_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 + PROCEDURE produce_ofmat_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); @@ -2148,46 +2260,141 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS l_additional_costs t_rec_additional_costs; l_quote_document VARCHAR2(240); BEGIN - cout_assert.istrue(p_enqu.enty_code IN ('REMOVE', 'STD REMOVE') - ,'Attempted to produce a removal quote for enquiry of type ' || + cout_assert.istrue(p_enqu.enty_code IN ('OFMAT') + ,'Attempted to produce an OFMAT quote for enquiry of type ' || + p_enqu.enty_code); + + produce_labour_only_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + + END produce_ofmat_quotes; + + PROCEDURE produce_alteration_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 ('ALTERATION') + ,'Attempted to produce an ALTERATION quote for enquiry of type ' || + p_enqu.enty_code); + + produce_labour_only_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + + END produce_alteration_quotes; + + PROCEDURE produce_addon_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_lifting_gear_costs t_rec_additional_costs; + l_amr_costs t_rec_additional_costs; + l_ems_costs t_rec_additional_costs; + l_bypass_costs t_rec_additional_costs; + l_quote_document VARCHAR2(240); + BEGIN + cout_assert.istrue(p_enqu.enty_code IN ('ADDON') + ,'Attempted to produce an ADDON quote for enquiry of type ' || p_enqu.enty_code); cout_assert.isnotnull(l_regi_code - ,'Attempted to produce an removal quote for enquiry for a installation postcode (' || + ,'Attempted to produce a 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 removal quote for ' || - p_enqu.id || '.' || ' Required SVCP ' || - p_enqu.required_svcp_code || - ', Meter Type Code=' || p_enqu.mety_code || - ', Meter Size Code=' || - p_enqu.existing_mesc_code || '.' + ,p_reason => 'Attempting an automatic addon quote for ' || + p_enqu.id || '.' || CASE + p_enqu.amr_required WHEN 'YES' THEN 'AMR is required. ' END || CASE p_enqu.ems_required WHEN 'YES' THEN 'EMS is required. ' END || CASE p_enqu.bypass_required WHEN 'YES' THEN 'Bypass is required. ' END ,p_internal_or_external => gc_internal_reason); l_this_is_automatic_quote := TRUE; - l_additional_costs := get_laco(p_enty_code => p_enqu.enty_code - ,p_regi_code => l_regi_code - ,p_mety_code => p_enqu.mety_code - ,p_mesc_code => p_enqu.existing_mesc_code - ,p_svcp_code => p_enqu.required_svcp_code); - IF l_additional_costs.selling_price IS NULL THEN + -- + -- check whether we have the required prices + -- if we do not, then we may need to produce a manual quote + -- + IF p_enqu.amr_required = 'YES' THEN + l_amr_costs := get_aico(p_adit_code => 'AMR' + ,p_regi_code => l_regi_code); + IF l_amr_costs.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_amr_costs.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_ems_costs := get_aico(p_adit_code => 'EMS' + ,p_regi_code => l_regi_code); + IF l_ems_costs.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_ems_costs.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_bypass_costs := get_aico(p_adit_code => 'BYPASS' + ,p_regi_code => l_regi_code); + IF l_bypass_costs.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_bypass_costs.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_lifting_gear_costs := get_aico(p_adit_code => 'LIFTING GEAR' + ,p_regi_code => l_regi_code); + IF l_lifting_gear_costs.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:' || - p_enqu.mety_code || ', Meter Size Code:' || - p_enqu.existing_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_reason => 'Unable to find selling price for LIFTING GEAR.' + ,p_internal_or_external => gc_internal_reason); + END IF; + IF l_lifting_gear_costs.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); @@ -2197,28 +2404,87 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_rfq_prty_id => p_rfq_prty_id ,p_owner_prty_id => p_owner_prty_id); + IF p_enqu.amr_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_amr_costs.adit_code + ,l_amr_costs.cost_price + ,l_amr_costs.selling_price + ,l_amr_costs.delivery_cost + ,'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 + ,l_ems_costs.adit_code + ,l_ems_costs.cost_price + ,l_ems_costs.selling_price + ,l_ems_costs.delivery_cost + ,l_ems_costs.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 + ,l_ems_costs.adit_code + ,l_ems_costs.cost_price + ,l_ems_costs.selling_price + ,l_ems_costs.delivery_cost + ,l_ems_costs.lead_time + ,'AQI'); + END IF; + + /* Always include LIFTING GEAR */ + INSERT INTO quote_items (id ,qute_id - ,enty_code - ,svcpt_code - ,mesc_code - ,mety_code + ,adit_code ,cost_price ,selling_price ,delivery_price + ,lead_time ,quit_type) VALUES (quit_seq.NEXTVAL ,l_qute_id - ,p_enqu.enty_code - ,l_additional_costs.svcpt_code - ,p_enqu.existing_mesc_code - ,p_enqu.mety_code - ,l_additional_costs.cost_price - ,l_additional_costs.selling_price - ,l_additional_costs.delivery_cost - ,'LQI'); + ,l_lifting_gear_costs.adit_code + ,l_lifting_gear_costs.cost_price + ,l_lifting_gear_costs.selling_price + ,l_lifting_gear_costs.delivery_cost + ,l_lifting_gear_costs.lead_time + ,'AQI'); -- Generate the quote PDF /*BEGIN*/ @@ -2242,7 +2508,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 @@ -2251,7 +2517,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END IF; - END produce_gash_quotes; + END produce_addon_quotes; PROCEDURE produce_automatic_quotes(p_enqu IN t_enqu ,p_rfq_prty_id IN parties.id%TYPE @@ -2266,16 +2532,26 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_rfq_prty_id => p_rfq_prty_id ,p_owner_prty_id => p_owner_prty_id ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); - ELSIF p_enqu.enty_code IN ('EXCHANGE') THEN + ELSIF p_enqu.enty_code IN ('EXCHANGE', 'STD EXCHANGE') THEN produce_exchange_quotes(p_enqu => p_enqu - ,p_rfq_prty_id => p_rfq_prty_id - ,p_owner_prty_id => p_owner_prty_id - ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); - ELSIF p_enqu.enty_code IN ('REMOVE', 'STD REMOVE') THEN + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + ELSIF p_enqu.enty_code IN ('REMOVE', 'STD REMOVE', 'ADVERSARIAL') THEN produce_removal_quotes(p_enqu => p_enqu ,p_rfq_prty_id => p_rfq_prty_id ,p_owner_prty_id => p_owner_prty_id ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + ELSIF p_enqu.enty_code IN ('OFMAT') THEN + produce_ofmat_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); + ELSIF p_enqu.enty_code IN ('ALTERATION') THEN + produce_alteration_quotes(p_enqu => p_enqu + ,p_rfq_prty_id => p_rfq_prty_id + ,p_owner_prty_id => p_owner_prty_id + ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); ELSE cout_err.report_and_stop(p_exception_message => 'Attempted to produce automatic quote for unexpected enquiry type of ' || p_enqu.enty_code); diff --git a/Schema/mipExtTables.sql b/Schema/mipExtTables.sql index ab38d69..bed1c73 100644 --- a/Schema/mipExtTables.sql +++ b/Schema/mipExtTables.sql @@ -5,6 +5,7 @@ @@ext_cost.pdc @@ext_caveat.pdc @@ext_postcode.pdc +@@ext_dataitem_role.pdc -- error logs used when merging data from the external tables to their final destinations exec dbms_errlog.create_error_log(dml_table_name => 'meters')