CREATE OR REPLACE PACKAGE mip_quotation IS -- Author : HARDYA -- Created : 15/11/2007 11:27:58 -- Purpose : Handle life-cycle of quotations FUNCTION ready_for_quote(p_id IN enquiries.id%TYPE) RETURN BOOLEAN; PROCEDURE produce_quotes(p_id IN enquiries.id%TYPE); END mip_quotation; / CREATE OR REPLACE PACKAGE BODY mip_quotation IS SUBTYPE t_reason IS VARCHAR2(240); SUBTYPE t_internal_or_external IS VARCHAR2(8); TYPE t_manual_quote_reason IS RECORD( reason t_reason ,internal_or_external t_internal_or_external); g_internal_reason CONSTANT t_internal_or_external := 'INTERNAL'; g_external_reason CONSTANT t_internal_or_external := 'EXTERNAL'; TYPE t_tab_manual_quote_reasons IS TABLE OF t_manual_quote_reason INDEX BY BINARY_INTEGER; SUBTYPE t_manual_or_automatic_quote IS VARCHAR2(9); SUBTYPE t_enqu IS enquiries%ROWTYPE; g_manual_quote CONSTANT t_manual_or_automatic_quote := 'MANUAL'; g_automatic_quote CONSTANT t_manual_or_automatic_quote := 'AUTOMATIC'; TYPE t_rec_costs IS RECORD( selling_price costs.selling_price%TYPE ,cost_price costs.cost_price%TYPE ,delivery_cost costs.delivery_cost%TYPE); PROCEDURE request_manual_quote(p_id IN enquiries.id%TYPE ,p_tab_manual_quote_reasons IN t_tab_manual_quote_reasons) IS BEGIN NULL; END request_manual_quote; PROCEDURE ready_for_quote(p_id IN enquiries.id%TYPE ,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks ,p_quote_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); END ready_for_quote; FUNCTION ready_for_quote(p_id IN enquiries.id%TYPE) RETURN BOOLEAN IS l_mandatory_checks mip_mandatory.t_mandatory_checks; l_quote_is_ready BOOLEAN; BEGIN ready_for_quote(p_id => p_id ,p_mandatory_checks => l_mandatory_checks ,p_quote_is_ready => l_quote_is_ready); RETURN l_quote_is_ready; END ready_for_quote; PROCEDURE add_manual_quote_reason(p_tab_manual_quote_reasons IN OUT t_tab_manual_quote_reasons ,p_reason IN VARCHAR2 ,p_internal_or_external IN VARCHAR2 DEFAULT g_external_reason) IS l_idx BINARY_INTEGER; BEGIN l_idx := nvl(p_tab_manual_quote_reasons.LAST ,0) + 1; p_tab_manual_quote_reasons(l_idx).reason := p_reason; p_tab_manual_quote_reasons(l_idx).internal_or_external := p_internal_or_external; END add_manual_quote_reason; FUNCTION get_u_meter_size(p_qmax IN NUMBER) RETURN meter_size_codes.code%TYPE IS l_meter_size_code meter_size_codes.code%TYPE; BEGIN -- get the smallest meter code that will support the given Qmax SELECT code INTO l_meter_size_code FROM (SELECT code FROM meter_size_codes mesc WHERE qmax >= p_qmax AND mesc.valid_for_new_meter = 'YES' ORDER BY qmax) WHERE rownum < 2; RETURN l_meter_size_code; EXCEPTION WHEN no_data_found THEN cout_err.report_and_stop(p_exception_message => 'Unable to find Meter Size Code for Qmax of ' || p_qmax); END get_u_meter_size; FUNCTION valid_meter_size_upgrade(p_existing_meter_size_code IN meter_size_codes.code%TYPE ,p_required_meter_size_code IN meter_size_codes.code%TYPE) RETURN BOOLEAN IS l_dummy NUMBER; BEGIN SELECT NULL INTO l_dummy FROM (SELECT code AS existing_mesc ,lead(code) over(ORDER BY qmax) AS required_mesc FROM meter_size_codes) WHERE existing_mesc = p_existing_meter_size_code AND required_mesc = p_required_meter_size_code; RETURN TRUE; EXCEPTION WHEN no_data_found THEN RETURN FALSE; END valid_meter_size_upgrade; PROCEDURE survey_required(p_enqu IN t_enqu ,p_tab_manual_quote_reasons IN OUT t_tab_manual_quote_reasons ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS l_svcpt_code service_pressure_types.code%TYPE; l_existing_meter_size_code meter_size_codes.code%TYPE; l_required_meter_size_code meter_size_codes.code%TYPE; BEGIN -- Low Pressure Rules -- 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 = 'RELOCATE' THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Site Survey is required for relocation.'); 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; IF l_required_meter_size_code IS NULL THEN l_required_meter_size_code := get_u_meter_size(p_enqu.qmax); END IF; IF NOT valid_meter_size_upgrade(p_existing_meter_size_code => l_existing_meter_size_code ,p_required_meter_size_code => l_required_meter_size_code) THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Site Survey is required for exchange of meter from size ' || l_existing_meter_size_code || ' to ' || l_required_meter_size_code || '.'); END IF; END IF; -- EXCHANGE END IF; -- svcpt_code = 'LP' END survey_required; PROCEDURE manual_or_automatic_quote(p_enqu IN t_enqu ,p_manual_or_automatic_quote OUT t_manual_or_automatic_quote ,p_tab_manual_quote_reasons OUT t_tab_manual_quote_reasons) IS BEGIN p_manual_or_automatic_quote := g_automatic_quote; survey_required(p_enqu => p_enqu ,p_tab_manual_quote_reasons => p_tab_manual_quote_reasons ,p_manual_or_automatic_quote => p_manual_or_automatic_quote); IF p_enqu.twin_stream_required = 'YES' THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Twin stream required.'); END IF; IF p_enqu.bypass_required = 'YES' THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Bypass required.'); END IF; IF p_enqu.required_metering_pressure > 21 THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Required metering pressure is greater than 21mbar.'); END IF; IF p_enqu.job_description IS NOT NULL THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Job Description field was entered.'); END IF; IF p_enqu.downstream_booster_or_compress = 'YES' THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Booster or compressor is present downstream of the meter module.'); END IF; IF p_enqu.annual_quantity > 732 THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Required Annual Quantity is in excess of 732MWh.'); END IF; -- check postcode IF NOT mip_regions.valid_postcode_format(p_enqu.install_postcode) THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Installation postcode is of an unrecognized format.'); ELSIF mip_regions.get_region_for_postcode(p_enqu.install_postcode) IS NULL THEN p_manual_or_automatic_quote := g_manual_quote; add_manual_quote_reason(p_tab_manual_quote_reasons ,'Unable to determine pricing region for given installation postcode.'); END IF; END manual_or_automatic_quote; FUNCTION get_aico(p_aico_code IN costs.aico_code%TYPE ,p_regi_code IN regions.code%TYPE) RETURN t_rec_costs IS l_rec_costs t_rec_costs; BEGIN SELECT selling_price ,cost_price ,delivery_cost INTO l_rec_costs.selling_price ,l_rec_costs.cost_price ,l_rec_costs.delivery_cost FROM (SELECT decode(regi_code ,p_regi_code ,1 ,999) AS accuracy ,selling_price ,cost_price ,delivery_cost FROM v_aico cost WHERE aico_code = p_aico_code AND SYSDATE BETWEEN cost.effective_from AND cost.effective_to AND regi_code = p_regi_code OR regi_code IS NULL ORDER BY 1) WHERE rownum < 2; RETURN l_rec_costs; EXCEPTION WHEN no_data_found THEN RETURN l_rec_costs; END get_aico; PROCEDURE produce_install_quotes(p_enqu IN t_enqu ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote ,p_tab_manual_quote_reasons IN OUT t_tab_manual_quote_reasons) 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_item_sequence NUMBER; l_aico_costs t_rec_costs; 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.'); 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 ,hou.code AS hou_code ,hou.selling_price AS hou_selling_price ,hou.cost_price AS hou_cost_price ,hou.delivery_cost AS hou_delivery_cost ,bas.code AS bas_code ,bas.selling_price AS bas_selling_price ,bas.cost_price AS bas_cost_price ,bas.delivery_cost 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 ,NULL AS amr_selling_price ,NULL AS amr_cost_price ,NULL AS amr_delivery_cost ,NULL AS ems_selling_price ,NULL AS ems_cost_price ,NULL AS ems_delivery_cost ,NULL AS bypass_selling_price ,NULL AS bypass_cost_price ,NULL AS bypass_delivery_cost ,NULL AS logger_selling_price ,NULL AS logger_cost_price ,NULL AS logger_delivery_cost FROM (SELECT modu.code ,modu.metr_code ,modu.hou_code ,modu.bas_code ,svcp_code ,outlet_pressure ,selling_price ,cost_price ,delivery_cost FROM modules modu ,(SELECT modu_code ,selling_price ,cost_price ,delivery_cost FROM (SELECT decode(regi_code ,l_regi_code ,1 ,999) AS accuracy ,modu_code ,selling_price ,cost_price ,delivery_cost 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 ORDER BY 1) WHERE rownum < 2) cost WHERE modu.code = cost.modu_code(+)) modu ,(SELECT hou.code ,cost_price ,selling_price ,delivery_cost FROM housings hou ,(SELECT hou_code ,selling_price ,cost_price ,delivery_cost FROM (SELECT decode(regi_code ,l_regi_code ,1 ,999) AS accuracy ,hou_code ,selling_price ,cost_price ,delivery_cost FROM v_hoco cost WHERE SYSDATE BETWEEN cost.effective_from AND cost.effective_to AND regi_code = l_regi_code OR regi_code IS NULL ORDER BY 1) WHERE rownum < 2) cost WHERE hou.code = cost.hou_code(+)) hou ,(SELECT bas.code ,cost_price ,selling_price ,delivery_cost FROM bases bas ,(SELECT bas_code ,selling_price ,cost_price ,delivery_cost FROM (SELECT decode(regi_code ,l_regi_code ,1 ,999) AS accuracy ,bas_code ,selling_price ,cost_price ,delivery_cost FROM v_baco cost WHERE SYSDATE BETWEEN cost.effective_from AND cost.effective_to AND regi_code = l_regi_code OR regi_code IS NULL ORDER BY 1) WHERE rownum < 2) cost WHERE bas.code = cost.bas_code) bas ,(SELECT metr.code ,metr.qmax ,metr.qmin ,metr.qnom ,cost_price ,selling_price ,delivery_cost FROM meters metr ,(SELECT metr_code ,selling_price ,cost_price ,delivery_cost FROM (SELECT decode(regi_code ,l_regi_code ,1 ,999) AS accuracy ,metr_code ,selling_price ,cost_price ,delivery_cost 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 ORDER BY 1) WHERE rownum < 2) 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 AND ((bas_code IS NULL AND p_enqu.base_required <> 'YES') OR (bas_code IS NOT NULL AND p_enqu.base_required <> 'YES')) AND modu.bas_code = bas.code(+) AND ((hou_code IS NULL AND p_enqu.housing_required <> 'YES') OR (hou_code IS NOT NULL AND p_enqu.housing_required <> 'YES')) AND modu.hou_code = hou.code(+)) LOOP l_this_is_automatic_quote := TRUE; -- -- 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_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for module ' || l_rec_module.modu_code ,p_internal_or_external => g_external_reason); END IF; IF l_rec_module.metr_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for meter ' || l_rec_module.metr_code ,p_internal_or_external => g_external_reason); END IF; IF p_enqu.base_required = 'YES' AND l_rec_module.bas_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for base ' || l_rec_module.bas_code ,p_internal_or_external => g_external_reason); END IF; IF p_enqu.housing_required = 'YES' AND l_rec_module.hou_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for housing ' || l_rec_module.hou_code ,p_internal_or_external => g_external_reason); END IF; IF p_enqu.amr_required = 'YES' THEN l_aico_costs := get_aico(p_aico_code => 'AMR' ,p_regi_code => l_regi_code); l_rec_module.amr_selling_price := l_aico_costs.selling_price; l_rec_module.amr_cost_price := l_aico_costs.cost_price; l_rec_module.amr_delivery_cost := l_aico_costs.delivery_cost; IF l_rec_module.amr_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for AMR' ,p_internal_or_external => g_external_reason); END IF; END IF; IF p_enqu.ems_required = 'YES' THEN l_aico_costs := get_aico(p_aico_code => 'EMS' ,p_regi_code => l_regi_code); l_rec_module.ems_selling_price := l_aico_costs.selling_price; l_rec_module.ems_cost_price := l_aico_costs.cost_price; l_rec_module.ems_delivery_cost := l_aico_costs.delivery_cost; IF l_rec_module.ems_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for EMS' ,p_internal_or_external => g_external_reason); END IF; END IF; IF p_enqu.bypass_required = 'YES' THEN l_aico_costs := get_aico(p_aico_code => 'BYPASS' ,p_regi_code => l_regi_code); l_rec_module.bypass_selling_price := l_aico_costs.selling_price; l_rec_module.bypass_cost_price := l_aico_costs.cost_price; l_rec_module.bypass_delivery_cost := l_aico_costs.delivery_cost; IF l_rec_module.bypass_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for BYPASS' ,p_internal_or_external => g_external_reason); END IF; END IF; IF p_enqu.logger_required = 'YES' THEN l_aico_costs := get_aico(p_aico_code => 'LOGGER' ,p_regi_code => l_regi_code); l_rec_module.logger_selling_price := l_aico_costs.selling_price; l_rec_module.logger_cost_price := l_aico_costs.cost_price; l_rec_module.logger_delivery_cost := l_aico_costs.delivery_cost; IF l_rec_module.logger_selling_price IS NULL THEN l_this_is_automatic_quote := FALSE; add_manual_quote_reason(p_tab_manual_quote_reasons ,p_reason => 'Unable to find selling price for LOGGER' ,p_internal_or_external => g_external_reason); END IF; END IF; IF l_this_is_automatic_quote THEN l_produced_automatic_quote := TRUE; INSERT INTO quotes (id ,qute_type ,enqu_id) VALUES (qute_seq.NEXTVAL ,'AQ' -- automatic quote ,p_enqu.id) RETURNING id INTO l_qute_id; INSERT INTO quote_events (event_date ,qust_code ,qute_id) VALUES (SYSDATE ,'INP' -- In Progress ,l_qute_id); l_item_sequence := 1; INSERT INTO quote_items (item_sequence ,qute_id ,modu_code ,cost_price ,selling_price ,delivery_price) VALUES (l_item_sequence ,l_qute_id ,l_rec_module.modu_code ,l_rec_module.modu_cost_price ,l_rec_module.modu_selling_price ,l_rec_module.modu_delivery_cost); IF l_rec_module.hou_code IS NOT NULL THEN l_item_sequence := l_item_sequence + 1; INSERT INTO quote_items (item_sequence ,qute_id ,hou_code ,cost_price ,selling_price ,delivery_price) VALUES (l_item_sequence ,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); END IF; IF l_rec_module.bas_code IS NOT NULL THEN l_item_sequence := l_item_sequence + 1; INSERT INTO quote_items (item_sequence ,qute_id ,bas_code ,cost_price ,selling_price ,delivery_price) VALUES (l_item_sequence ,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); END IF; IF p_enqu.amr_required = 'YES' THEN NULL; END IF; END IF; END LOOP; END produce_install_quotes; PROCEDURE produce_automatic_quotes(p_enqu IN t_enqu ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote ,p_tab_manual_quote_reasons IN OUT t_tab_manual_quote_reasons) IS BEGIN cout_assert.istrue(p_manual_or_automatic_quote = g_automatic_quote ,p_message => 'Attempted to produce automatic quote for enquiry marked as manual only'); IF p_enqu.enty_code IN ('INSTALL', 'STD INSTALL') THEN produce_install_quotes(p_enqu => p_enqu ,p_manual_or_automatic_quote => p_manual_or_automatic_quote ,p_tab_manual_quote_reasons => p_tab_manual_quote_reasons); ELSE cout_err.report_and_stop(p_exception_message => 'Attempted to produce automatic quote for unexpected enquiry type of ' || p_enqu.enty_code); END IF; END produce_automatic_quotes; PROCEDURE produce_quotes(p_id IN enquiries.id%TYPE) IS l_manual_or_automatic_quote t_manual_or_automatic_quote; l_tab_manual_quote_reasons t_tab_manual_quote_reasons; l_enqu t_enqu; BEGIN cout_assert.istrue(ready_for_quote(p_id) ,'Not all mandatory fields for Enquiry ID=' || p_id || ' have been completed'); SELECT * INTO l_enqu FROM enquiries WHERE id = p_id; manual_or_automatic_quote(p_enqu => l_enqu ,p_manual_or_automatic_quote => l_manual_or_automatic_quote ,p_tab_manual_quote_reasons => l_tab_manual_quote_reasons); IF l_manual_or_automatic_quote = g_manual_quote THEN request_manual_quote(p_id => l_enqu.id ,p_tab_manual_quote_reasons => l_tab_manual_quote_reasons); ELSE produce_automatic_quotes(p_enqu => l_enqu ,p_manual_or_automatic_quote => l_manual_or_automatic_quote ,p_tab_manual_quote_reasons => l_tab_manual_quote_reasons); IF l_manual_or_automatic_quote = g_manual_quote THEN request_manual_quote(p_id => l_enqu.id ,p_tab_manual_quote_reasons => l_tab_manual_quote_reasons); END IF; -- END IF; -- manual or automatic quote END produce_quotes; BEGIN -- Initialization NULL; END mip_quotation; /