diff --git a/Modules/mip_bulk_load.pck b/Modules/mip_bulk_load.pck index 7a594cd..6303652 100644 --- a/Modules/mip_bulk_load.pck +++ b/Modules/mip_bulk_load.pck @@ -6,6 +6,10 @@ CREATE OR REPLACE PACKAGE mip_bulk_load IS PROCEDURE load_meters; PROCEDURE load_modules; + PROCEDURE load_drawings; + PROCEDURE load_bases; + + PROCEDURE load_all; END mip_bulk_load; / @@ -13,6 +17,9 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS g_unknown_manufacturer_id parties.id%TYPE; +PROCEDURE get_dir_list(p_directory IN VARCHAR2) AS + LANGUAGE JAVA NAME 'DirList.getList( java.lang.String )'; + PROCEDURE get_globals IS BEGIN @@ -141,32 +148,6 @@ g_unknown_manufacturer_id parties.id%TYPE; END get_globals; - PROCEDURE load_manufacturers(p_reason VARCHAR2 DEFAULT 'no reason given') IS - BEGIN - MERGE INTO parties prty - - USING (SELECT field_1 - FROM ext_meters) e_metr - ON (upper(e_metr.field_1) = upper(prty.manu_ref)) - WHEN NOT MATCHED THEN - INSERT - (prty.manu_ref - ,NAME - ,description - ,created_on - ,created_by - ,prty_type - ,id) - VALUES - (upper(e_metr.field_1) - ,e_metr.field_1 - ,'Inserted missing manufacturer - ' || p_reason - ,SYSDATE - ,USER - ,'MANU' - ,prty_seq.NEXTVAL) log errors reject LIMIT unlimited; - END load_manufacturers; - PROCEDURE load_meters IS BEGIN @@ -175,13 +156,13 @@ g_unknown_manufacturer_id parties.id%TYPE; (code ,description ) - (SELECT manu_ref + (SELECT code ,'Inserted for load_meters' - FROM (SELECT DISTINCT upper(field_3) AS manu_ref + FROM (SELECT DISTINCT upper(field_3) AS code FROM ext_meters WHERE field_3 IS NOT NULL) - WHERE manu_ref NOT IN (SELECT manu_ref - FROM parties)); + WHERE code NOT IN (SELECT code + FROM meter_types)); -- Manufacturers INSERT INTO parties @@ -208,10 +189,10 @@ g_unknown_manufacturer_id parties.id%TYPE; (code ,description) (SELECT code - ,'Inserted for load_modules' - FROM (SELECT DISTINCT field_4 AS code + ,'Inserted for load_meters' + FROM (SELECT DISTINCT upper(field_2) AS code FROM ext_meters - WHERE field_4 IS NOT NULL) + WHERE field_2 IS NOT NULL) WHERE code NOT IN (SELECT code FROM drawings)); @@ -300,10 +281,10 @@ g_unknown_manufacturer_id parties.id%TYPE; (SELECT code ,'Inserted for load_modules' FROM (SELECT DISTINCT code - FROM (SELECT field_2 AS code + FROM (SELECT upper(field_2) AS code FROM ext_modules UNION - SELECT field_3 + SELECT upper(field_3) FROM ext_modules)) WHERE code NOT IN (SELECT code FROM connection_types)); @@ -314,7 +295,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,description) (SELECT code ,'Inserted for load_modules' - FROM (SELECT DISTINCT field_4 AS code + FROM (SELECT DISTINCT upper(field_4) AS code FROM ext_modules WHERE field_4 IS NOT NULL) WHERE code NOT IN (SELECT code @@ -366,7 +347,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,.999 ,.999 ,trunc(SYSDATE) - FROM (SELECT DISTINCT nvl(field_5,'UNKNOWN') AS code + FROM (SELECT DISTINCT nvl(upper(field_5),'UNKNOWN') AS code FROM ext_modules) WHERE code NOT IN (SELECT code FROM meters)); @@ -382,7 +363,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,'UNKNOWN' ,999 ,999 - FROM (SELECT DISTINCT field_6 AS code + FROM (SELECT DISTINCT upper(field_6) AS code FROM ext_modules) WHERE code NOT IN (SELECT code FROM relief_valves)); @@ -397,7 +378,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,'UNKNOWN' ,999 ,999 - FROM (SELECT DISTINCT field_7 AS code + FROM (SELECT DISTINCT upper(field_7) AS code FROM ext_modules) WHERE code NOT IN (SELECT code FROM slamshut_valves)); @@ -410,7 +391,7 @@ g_unknown_manufacturer_id parties.id%TYPE; (SELECT code ,'UNKNOWN' ,'Inserted for load_modules' - FROM (SELECT DISTINCT field_8 AS code + FROM (SELECT DISTINCT upper(field_8) AS code FROM ext_modules) WHERE code NOT IN (SELECT code FROM service_pressures)); @@ -443,7 +424,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,999 ,999 ,999 - FROM (SELECT DISTINCT field_15 AS code + FROM (SELECT DISTINCT upper(field_15) AS code FROM ext_modules WHERE field_15 IS NOT NULL) WHERE code NOT IN (SELECT code @@ -469,7 +450,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,999 ,999 ,999 - FROM (SELECT DISTINCT field_16 AS code + FROM (SELECT DISTINCT upper(field_16) AS code FROM ext_modules WHERE field_16 IS NOT NULL) WHERE code NOT IN (SELECT code @@ -487,7 +468,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,'Inserted for load_modules' ,999 ,999 - FROM (SELECT DISTINCT field_25 AS code + FROM (SELECT DISTINCT upper(field_25) AS code FROM ext_modules WHERE field_25 IS NOT NULL) WHERE code NOT IN (SELECT code @@ -501,7 +482,7 @@ g_unknown_manufacturer_id parties.id%TYPE; (SELECT code ,'UNKNOWN' ,999 - FROM (SELECT DISTINCT field_26 AS code + FROM (SELECT DISTINCT upper(field_26) AS code FROM ext_modules WHERE field_26 IS NOT NULL) WHERE code NOT IN (SELECT code @@ -513,32 +494,32 @@ g_unknown_manufacturer_id parties.id%TYPE; (SELECT code ,'Inserted for load_modules' FROM (SELECT DISTINCT code - FROM (SELECT field_27 AS code + FROM (SELECT upper(field_27) AS code FROM ext_modules UNION - SELECT field_28 + SELECT upper(field_28) FROM ext_modules) WHERE code IS NOT NULL) WHERE code NOT IN (SELECT code FROM connection_orientations)); MERGE INTO modules modu - USING (SELECT field_1 - ,field_2 - ,field_3 - ,field_4 - ,field_5 - ,field_6 - ,field_7 - ,field_8 + USING (SELECT upper(field_1) AS field_1 + ,upper(field_2) AS field_2 + ,upper(field_3) AS field_3 + ,upper(field_4) AS field_4 -- drwg_code + ,upper(field_5) AS field_5 + ,upper(field_6) AS field_6 + ,upper(field_7) AS field_7 + ,upper(field_8) AS field_8 ,field_9 ,field_10 ,field_11 ,field_12 ,field_13 ,field_14 - ,field_15 - ,field_16 + ,upper(field_15) AS field_15 -- base + ,upper(field_16) AS field_16 -- housing ,field_17 ,field_18 ,field_19 @@ -547,12 +528,12 @@ g_unknown_manufacturer_id parties.id%TYPE; ,field_22 ,field_23 ,field_24 - ,field_25 - ,field_26 - ,field_27 - ,field_28 + ,upper(field_25) AS field_25 -- regu_code + ,upper(field_26) AS field_26 -- fltr_code + ,upper(field_27) AS field_27 -- inlet connection orientation + ,upper(field_28) AS field_28 -- outlet ... ,field_29 - ,field_30 + ,upper(field_30) AS field_30 -- MANU_REF FROM ext_modules) e ON (e.field_1 = modu.code) WHEN MATCHED THEN @@ -590,7 +571,7 @@ g_unknown_manufacturer_id parties.id%TYPE; ,lead_time = e.field_29 ,prty_id = (SELECT id FROM parties p - WHERE upper(p.manu_ref) = upper(e.field_30) + WHERE p.manu_ref = e.field_30 AND p.prty_type = 'MANU') WHEN NOT MATCHED THEN @@ -666,6 +647,298 @@ g_unknown_manufacturer_id parties.id%TYPE; ,'dd/mm/yyyy')END) log errors reject LIMIT unlimited; END load_modules; + PROCEDURE load_drawings IS + l_directory_path all_directories.directory_path%TYPE; + l_source_file BFILE; + l_source_file_length BINARY_INTEGER; + l_blob BLOB; + l_success BOOLEAN; + BEGIN + + dbms_lob.createtemporary(lob_loc => l_blob + ,cache => TRUE); + dbms_lob.OPEN(lob_loc => l_blob + ,open_mode => dbms_lob.lob_readwrite); + + SELECT directory_path + INTO l_directory_path + FROM all_directories + WHERE directory_name = 'WEBMIP_BULK_LOAD'; + + get_dir_list(l_directory_path); + + FOR l_rec IN (SELECT filename AS filename + ,upper(substr(filename + ,1 + ,regexp_instr(filename + ,'.(jpg)|.(jpeg)|.(png)$' + ,1 + ,1 + ,0 + ,'i') - 1)) AS drwg_code + ,substr(filename + ,regexp_instr(filename + ,'.(jpg)|.(jpeg)|.(png)$' + ,1 + ,1 + ,0 + ,'i') + 1) AS filename_suffix + FROM gtt_dir_list g + WHERE g.filetype = 'F' + AND regexp_like(g.filename + ,'.(jpg)|.(jpeg)|.(png)$' + ,'i')) LOOP + + l_source_file := bfilename('WEBMIP_BULK_LOAD' + ,l_rec.filename); + l_source_file_length := dbms_lob.getlength(l_source_file); + + dbms_lob.OPEN(file_loc => l_source_file + ,open_mode => dbms_lob.lob_readonly); + + dbms_lob.loadfromfile(dest_lob => l_blob + ,src_lob => l_source_file + ,amount => l_source_file_length); + + dbms_lob.fileclose(file_loc => l_source_file); + + BEGIN + SAVEPOINT this_drawing_savepoint; + BEGIN + INSERT INTO drawings + (code + ,description) + VALUES + (l_rec.drwg_code + ,'Inserted for load_drawings'); + EXCEPTION + WHEN dup_val_on_index THEN + NULL; + END; + + DELETE FROM wwv_flow_files + WHERE NAME = l_rec.filename; + + DELETE FROM document_roles doro + WHERE doro.drwg_code = l_rec.drwg_code; + + DELETE FROM documents doco + WHERE doco.uri = l_rec.filename; + + INSERT INTO wwv_flow_files + (NAME + ,title + ,mime_type + ,flow_id + ,doc_size + ,description + ,blob_content) + VALUES + (l_rec.filename + ,'Drawing' + ,'image/' || l_rec.filename_suffix + ,apex_application.g_flow_id + ,l_source_file_length + ,'Bulk Loaded on ' || + to_char(SYSDATE + ,'DD-MON-YYYY HH24:MI:SS') + ,l_blob) + ; + + l_success := mip_files.set_file_association(p_uri => l_rec.filename + ,p_description => 'Drawing' + ,p_docu_type => 'INDO' + ,p_rt_code => 'HIGH DEFINITION DRAWING' + ,p_qute_id => NULL + ,p_enqu_id => NULL + ,p_drwg_code => l_rec.drwg_code + ,p_doro_type => 'DRRO'); + IF NOT l_success THEN + ROLLBACK TO this_drawing_savepoint; + END IF; + END; + END LOOP; + END load_drawings; + + PROCEDURE load_bases IS + BEGIN + + -- Drawings + INSERT INTO drawings + (code + ,description) + (SELECT code + ,'Inserted for load_bases' + FROM (SELECT DISTINCT upper(field_2) AS code + FROM ext_bases + WHERE field_2 IS NOT NULL) + WHERE code NOT IN (SELECT code + FROM drawings)); + + MERGE INTO bases bas + USING (SELECT upper(field_1) AS field_1 + ,upper(field_2) AS field_2 + ,field_3 + ,field_4 + ,field_5 + ,field_6 + ,field_7 + ,field_8 + ,field_9 + ,field_10 + ,field_11 + ,field_12 + ,field_13 + FROM ext_bases) e + ON (e.field_1 = bas.code) + WHEN MATCHED THEN + UPDATE + SET drwg_code = e.field_2 + ,description = e.field_3 + ,dim_a = e.field_4 + ,dim_b = e.field_5 + ,dim_c = e.field_6 + ,dim_d = e.field_7 + ,dim_e = e.field_8 + ,dim_f = e.field_9 + ,dim_g = e.field_10 + ,dim_h = e.field_11 + ,dim_i = e.field_12 + ,depth = e.field_13 + WHEN NOT MATCHED THEN + INSERT + (code + ,drwg_code + ,description + ,dim_a + ,dim_b + ,dim_c + ,dim_d + ,dim_e + ,dim_f + ,dim_g + ,dim_h + ,dim_i + ,depth) + VALUES + (e.field_1 + ,e.field_2 + ,e.field_3 + ,e.field_4 + ,e.field_5 + ,e.field_6 + ,e.field_7 + ,e.field_8 + ,e.field_9 + ,e.field_10 + ,e.field_11 + ,e.field_12 + ,e.field_13) log errors reject LIMIT unlimited; + END load_bases; + + PROCEDURE load_housings IS + BEGIN + + -- Manufacturers + INSERT INTO parties + (id + ,manu_ref + ,description + ,prty_type + ,created_on + ,created_by) + (SELECT prty_seq.NEXTVAL + ,manu_ref + ,'Inserted for load_housings' + ,'MANU' + ,SYSDATE + ,USER + FROM (SELECT DISTINCT upper(field_2) AS manu_ref + FROM ext_housings + WHERE field_2 IS NOT NULL) + WHERE manu_ref NOT IN (SELECT manu_ref + FROM parties)); + -- Drawings + INSERT INTO drawings + (code + ,description) + (SELECT code + ,'Inserted for load_housings' + FROM (SELECT DISTINCT upper(field_3) AS code + FROM ext_housings + WHERE field_3 IS NOT NULL) + WHERE code NOT IN (SELECT code + FROM drawings)); + + -- Housing Types + INSERT INTO housing_types + (code + ,description) + (SELECT code + ,'Inserted for load_housings' + FROM (SELECT DISTINCT upper(field_4) AS code + FROM ext_housings + WHERE field_4 IS NOT NULL) + WHERE code NOT IN (SELECT code + FROM housing_types)); + + MERGE INTO housings hou + USING (SELECT upper(field_1) AS field_1 + ,upper(field_2) AS field_2 + ,upper(field_3) AS field_3 + ,upper(field_4) AS field_4 + ,field_5 + ,field_6 + ,field_7 + ,field_8 + ,field_9 + FROM ext_housings) e + ON (e.field_1 = hou.code) + WHEN MATCHED THEN + UPDATE + SET prty_id = (SELECT id FROM parties WHERE manu_ref = e.field_2 AND prty_type = 'MANU') + ,drwg_code = e.field_3 + ,hoty_code = e.field_4 + ,description = e.field_5 + ,dim_w = e.field_6 + ,dim_h = e.field_7 + ,dim_l = e.field_8 + ,weight = e.field_9 + WHEN NOT MATCHED THEN + INSERT + (code + ,prty_id + ,drwg_code + ,hoty_code + ,description + ,dim_w + ,dim_h + ,dim_l + ,weight) + VALUES + (e.field_1 + ,(SELECT id FROM parties WHERE manu_ref = e.field_2 AND prty_type = 'MANU') + ,e.field_3 + ,e.field_4 + ,e.field_5 + ,e.field_6 + ,e.field_7 + ,e.field_8 + ,e.field_9) log errors reject LIMIT unlimited; + END load_housings; + + + PROCEDURE load_all + IS + BEGIN + + load_modules; + load_meters; + load_bases; + load_housings; + load_drawings; + + END load_all; BEGIN -- Initialization get_globals; diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck index bc7d871..1cade69 100644 --- a/Modules/mip_quotation.pck +++ b/Modules/mip_quotation.pck @@ -47,14 +47,42 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS TYPE t_rec_additional_costs IS RECORD( adit_code additional_items.code%TYPE + ,svcpt_code service_pressure_types.code%TYPE ,lead_time additional_items.lead_time%TYPE ,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) IS + PROCEDURE request_manual_quote(p_enqu_id IN enquiries.id%TYPE) IS + l_qute_id quotes.id%TYPE; BEGIN - NULL; + INSERT INTO quotes + (id + ,qute_type + ,enqu_id + ,valid_from + ,valid_until + ,created_on + ,created_by) + VALUES + (qute_seq.NEXTVAL + ,'MQ' -- manual quote + ,p_enqu_id + ,trunc(SYSDATE) + ,trunc(SYSDATE + 90) + ,SYSDATE + ,USER) + RETURNING id INTO l_qute_id; + + INSERT INTO quote_events + (event_date + ,qust_code + ,qute_id) + VALUES + (SYSDATE + ,'INP' -- In Progress + ,l_qute_id); + END request_manual_quote; PROCEDURE ready_for_quote(p_id IN enquiries.id%TYPE @@ -228,6 +256,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS add_quote_reason(p_enqu.id ,'Unable to determine pricing region for given installation postcode.'); END IF; + + IF p_manual_or_automatic_quote = g_manual_quote THEN + add_quote_reason(p_enqu.id + ,'- Manual quote required.' + ,g_internal_reason); + END IF; END manual_or_automatic_quote; FUNCTION get_housing(p_hou_code IN modules.hou_code%TYPE @@ -244,7 +278,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS FROM (SELECT selling_price ,cost_price ,delivery_cost - FROM (SELECT row_number() over(PARTITION BY hou_code ORDER BY(decode(regi_code, p_regi_code, 1, 999))) AS accuracy + FROM (SELECT decode(regi_code + ,p_regi_code + ,1 + ,999) AS accuracy ,hou_code ,selling_price ,cost_price @@ -254,9 +291,9 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS WHERE hou_code = p_hou_code AND SYSDATE BETWEEN cost.effective_from AND cost.effective_to - AND regi_code = p_regi_code - OR regi_code IS NULL) - WHERE accuracy <= 1); + AND (regi_code = p_regi_code OR regi_code IS NULL) + ORDER BY 1) + WHERE rownum < 2); RETURN l_rec_costs; EXCEPTION @@ -278,7 +315,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS FROM (SELECT selling_price ,cost_price ,delivery_cost - FROM (SELECT row_number() over(PARTITION BY bas_code ORDER BY(decode(regi_code, p_regi_code, 1, 999))) AS accuracy + FROM (SELECT decode(regi_code + ,p_regi_code + ,1 + ,999) AS accuracy ,bas_code ,selling_price ,cost_price @@ -288,9 +328,9 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS WHERE bas_code = p_bas_code AND SYSDATE BETWEEN cost.effective_from AND cost.effective_to - AND regi_code = p_regi_code - OR regi_code IS NULL) - WHERE accuracy <= 1); + AND (regi_code = p_regi_code OR regi_code IS NULL) + ORDER BY 1) + WHERE rownum < 2); RETURN l_rec_costs; @@ -319,7 +359,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,cost_price ,delivery_cost ,adit_code - FROM (SELECT row_number() over(PARTITION BY adit_code ORDER BY(decode(regi_code, p_regi_code, 1, 999))) AS accuracy + FROM (SELECT decode(regi_code + ,p_regi_code + ,1 + ,999) AS accuracy ,adit_code ,selling_price ,cost_price @@ -329,9 +372,9 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS WHERE adit_code = p_adit_code AND SYSDATE BETWEEN cost.effective_from AND cost.effective_to - AND regi_code = p_regi_code - OR regi_code IS NULL) - WHERE accuracy <= 1) cost + AND (regi_code = p_regi_code OR regi_code IS NULL) + ORDER BY 1) + WHERE rownum < 2) cost WHERE adit.code = cost.adit_code AND adit.code = p_adit_code; @@ -342,6 +385,56 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS RETURN l_rec_costs; END get_aico; + FUNCTION get_laco(p_enty_code IN enquiry_types.code%TYPE + ,p_regi_code IN regions.code%TYPE + ,p_mety_code IN meter_types.code%TYPE + ,p_mesc_code IN meter_size_codes.code%TYPE DEFAULT NULL + ,p_svcp_code IN service_pressures.code%TYPE DEFAULT NULL) + RETURN t_rec_additional_costs IS + l_rec_costs t_rec_additional_costs; + BEGIN + SELECT selling_price + ,cost_price + ,delivery_cost + ,svcpt_code + INTO l_rec_costs.selling_price + ,l_rec_costs.cost_price + ,l_rec_costs.delivery_cost + ,l_rec_costs.svcpt_code + FROM (SELECT decode(regi_code + ,p_regi_code + ,1 + ,999) AS accuracy + ,enty_code + ,mety_code + ,cost.svcpt_code + ,mesc_code + ,selling_price + ,cost_price + ,delivery_cost + ,cost.ROWID + ,svcp.code AS svcp_code + FROM v_laco cost + ,service_pressures svcp + WHERE SYSDATE BETWEEN cost.effective_from AND cost.effective_to + AND (regi_code = p_regi_code OR regi_code IS NULL) + AND cost.svcpt_code = svcp.svcpt_code + AND enty_code = p_enty_code + AND mety_code = p_mety_code + AND ((svcp.code = p_svcp_code) OR + (svcp.code IS NULL AND p_svcp_code IS NULL)) + AND ((mesc_code = p_mesc_code) OR + (mesc_code IS NULL AND p_mesc_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_laco; + PROCEDURE produce_install_quotes(p_enqu IN t_enqu ,p_manual_or_automatic_quote IN OUT t_manual_or_automatic_quote) IS l_produced_automatic_quote BOOLEAN; @@ -372,6 +465,8 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,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 @@ -387,13 +482,12 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,metr.cost_price AS metr_cost_price ,metr.delivery_cost AS metr_delivery_cost ,metr.mety_code - ,laco.mety_code AS laco_mety_code - ,laco.svcp_code AS laco_svcp_code - ,laco.svcpt_code AS laco_svcpt_code - ,laco.mesc_code AS laco_mesc_code - ,laco.selling_price /*NULL*/ AS laco_selling_price - ,laco.cost_price /*NULL*/ AS laco_cost_price - ,laco.delivery_cost /*NULL*/ AS laco_delivery_cost + ,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 @@ -420,11 +514,15 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,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 @@ -436,53 +534,16 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,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(+)) modu - ,(SELECT enty_code - ,mety_code - ,svcpt_code - ,mesc_code - ,svcp_code - ,selling_price - ,cost_price - ,delivery_cost - FROM enquiry_types enty - ,(SELECT enty_code - ,mety_code - ,svcpt_code - ,mesc_code - ,svcp_code - ,selling_price - ,cost_price - ,delivery_cost - FROM (SELECT row_number() over(PARTITION BY enty_code, mety_code, cost.svcpt_code, mesc_code ORDER BY(decode(regi_code, l_regi_code, 1, 999))) AS accuracy - ,enty_code - ,mety_code - ,cost.svcpt_code - ,mesc_code - ,selling_price - ,cost_price - ,delivery_cost - ,cost.ROWID - ,svcp.code AS svcp_code - FROM v_laco cost - ,service_pressures svcp WHERE SYSDATE BETWEEN cost.effective_from AND cost.effective_to AND (regi_code = l_regi_code OR - regi_code IS NULL) - AND cost.svcpt_code = - svcp.svcpt_code(+)) + regi_code IS NULL)) WHERE accuracy <= 1) cost - WHERE enty.code = cost.enty_code(+)) laco + 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 @@ -506,9 +567,9 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS WHERE SYSDATE BETWEEN cost.effective_from AND cost.effective_to - AND regi_code = - l_regi_code - OR regi_code IS NULL) + 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 @@ -516,16 +577,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS p_enqu.required_metering_pressure AND metr.code = modu.metr_code AND metr.qmax >= p_enqu.qmax - AND (laco.enty_code = p_enqu.enty_code AND - laco.mety_code = metr.mety_code AND - ((laco.svcp_code = - p_enqu.required_svcp_code) OR - (laco.svcp_code IS NULL AND - p_enqu.required_svcp_code IS NULL)) AND - ((laco.mesc_code = - p_enqu.required_mesc_code) OR - (laco.mesc_code IS NULL AND - p_enqu.required_mesc_code IS NULL)))) LOOP + ) LOOP l_this_is_automatic_quote := TRUE; add_quote_reason(p_enqu.id ,p_reason => 'Considering module : ' || @@ -551,11 +603,27 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_internal_or_external => g_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 enquiry type ' || - p_enqu.enty_code || CASE l_regi_code WHEN NULL THEN '' ELSE ' for region code ' || l_regi_code END || '.' + ,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 => g_internal_reason); END IF; @@ -720,23 +788,6 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,'INP' -- In Progress ,l_qute_id); - INSERT INTO quote_items - (id - ,qute_id - ,modu_code - ,cost_price - ,selling_price - ,delivery_price - ,quit_type) - VALUES - (quit_seq.NEXTVAL - ,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 - ,'MQI'); - INSERT INTO quote_items (id ,qute_id @@ -760,6 +811,29 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,l_rec_module.laco_delivery_cost ,'LQI'); + INSERT INTO quote_items + (id + ,qute_id + ,modu_code + ,qmax + ,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.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 @@ -883,13 +957,13 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,'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; - + /*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 || '.' @@ -909,41 +983,16 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END LOOP; IF l_produced_automatic_quote THEN + p_manual_or_automatic_quote := g_automatic_quote; add_quote_reason(p_enqu_id => p_enqu.id ,p_reason => '-- Produced an automatic quote.' ,p_internal_or_external => g_internal_reason); ELSE + p_manual_or_automatic_quote := g_manual_quote; add_quote_reason(p_enqu_id => p_enqu.id - ,p_reason => '-- Manual quote required.' + ,p_reason => '-- Automatic quote failed - Manual quote required.' ,p_internal_or_external => g_internal_reason); - INSERT INTO quotes - (id - ,qute_type - ,enqu_id - ,valid_from - ,valid_until - ,created_on - ,created_by) - VALUES - (qute_seq.NEXTVAL - ,'MQ' -- manual quote - ,p_enqu.id - ,trunc(SYSDATE) - ,trunc(SYSDATE + 90) - ,SYSDATE - ,USER) - RETURNING id INTO l_qute_id; - - INSERT INTO quote_events - (event_date - ,qust_code - ,qute_id) - VALUES - (SYSDATE - ,'INP' -- In Progress - ,l_qute_id); - END IF; END produce_install_quotes; @@ -981,20 +1030,20 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS ,p_manual_or_automatic_quote => l_manual_or_automatic_quote); IF l_manual_or_automatic_quote = g_manual_quote THEN - request_manual_quote(p_id => l_enqu.id); + request_manual_quote(p_enqu_id => l_enqu.id); ELSE produce_automatic_quotes(p_enqu => l_enqu ,p_manual_or_automatic_quote => l_manual_or_automatic_quote); IF l_manual_or_automatic_quote = g_manual_quote THEN - request_manual_quote(p_id => l_enqu.id); + request_manual_quote(p_enqu_id => l_enqu.id); END IF; -- END IF; -- manual or automatic quote - EXCEPTION + /* EXCEPTION WHEN OTHERS THEN - cout_err.report_and_stop; + cout_err.report_and_stop;*/ END produce_quotes; BEGIN