Bulk Load: Changes to default values for 'unknown' items, inclusion of LeadTimes.csv

MIP_QUOTATION: Changes to make use of LeadTimes.csv

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3605 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-02-15 18:01:40 +00:00
parent 31e373438a
commit dfd3210818
21 changed files with 635 additions and 301 deletions

View File

@@ -7,12 +7,15 @@ CREATE OR REPLACE PACKAGE mip_bulk_load IS
g_flow_id NUMBER DEFAULT nvl(apex_application.g_flow_id
,155);
PROCEDURE init;
PROCEDURE load_meters;
PROCEDURE load_modules;
PROCEDURE load_drawings;
PROCEDURE load_bases;
PROCEDURE load_costs;
PROCEDURE load_postcodes;
PROCEDURE load_leadtimes;
PROCEDURE report_err;
@@ -140,6 +143,18 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
NULL;
END;
BEGIN
INSERT INTO relief_valves
(code
,rvty_code)
VALUES
('UNKNOWN'
,'UNKNOWN');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO slamshut_types
(code
@@ -152,6 +167,18 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
NULL;
END;
BEGIN
INSERT INTO slamshut_valves
(code
,slty_code)
VALUES
('UNKNOWN'
,'UNKNOWN');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO service_pressure_types
(code
@@ -192,11 +219,11 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_meters'
FROM (SELECT DISTINCT upper(field_3) AS code
FROM ext_meters
WHERE field_3 IS NOT NULL)
WHERE code NOT IN (SELECT code
,initcap(code)
FROM (SELECT DISTINCT upper(TRIM(mety_code)) AS code
FROM ext_meters)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM meter_types));
pl(to_char(SQL%ROWCOUNT
@@ -214,14 +241,14 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(SELECT prty_seq.NEXTVAL
,manu_ref
,manu_ref
,'Inserted for load_meters'
,initcap(manu_ref)
,'MANU'
,SYSDATE
,USER
FROM (SELECT DISTINCT upper(field_4) AS manu_ref
FROM ext_meters
WHERE field_4 IS NOT NULL)
WHERE manu_ref NOT IN (SELECT manu_ref
FROM (SELECT DISTINCT upper(TRIM(manu_ref)) AS manu_ref
FROM ext_meters)
WHERE manu_ref IS NOT NULL
AND manu_ref NOT IN (SELECT manu_ref
FROM parties
WHERE prty_type = 'MANU'));
@@ -233,63 +260,63 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_meters'
FROM (SELECT DISTINCT upper(field_2) AS code
FROM ext_meters
WHERE field_2 IS NOT NULL)
WHERE code NOT IN (SELECT code
,code
FROM (SELECT DISTINCT upper(TRIM(drwg_code)) AS code
FROM ext_meters)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM drawings));
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': drawings');
MERGE INTO meters metr
USING (SELECT upper(field_1) AS field_1
,upper(field_2) AS field_2
,upper(field_3) AS field_3
,p.id AS field_4
,field_5
,field_6
,field_7
,field_8
,field_9
,field_10
USING (SELECT upper(TRIM(code)) AS code
,upper(TRIM(drwg_code)) AS drwg_code
,upper(TRIM(mety_code)) AS mety_code
,p.id AS prty_id
,dim_a
,dim_b
,dim_c
,centres
,weight
,qmax
,CASE
WHEN field_11 IS NULL THEN
WHEN valid_from IS NULL THEN
SYSDATE
ELSE
to_date(field_11
to_date(valid_from
,'dd/mm/yyyy')
END AS field_11
END AS valid_from
,CASE
WHEN field_12 IS NULL THEN
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(field_12
to_date(valid_to
,'dd/mm/yyyy')
END AS field_12
,field_13
,field_14
END AS valid_to
,qmin
,qnom
FROM ext_meters
,parties p
WHERE p.manu_ref = field_4
WHERE p.manu_ref = upper(TRIM(ext_meters.manu_ref))
AND p.prty_type = 'MANU') e
ON (e.field_1 = metr.code)
ON (e.code = metr.code)
WHEN MATCHED THEN
UPDATE
SET drwg_code = e.field_2
,mety_code = e.field_3
,prty_id = e.field_4
,dim_a = e.field_5
,dim_b = e.field_6
,centres = e.field_7
,dim_c = e.field_8
,weight = e.field_9
,qmax = e.field_10
,valid_from = e.field_11
,valid_to = e.field_12
,qnom = e.field_13
,qmin = e.field_14
SET drwg_code = e.drwg_code
,mety_code = e.mety_code
,prty_id = e.prty_id
,dim_a = e.dim_a
,dim_b = e.dim_b
,centres = e.centres
,dim_c = e.dim_c
,weight = e.weight
,qmax = e.qmax
,valid_from = e.valid_from
,valid_to = e.valid_to
,qnom = e.qnom
,qmin = e.qmin
WHEN NOT MATCHED THEN
INSERT
(code
@@ -307,20 +334,20 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,qnom
,qmin)
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
,e.field_14) log errors reject LIMIT unlimited;
(e.code
,e.drwg_code
,e.mety_code
,e.prty_id
,e.dim_a
,e.dim_b
,e.centres
,e.dim_c
,e.weight
,e.qmax
,e.valid_from
,e.valid_to
,e.qnom
,e.qmin) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meters');
@@ -343,14 +370,15 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_modules'
,initcap(code)
FROM (SELECT DISTINCT code
FROM (SELECT upper(inlet_cnty_code) AS code
FROM (SELECT upper(TRIM(inlet_cnty_code)) AS code
FROM ext_modules
UNION
SELECT upper(outlet_cnty_code)
SELECT upper(TRIM(outlet_cnty_code))
FROM ext_modules))
WHERE code NOT IN (SELECT code
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM connection_types));
pl(to_char(SQL%ROWCOUNT
@@ -360,11 +388,12 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_modules'
FROM (SELECT DISTINCT upper(drwg_code) AS code
,code
FROM (SELECT DISTINCT upper(TRIM(drwg_code)) AS code
FROM ext_modules
WHERE drwg_code IS NOT NULL)
WHERE code NOT IN (SELECT code
WHERE TRIM(drwg_code) IS NOT NULL)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM drawings));
pl(to_char(SQL%ROWCOUNT
@@ -382,13 +411,14 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(SELECT prty_seq.NEXTVAL
,manu_ref
,manu_ref
,'Inserted for load_modules'
,initcap(manu_ref)
,'MANU'
,SYSDATE
,USER
FROM (SELECT DISTINCT upper(manu_ref) AS manu_ref
FROM (SELECT DISTINCT upper(TRIM(manu_ref)) AS manu_ref
FROM ext_modules)
WHERE manu_ref NOT IN (SELECT manu_ref
WHERE manu_ref IS NOT NULL
AND manu_ref NOT IN (SELECT manu_ref
FROM parties
WHERE prty_type = 'MANU'));
@@ -421,7 +451,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,.999
,.999
,trunc(SYSDATE)
FROM (SELECT DISTINCT nvl(upper(metr_code)
FROM (SELECT DISTINCT nvl(upper(TRIM(metr_code))
,'UNKNOWN') AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
@@ -440,9 +470,9 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'UNKNOWN'
,999
,999
FROM (SELECT DISTINCT upper(reva_code) AS code
FROM (SELECT DISTINCT upper(TRIM(reva_code)) AS code
FROM ext_modules
WHERE reva_code IS NOT NULL)
WHERE TRIM(reva_code) IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM relief_valves));
@@ -458,9 +488,9 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'UNKNOWN'
,999
,999
FROM (SELECT DISTINCT upper(slva_code) AS code
FROM (SELECT DISTINCT upper(TRIM(slva_code)) AS code
FROM ext_modules
WHERE slva_code IS NOT NULL)
WHERE TRIM(slva_code) IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM slamshut_valves));
@@ -474,10 +504,11 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,description)
(SELECT code
,'UNKNOWN'
,'Inserted for load_modules'
FROM (SELECT DISTINCT upper(svcp_code) AS code
,code
FROM (SELECT DISTINCT upper(TRIM(svcp_code)) AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM service_pressures));
pl(to_char(SQL%ROWCOUNT
@@ -500,7 +531,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,depth)
(SELECT code
,'UNKNOWN'
,'Inserted for load_modules'
,code
,999
,999
,999
@@ -511,10 +542,10 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,999
,999
,999
FROM (SELECT DISTINCT upper(bas_code) AS code
FROM ext_modules
WHERE bas_code IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM (SELECT DISTINCT upper(TRIM(bas_code)) AS code
FROM ext_modules)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM bases));
pl(to_char(SQL%ROWCOUNT
@@ -535,15 +566,15 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'UNKNOWN'
,'UNKNOWN'
,g_unknown_manufacturer_id
,'Inserted for load_modules'
,code
,999
,999
,999
,999
FROM (SELECT DISTINCT upper(hou_code) AS code
FROM ext_modules
WHERE hou_code IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM (SELECT DISTINCT upper(TRIM(hou_code)) AS code
FROM ext_modules)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM housings));
pl(to_char(SQL%ROWCOUNT
@@ -558,13 +589,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,lock_up)
(SELECT code
,'UNKNOWN'
,'Inserted for load_modules'
,code
,999
,999
FROM (SELECT DISTINCT upper(regu_code) AS code
FROM ext_modules
WHERE regu_code IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM (SELECT DISTINCT upper(TRIM(regu_code)) AS code
FROM ext_modules)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM regulators));
pl(to_char(SQL%ROWCOUNT
@@ -578,10 +609,10 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(SELECT code
,'UNKNOWN'
,999
FROM (SELECT DISTINCT upper(fltr_code) AS code
FROM ext_modules
WHERE fltr_code IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM (SELECT DISTINCT upper(TRIM(fltr_code)) AS code
FROM ext_modules)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM filters));
pl(to_char(SQL%ROWCOUNT
@@ -592,12 +623,12 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_modules'
,initcap(code)
FROM (SELECT DISTINCT code
FROM (SELECT upper(inlet_cnor_code) AS code
FROM (SELECT upper(TRIM(inlet_cnor_code)) AS code
FROM ext_modules
UNION
SELECT upper(outlet_cnor_code)
SELECT upper(TRIM(outlet_cnor_code))
FROM ext_modules)
WHERE code IS NOT NULL)
WHERE code NOT IN (SELECT code
@@ -607,24 +638,24 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'FM099G999G999') || ': connection_orientations');
MERGE INTO modules modu
USING (SELECT upper(code) AS code
,upper(outlet_cnty_code) AS outlet_cnty_code
,upper(inlet_cnty_code) AS inlet_cnty_code
,upper(drwg_code) AS drwg_code
,upper(metr_code) AS metr_code
,upper(nvl(reva_code
USING (SELECT upper(TRIM(code)) AS code
,upper(TRIM(outlet_cnty_code)) AS outlet_cnty_code
,upper(TRIM(inlet_cnty_code)) AS inlet_cnty_code
,upper(TRIM(drwg_code)) AS drwg_code
,upper(TRIM(metr_code)) AS metr_code
,upper(nvl(TRIM(reva_code)
,'UNKNOWN')) AS reva_code
,upper(nvl(slva_code
,upper(nvl(TRIM(slva_code)
,'UNKNOWN')) AS slva_code
,upper(svcp_code) AS svcp_code
,upper(TRIM(svcp_code)) AS svcp_code
,weight
,inlet_height
,inlet_size
,outlet_pressure
,outlet_height
,outlet_size
,upper(bas_code) AS bas_code
,upper(hou_code) AS hou_code
,upper(TRIM(bas_code)) AS bas_code
,upper(TRIM(hou_code)) AS hou_code
,dim_a
,dim_b
,dim_c
@@ -645,16 +676,16 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
to_date(valid_to
,'dd/mm/yyyy')
END AS valid_to
,upper(regu_code) AS regu_code
,upper(fltr_code) AS fltr_code
,upper(inlet_cnor_code) AS inlet_cnor_code
,upper(outlet_cnor_code) AS outlet_cnor_code
,upper(TRIM(regu_code)) AS regu_code
,upper(TRIM(fltr_code)) AS fltr_code
,upper(TRIM(inlet_cnor_code)) AS inlet_cnor_code
,upper(TRIM(outlet_cnor_code)) AS outlet_cnor_code
,lead_time
,p.id AS prty_id
,qmax
FROM ext_modules e
,parties p
WHERE p.manu_ref = upper(e.manu_ref)
WHERE p.manu_ref = upper(TRIM(e.manu_ref))
AND p.prty_type = 'MANU') e
ON (upper(e.code) = modu.code)
WHEN MATCHED THEN
@@ -709,6 +740,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,dim_a
,dim_b
,dim_c
,dim_d
,dim_e
,dim_h
,valid_from
@@ -740,6 +772,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,e.dim_a
,e.dim_b
,e.dim_c
,e.dim_d
,e.dim_e
,e.dim_h
,e.valid_from
@@ -824,7 +857,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,description)
VALUES
(l_rec.drwg_code
,'Inserted for load_drawings');
,l_rec.drwg_code);
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
@@ -893,17 +926,17 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_bases'
FROM (SELECT DISTINCT upper(field_2) AS code
,code
FROM (SELECT DISTINCT upper(TRIM(field_2)) AS code
FROM ext_bases
WHERE field_2 IS NOT NULL)
WHERE TRIM(field_2) IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM drawings));
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': drawings');
MERGE INTO bases bas
USING (SELECT upper(field_1) AS field_1
,upper(field_2) AS field_2
USING (SELECT upper(TRIM(field_1)) AS field_1
,upper(TRIM(field_2)) AS field_2
,field_3
,field_4
,field_5
@@ -920,7 +953,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
WHEN MATCHED THEN
UPDATE
SET drwg_code = e.field_2
,description = e.field_3
,description = nvl(e.field_3,initcap(e.field_1))
,dim_a = e.field_4
,dim_b = e.field_5
,dim_c = e.field_6
@@ -949,7 +982,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
VALUES
(e.field_1
,e.field_2
,e.field_3
,nvl(e.field_3,initcap(e.field_1))
,e.field_4
,e.field_5
,e.field_6
@@ -987,13 +1020,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(SELECT prty_seq.NEXTVAL
,manu_ref
,manu_ref
,'Inserted for load_housings'
,initcap(manu_ref)
,'MANU'
,SYSDATE
,USER
FROM (SELECT DISTINCT upper(field_2) AS manu_ref
FROM (SELECT DISTINCT upper(TRIM(field_2)) AS manu_ref
FROM ext_housings
WHERE field_2 IS NOT NULL)
WHERE TRIM(field_2) IS NOT NULL)
WHERE manu_ref NOT IN (SELECT manu_ref
FROM parties
WHERE prty_type = 'MANU'));
@@ -1005,10 +1038,10 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_housings'
FROM (SELECT DISTINCT upper(field_3) AS code
,code
FROM (SELECT DISTINCT upper(TRIM(field_3)) AS code
FROM ext_housings
WHERE field_3 IS NOT NULL)
WHERE TRIM(field_3) IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM drawings));
pl(to_char(SQL%ROWCOUNT
@@ -1020,19 +1053,19 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,description)
(SELECT code
,initcap(code)
FROM (SELECT DISTINCT upper(field_4) AS code
FROM (SELECT DISTINCT upper(TRIM(field_4)) AS code
FROM ext_housings
WHERE field_4 IS NOT NULL)
WHERE TRIM(field_4) IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM housing_types));
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': housing_types');
MERGE INTO housings hou
USING (SELECT upper(field_1) AS field_1
USING (SELECT upper(TRIM(field_1)) AS field_1
,p.id AS field_2
,upper(field_3) AS field_3
,upper(field_4) AS field_4
,upper(TRIM(field_3)) AS field_3
,upper(TRIM(field_4)) AS field_4
,field_5
,field_6
,field_7
@@ -1040,7 +1073,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,field_9
FROM ext_housings
,parties p
WHERE p.manu_ref = upper(field_2)
WHERE p.manu_ref = upper(TRIM(field_2))
AND p.prty_type = 'MANU') e
ON (e.field_1 = hou.code)
WHEN MATCHED THEN
@@ -1048,7 +1081,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
SET prty_id = e.field_2
,drwg_code = e.field_3
,hoty_code = e.field_4
,description = e.field_5
,description = nvl(e.field_5,initcap(e.field_1))
,dim_w = e.field_6
,dim_h = e.field_7
,dim_l = e.field_8
@@ -1069,7 +1102,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,nvl(e.field_5, initcap(e.field_1))
,e.field_6
,e.field_7
,e.field_8
@@ -1099,7 +1132,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Additional Items
--
MERGE INTO costs cos
USING (SELECT upper(adit_code) AS adit_code
USING (SELECT upper(TRIM(adit_code)) AS adit_code
,selling_price
,cost_price
,delivery_cost
@@ -1118,7 +1151,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'dd/mm/yyyy')
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'AICO') e
WHERE upper(TRIM(cost_type)) = 'AICO') e
ON (e.adit_code = cos.adit_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'AICO')
WHEN MATCHED THEN
UPDATE
@@ -1152,7 +1185,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Base costs
--
MERGE INTO costs cos
USING (SELECT upper(bas_code) AS bas_code
USING (SELECT upper(TRIM(bas_code)) AS bas_code
,selling_price
,cost_price
,delivery_cost
@@ -1171,7 +1204,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'dd/mm/yyyy')
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'BACO') e
WHERE upper(TRIM(cost_type)) = 'BACO') e
ON (e.bas_code = cos.bas_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'BACO')
WHEN MATCHED THEN
UPDATE
@@ -1205,7 +1238,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Housing costs
--
MERGE INTO costs cos
USING (SELECT upper(hou_code) AS hou_code
USING (SELECT upper(TRIM(hou_code)) AS hou_code
,selling_price
,cost_price
,delivery_cost
@@ -1224,7 +1257,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'dd/mm/yyyy')
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'HOCO') e
WHERE upper(TRIM(cost_type)) = 'HOCO') e
ON (e.hou_code = cos.hou_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'HOCO')
WHEN MATCHED THEN
UPDATE
@@ -1258,7 +1291,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Module costs
--
MERGE INTO costs cos
USING (SELECT upper(modu_code) AS modu_code
USING (SELECT upper(TRIM(modu_code)) AS modu_code
,selling_price
,cost_price
,delivery_cost
@@ -1277,7 +1310,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,'dd/mm/yyyy')
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'MOCO') e
WHERE upper(TRIM(cost_type)) = 'MOCO') e
ON (e.modu_code = cos.modu_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'MOCO')
WHEN MATCHED THEN
UPDATE
@@ -1349,12 +1382,14 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
to_date(valid_to
,'dd/mm/yyyy')
END AS valid_to
,upper(enty_code) AS enty_code
,upper(replace(mesc_code,'"','inch')) AS mesc_code
,upper(svcpt_code) AS svcpt_code
,upper(mety_code) AS mety_code
,upper(TRIM(enty_code)) AS enty_code
,upper(REPLACE(TRIM(mesc_code)
,'"'
,'inch')) AS mesc_code
,upper(TRIM(svcpt_code)) AS svcpt_code
,upper(TRIM(mety_code)) AS mety_code
FROM ext_labour_costs
WHERE upper(enty_code) = l_cost_enty_code) e
WHERE upper(TRIM(enty_code)) = l_cost_enty_code) e
ON (e.enty_code = cos.enty_code AND e.valid_from = cos.valid_from AND e.mety_code = cos.mety_code AND cos.cost_type = 'LACO' AND ((e. mesc_code IS NULL AND cos.mesc_code IS NULL) OR (e.mesc_code = cos.mesc_code)) AND ((e.svcpt_code IS NULL AND cos.svcpt_code IS NULL) OR (e.svcpt_code = cos.svcpt_code)))
WHEN MATCHED THEN
UPDATE
@@ -1405,12 +1440,12 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Caveats
--
MERGE INTO caveat_texts
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
,upper(field_5) AS field_5
,field_6
USING (SELECT upper(TRIM(field_1)) AS field_1
,upper(TRIM(field_2)) AS field_2
,upper(TRIM(field_3)) AS field_3
,upper(TRIM(field_4)) AS field_4
,upper(TRIM(field_5)) AS field_5
,TRIM(field_6) AS field_6
FROM ext_caveats) e
ON (field_1 = document_position AND field_2 = enty_code AND field_3 = mety_code AND field_4 = svcpt_code AND ((field_5 = sort_order) OR (field_5 IS NULL AND sort_order IS NULL)))
WHEN MATCHED THEN
@@ -1454,8 +1489,8 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(code
,description)
(SELECT code
,'Inserted for load_postcodes'
FROM (SELECT DISTINCT upper(field_2) AS code
,initcap(code)
FROM (SELECT DISTINCT upper(TRIM(field_2)) AS code
FROM ext_postcodes)
WHERE code NOT IN (SELECT code
FROM regions));
@@ -1466,7 +1501,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
DELETE FROM postcodes
WHERE ROWID NOT IN (SELECT p.ROWID
FROM postcodes p
,(SELECT CASE instr(field_1
,(SELECT CASE instr(TRIM(field_1)
,' ')
WHEN 0 THEN
upper(field_1)
@@ -1476,13 +1511,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,instr(field_1
,' ') - 1))
END AS outcode
,CASE instr(field_1
,CASE instr(TRIM(field_1)
,' ')
WHEN 0 THEN
NULL
ELSE
substr(field_1
,instr(field_1
substr(TRIM(field_1)
,instr(TRIM(field_1)
,' ') + 1)
END AS incode
FROM ext_postcodes) e
@@ -1497,26 +1532,26 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Postcodes
--
MERGE INTO postcodes p
USING (SELECT CASE instr(field_1
USING (SELECT CASE instr(TRIM(field_1)
,' ')
WHEN 0 THEN
upper(field_1)
upper(TRIM(field_1))
ELSE
upper(substr(field_1
upper(substr(TRIM(field_1)
,1
,instr(field_1
,instr(TRIM(field_1)
,' ') - 1))
END AS outcode
,CASE instr(field_1
,CASE instr(TRIM(field_1)
,' ')
WHEN 0 THEN
NULL
ELSE
substr(field_1
,instr(field_1
substr(TRIM(field_1)
,instr(TRIM(field_1)
,' ') + 1)
END AS incode
,upper(field_2) AS regi_code
,upper(TRIM(field_2)) AS regi_code
FROM ext_postcodes) e
ON (e.outcode = p.outcode AND ((e.incode = p.incode) OR (e.incode IS NULL AND p.incode IS NULL)))
WHEN MATCHED THEN
@@ -1539,6 +1574,80 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
END load_postcodes;
PROCEDURE load_leadtimes IS
l_enty_code enquiry_types.code%TYPE;
BEGIN
--
-- leadtimes
--
IF NOT file_available('LEADTIMES.csv') THEN
pl('LEADTIMES.csv file missing');
RETURN;
END IF;
DELETE FROM lead_times;
MERGE INTO lead_times leti
USING (SELECT enty.code AS enty_code
,upper(TRIM(mety_code)) AS mety_code
,upper(TRIM(mesc_code)) AS mesc_code
,upper(TRIM(svcpt_code)) AS svcpt_code
,upper(TRIM(lead_time)) AS days
FROM ext_leadtimes el
,(SELECT CASE code
WHEN 'ADDON' THEN
'ADDON'
WHEN 'ADVERSARIAL' THEN
'REMOVE'
WHEN 'CHANGE CAPACITY' THEN
'CHANGE CAPACITY'
WHEN 'EXCHANGE' THEN
'EXCHANGE'
WHEN 'INSTALL' THEN
'INSTALL'
WHEN 'OFMAT' THEN
'OFMAT'
WHEN 'OTHER' THEN
'OTHER'
WHEN 'REMOVE' THEN
'REMOVE'
WHEN 'STD EXCHANGE' THEN
'EXCHANGE'
WHEN 'STD INSTALL' THEN
'INSTALL'
WHEN 'STD REMOVE' THEN
'REMOVE'
ELSE
NULL
END AS l_enty_code
,code
FROM enquiry_types) enty
WHERE upper(TRIM(enty_code)) = l_enty_code) e
ON (e.enty_code = leti.enty_code AND e.mety_code = leti.mety_code AND ((e.mesc_code = leti.mesc_code) OR (e.mesc_code IS NULL AND leti.mesc_code IS NULL)) AND ((e.svcpt_code = leti.svcpt_code) OR (e.svcpt_code IS NULL AND leti.svcpt_code IS NULL)))
WHEN MATCHED THEN
UPDATE
SET days = e.days
WHEN NOT MATCHED THEN
INSERT
(id
,enty_code
,mety_code
,mesc_code
,svcpt_code
,days)
VALUES
(leti_seq.NEXTVAL
,e.enty_code
,e.mety_code
,e.mesc_code
,e.svcpt_code
,e.days) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': leadtimes - merge');
END load_leadtimes;
PROCEDURE init IS
l_sgid NUMBER;
BEGIN
@@ -1630,6 +1739,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
load_costs;
load_caveats;
load_postcodes;
load_leadtimes;
report_err;