Changes made for bulk load and 'flange size' (MESC_CODE on meters).

Store images used by the WebServer

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3797 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-02-29 17:27:39 +00:00
parent 6dbf407063
commit 5649f4b934
25 changed files with 16249 additions and 15839 deletions

View File

@@ -12,6 +12,7 @@ CREATE OR REPLACE PACKAGE mip_bulk_load IS
PROCEDURE load_meters;
PROCEDURE load_modules;
PROCEDURE load_drawings;
PROCEDURE load_housings;
PROCEDURE load_bases;
PROCEDURE load_costs;
PROCEDURE load_postcodes;
@@ -203,6 +204,19 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
NULL;
END;
/* BEGIN
INSERT INTO meter_size_codes
(code
,description
,QMAX,valid_for_existing_meter,valid_for_new_meter)
VALUES
('UNKNOWN'
,'Unknown Meter Size - inserted for bulk load'
,0,'NO','NO');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;*/
END get_globals;
PROCEDURE load_meters IS
@@ -228,6 +242,28 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meter_types');
-- Meter Sizes
INSERT INTO meter_size_codes
(code
,description
,qmax
,valid_for_existing_meter
,valid_for_new_meter)
(SELECT code
,initcap(code)
,0
,'YES'
,'NO'
FROM (SELECT DISTINCT upper(REPLACE(TRIM(mesc_code)
,'"'
,'inch')) AS code
FROM ext_meters)
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
FROM meter_size_codes));
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meter_size_codes');
-- Manufacturers
INSERT INTO parties
@@ -297,6 +333,9 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
END AS valid_to
,qmin
,qnom
,upper(REPLACE(TRIM(mesc_code)
,'"'
,'inch')) AS mesc_code
FROM ext_meters
,parties p
WHERE p.manu_ref = upper(TRIM(ext_meters.manu_ref))
@@ -317,6 +356,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,valid_to = e.valid_to
,qnom = e.qnom
,qmin = e.qmin
,mesc_code = e.mesc_code
WHEN NOT MATCHED THEN
INSERT
(code
@@ -332,7 +372,8 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,valid_from
,valid_to
,qnom
,qmin)
,qmin
,mesc_code)
VALUES
(e.code
,e.drwg_code
@@ -347,7 +388,8 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,e.valid_from
,e.valid_to
,e.qnom
,e.qmin) log errors reject LIMIT unlimited;
,e.qmin
,e.mesc_code) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meters');
@@ -372,10 +414,14 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
(SELECT code
,initcap(code)
FROM (SELECT DISTINCT code
FROM (SELECT upper(TRIM(inlet_cnty_code)) AS code
FROM (SELECT upper(REPLACE(TRIM(inlet_cnty_code)
,'"'
,'inch')) AS code
FROM ext_modules
UNION
SELECT upper(TRIM(outlet_cnty_code))
SELECT upper(REPLACE(TRIM(outlet_cnty_code)
,'"'
,'inch'))
FROM ext_modules))
WHERE code IS NOT NULL
AND code NOT IN (SELECT code
@@ -425,41 +471,43 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': manufacturers');
-- Meters
INSERT INTO meters
(code
,mety_code
,prty_id
,dim_a
,dim_b
,dim_c
,centres
,weight
,qmax
,qmin
,qnom
,valid_from)
(SELECT code
,'UNKNOWN'
,g_unknown_manufacturer_id
,999
,999
,999
,999
,999
,.999
,.999
,.999
,trunc(SYSDATE)
FROM (SELECT DISTINCT nvl(upper(TRIM(metr_code))
,'UNKNOWN') AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
FROM meters));
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meters');
/*-- Meters
INSERT INTO meters
(code
,mety_code
,prty_id
,dim_a
,dim_b
,dim_c
,centres
,weight
,qmax
,qmin
,qnom
,valid_from
,mesc_code)
(SELECT code
,'UNKNOWN'
,g_unknown_manufacturer_id
,999
,999
,999
,999
,999
,.999
,.999
,.999
,trunc(SYSDATE)
,'UNKNOWN'
FROM (SELECT DISTINCT nvl(upper(TRIM(metr_code))
,'UNKNOWN') AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
FROM meters));
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meters');
*/
-- Relief valves
INSERT INTO relief_valves
(code
@@ -639,14 +687,16 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
MERGE INTO modules modu
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(REPLACE(TRIM(outlet_cnty_code)
,'"'
,'inch')) AS outlet_cnty_code
,upper(REPLACE(TRIM(inlet_cnty_code)
,'"'
,'inch')) AS inlet_cnty_code
,upper(TRIM(drwg_code)) AS drwg_code
,upper(TRIM(metr_code)) AS metr_code
,upper(TRIM(reva_code)
) AS reva_code
,upper(TRIM(slva_code)
) AS slva_code
,upper(TRIM(reva_code)) AS reva_code
,upper(TRIM(slva_code)) AS slva_code
,upper(TRIM(svcp_code)) AS svcp_code
,weight
,inlet_height
@@ -710,7 +760,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,dim_b = e.dim_b
,dim_c = e.dim_c
,dim_e = e.dim_e
,dim_f = e.dim_f
,dim_f = e.dim_f
,dim_h = e.dim_h
,valid_from = e.valid_from
,valid_to = e.valid_to
@@ -957,7 +1007,8 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
WHEN MATCHED THEN
UPDATE
SET drwg_code = e.field_2
,description = nvl(e.field_3,initcap(e.field_1))
,description = nvl(e.field_3
,initcap(e.field_1))
,dim_a = e.field_4
,dim_b = e.field_5
,dim_c = e.field_6
@@ -986,7 +1037,8 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
VALUES
(e.field_1
,e.field_2
,nvl(e.field_3,initcap(e.field_1))
,nvl(e.field_3
,initcap(e.field_1))
,e.field_4
,e.field_5
,e.field_6
@@ -1085,7 +1137,8 @@ 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 = nvl(e.field_5,initcap(e.field_1))
,description = nvl(e.field_5
,initcap(e.field_1))
,dim_w = e.field_6
,dim_h = e.field_7
,dim_l = e.field_8
@@ -1106,7 +1159,8 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,e.field_2
,e.field_3
,e.field_4
,nvl(e.field_5, initcap(e.field_1))
,nvl(e.field_5
,initcap(e.field_1))
,e.field_6
,e.field_7
,e.field_8
@@ -1354,47 +1408,50 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
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;
FOR l_network IN 1 .. 8 LOOP
MERGE INTO costs cos
USING (SELECT CASE l_network
WHEN 1 THEN
netw01_selling_price
WHEN 2 THEN
netw02_selling_price
WHEN 3 THEN
netw03_selling_price
WHEN 4 THEN
netw04_selling_price
WHEN 5 THEN
netw05_selling_price
WHEN 6 THEN
netw06_selling_price
WHEN 7 THEN
netw07_selling_price
WHEN 8 THEN
netw08_selling_price
END AS selling_price
,CASE
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(valid_from
,'dd/mm/yyyy')
END AS valid_from
,CASE
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(valid_to
,'dd/mm/yyyy')
END AS valid_to
,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(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)))
USING (SELECT *
FROM (SELECT CASE l_network
WHEN 1 THEN
netw01_selling_price
WHEN 2 THEN
netw02_selling_price
WHEN 3 THEN
netw03_selling_price
WHEN 4 THEN
netw04_selling_price
WHEN 5 THEN
netw05_selling_price
WHEN 6 THEN
netw06_selling_price
WHEN 7 THEN
netw07_selling_price
WHEN 8 THEN
netw08_selling_price
END AS selling_price
,'NETW0' || l_network AS regi_code
,CASE
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(valid_from
,'dd/mm/yyyy')
END AS valid_from
,CASE
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(valid_to
,'dd/mm/yyyy')
END AS valid_to
,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(TRIM(enty_code)) = l_cost_enty_code)
WHERE selling_price IS NOT NULL) 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.regi_code = cos.regi_code) OR (e.regi_code IS NULL AND cos.regi_code IS NULL)) 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
SET selling_price = e.selling_price
@@ -1413,7 +1470,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,mety_code)
VALUES
(cost_seq.NEXTVAL
,'NETW0' || l_network
,e.regi_code
,e.selling_price
,e.valid_from
,e.valid_to
@@ -1585,11 +1642,11 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
--
-- leadtimes
--
IF NOT file_available('LEADTIMES.csv') THEN
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