Alter bulk_load routines to match discussions with Gareth regarding costs.
Added 'quotation_text' and 'contact_text' to regions, to be used during quote document generation. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3494 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
@@ -1071,50 +1071,54 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
END load_housings;
|
||||
|
||||
PROCEDURE load_costs IS
|
||||
l_cost_enty_code VARCHAR2(20);
|
||||
BEGIN
|
||||
pl('load_costs');
|
||||
|
||||
IF NOT file_available('COSTS.csv') THEN
|
||||
pl('COSTS.csv file missing');
|
||||
IF NOT file_available('LABOUR_COSTS.csv') THEN
|
||||
pl('LABOUR_COSTS.csv file missing');
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF NOT file_available('MATERIAL_COSTS.csv') THEN
|
||||
pl('MATERIAL_COSTS.csv file missing');
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
--
|
||||
-- Additional Items
|
||||
--
|
||||
MERGE INTO costs cos
|
||||
USING (SELECT upper(field_1) AS field_1
|
||||
,field_2
|
||||
,field_3
|
||||
,field_4
|
||||
USING (SELECT upper(adit_code) AS adit_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
,CASE
|
||||
WHEN field_5 IS NULL THEN
|
||||
WHEN valid_from IS NULL THEN
|
||||
trunc(SYSDATE)
|
||||
ELSE
|
||||
to_date(field_5
|
||||
to_date(valid_from
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_5
|
||||
END AS valid_from
|
||||
,CASE
|
||||
WHEN field_6 IS NULL THEN
|
||||
WHEN valid_to IS NULL THEN
|
||||
NULL
|
||||
ELSE
|
||||
to_date(field_6
|
||||
to_date(valid_to
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_6
|
||||
,upper(field_7) AS field_7
|
||||
,upper(field_16) AS field_16
|
||||
FROM ext_costs
|
||||
WHERE upper(field_7) = 'AICO') e
|
||||
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_16 = cos.adit_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
|
||||
END AS valid_to
|
||||
FROM ext_material_costs
|
||||
WHERE upper(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
|
||||
SET selling_price = e.field_2
|
||||
,cost_price = e.field_3
|
||||
,delivery_cost = e.field_4
|
||||
,valid_to = e.field_6
|
||||
SET selling_price = e.selling_price
|
||||
,cost_price = e.cost_price
|
||||
,delivery_cost = e.delivery_cost
|
||||
,valid_to = e.valid_to
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
@@ -1124,14 +1128,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
,adit_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,e.field_1
|
||||
,e.field_2
|
||||
,e.field_3
|
||||
,e.field_4
|
||||
,e.field_5
|
||||
,e.field_6
|
||||
,e.field_7
|
||||
,e.field_16) log errors reject LIMIT unlimited;
|
||||
,e.selling_price
|
||||
,e.cost_price
|
||||
,e.delivery_cost
|
||||
,e.valid_from
|
||||
,e.valid_to
|
||||
,'AICO'
|
||||
,e.adit_code) log errors reject LIMIT unlimited;
|
||||
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') || ': additional_items');
|
||||
@@ -1139,39 +1142,36 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
-- Base costs
|
||||
--
|
||||
MERGE INTO costs cos
|
||||
USING (SELECT upper(field_1) AS field_1
|
||||
,field_2
|
||||
,field_3
|
||||
,field_4
|
||||
USING (SELECT upper(bas_code) AS bas_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
,CASE
|
||||
WHEN field_5 IS NULL THEN
|
||||
WHEN valid_from IS NULL THEN
|
||||
trunc(SYSDATE)
|
||||
ELSE
|
||||
to_date(field_5
|
||||
to_date(valid_from
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_5
|
||||
END AS valid_from
|
||||
,CASE
|
||||
WHEN field_6 IS NULL THEN
|
||||
WHEN valid_to IS NULL THEN
|
||||
NULL
|
||||
ELSE
|
||||
to_date(field_6
|
||||
to_date(valid_to
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_6
|
||||
,upper(field_7) AS field_7
|
||||
,upper(field_15) AS field_15
|
||||
FROM ext_costs
|
||||
WHERE upper(field_7) = 'BACO') e
|
||||
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_15 = cos.bas_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
|
||||
END AS valid_to
|
||||
FROM ext_material_costs
|
||||
WHERE upper(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
|
||||
SET selling_price = e.field_2
|
||||
,cost_price = e.field_3
|
||||
,delivery_cost = e.field_4
|
||||
,valid_to = e.field_6
|
||||
SET selling_price = e.selling_price
|
||||
,cost_price = e.cost_price
|
||||
,delivery_cost = e.delivery_cost
|
||||
,valid_to = e.valid_to
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
@@ -1181,14 +1181,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
,bas_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,e.field_1
|
||||
,e.field_2
|
||||
,e.field_3
|
||||
,e.field_4
|
||||
,e.field_5
|
||||
,e.field_6
|
||||
,e.field_7
|
||||
,e.field_15) log errors reject LIMIT unlimited;
|
||||
,e.selling_price
|
||||
,e.cost_price
|
||||
,e.delivery_cost
|
||||
,e.valid_from
|
||||
,e.valid_to
|
||||
,'BACO'
|
||||
,e.bas_code) log errors reject LIMIT unlimited;
|
||||
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') || ': bases');
|
||||
@@ -1196,39 +1195,36 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
-- Housing costs
|
||||
--
|
||||
MERGE INTO costs cos
|
||||
USING (SELECT upper(field_1) AS field_1
|
||||
,field_2
|
||||
,field_3
|
||||
,field_4
|
||||
USING (SELECT upper(hou_code) AS hou_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
,CASE
|
||||
WHEN field_5 IS NULL THEN
|
||||
WHEN valid_from IS NULL THEN
|
||||
trunc(SYSDATE)
|
||||
ELSE
|
||||
to_date(field_5
|
||||
to_date(valid_from
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_5
|
||||
END AS valid_from
|
||||
,CASE
|
||||
WHEN field_6 IS NULL THEN
|
||||
WHEN valid_to IS NULL THEN
|
||||
NULL
|
||||
ELSE
|
||||
to_date(field_6
|
||||
to_date(valid_to
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_6
|
||||
,upper(field_7) AS field_7
|
||||
,upper(field_14) AS field_14
|
||||
FROM ext_costs
|
||||
WHERE upper(field_7) = 'HOCO') e
|
||||
ON (((e.field_1 = cos.regi_code) OR (e.field_1 IS NULL AND cos.regi_code IS NULL)) AND e.field_14 = cos.hou_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
|
||||
END AS valid_to
|
||||
FROM ext_material_costs
|
||||
WHERE upper(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
|
||||
SET selling_price = e.field_2
|
||||
,cost_price = e.field_3
|
||||
,delivery_cost = e.field_4
|
||||
,valid_to = e.field_6
|
||||
SET selling_price = e.selling_price
|
||||
,cost_price = e.cost_price
|
||||
,delivery_cost = e.delivery_cost
|
||||
,valid_to = e.valid_to
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
@@ -1238,114 +1234,50 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
,hou_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,e.field_1
|
||||
,e.field_2
|
||||
,e.field_3
|
||||
,e.field_4
|
||||
,e.field_5
|
||||
,e.field_6
|
||||
,e.field_7
|
||||
,e.field_14) log errors reject LIMIT unlimited;
|
||||
,e.selling_price
|
||||
,e.cost_price
|
||||
,e.delivery_cost
|
||||
,e.valid_from
|
||||
,e.valid_to
|
||||
,'HOCO'
|
||||
,e.hou_code) log errors reject LIMIT unlimited;
|
||||
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') || ': housings');
|
||||
--
|
||||
-- Meter costs
|
||||
--
|
||||
MERGE INTO costs cos
|
||||
USING (SELECT upper(field_1) AS field_1
|
||||
,field_2
|
||||
,field_3
|
||||
,field_4
|
||||
,CASE
|
||||
WHEN field_5 IS NULL THEN
|
||||
trunc(SYSDATE)
|
||||
ELSE
|
||||
to_date(field_5
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_5
|
||||
,CASE
|
||||
WHEN field_6 IS NULL THEN
|
||||
NULL
|
||||
ELSE
|
||||
to_date(field_6
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_6
|
||||
,upper(field_7) AS field_7
|
||||
,upper(field_13) AS field_13
|
||||
FROM ext_costs
|
||||
WHERE upper(field_7) = 'MECO') e
|
||||
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_13 = cos.metr_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
|
||||
WHEN MATCHED THEN
|
||||
UPDATE
|
||||
SET selling_price = e.field_2
|
||||
,cost_price = e.field_3
|
||||
,delivery_cost = e.field_4
|
||||
,valid_to = e.field_6
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
,valid_from
|
||||
,valid_to
|
||||
,cost_type
|
||||
,metr_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,e.field_1
|
||||
,e.field_2
|
||||
,e.field_3
|
||||
,e.field_4
|
||||
,e.field_5
|
||||
,e.field_6
|
||||
,e.field_7
|
||||
,e.field_13) log errors reject LIMIT unlimited;
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') || ': meters');
|
||||
|
||||
--
|
||||
-- Module costs
|
||||
--
|
||||
MERGE INTO costs cos
|
||||
USING (SELECT DISTINCT upper(field_1) AS field_1
|
||||
,field_2
|
||||
,field_3
|
||||
,field_4
|
||||
,CASE
|
||||
WHEN field_5 IS NULL THEN
|
||||
trunc(SYSDATE)
|
||||
ELSE
|
||||
to_date(field_5
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_5
|
||||
,CASE
|
||||
WHEN field_6 IS NULL THEN
|
||||
NULL
|
||||
ELSE
|
||||
to_date(field_6
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_6
|
||||
,upper(field_7) AS field_7
|
||||
,upper(field_8) AS field_8
|
||||
,upper(field_9) AS field_9
|
||||
,upper(field_10) AS field_10
|
||||
,upper(field_12) AS field_12
|
||||
FROM ext_costs
|
||||
WHERE upper(field_7) = 'MOCO') e
|
||||
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_12 = cos.modu_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
|
||||
USING (SELECT upper(modu_code) AS modu_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
,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
|
||||
FROM ext_material_costs
|
||||
WHERE upper(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
|
||||
SET selling_price = e.field_2
|
||||
,cost_price = e.field_3
|
||||
,delivery_cost = e.field_4
|
||||
,valid_to = e.field_6
|
||||
SET selling_price = e.selling_price
|
||||
,cost_price = e.cost_price
|
||||
,delivery_cost = e.delivery_cost
|
||||
,valid_to = e.valid_to
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
@@ -1355,82 +1287,99 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
|
||||
,modu_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,e.field_1
|
||||
,e.field_2
|
||||
,e.field_3
|
||||
,e.field_4
|
||||
,e.field_5
|
||||
,e.field_6
|
||||
,e.field_7
|
||||
,e.field_12) log errors reject LIMIT unlimited;
|
||||
,e.selling_price
|
||||
,e.cost_price
|
||||
,e.delivery_cost
|
||||
,e.valid_from
|
||||
,e.valid_to
|
||||
,'MOCO'
|
||||
,e.modu_code) log errors reject LIMIT unlimited;
|
||||
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') || ': modules');
|
||||
--
|
||||
-- Labour costs
|
||||
--
|
||||
MERGE INTO costs cos
|
||||
USING (SELECT upper(field_1) AS field_1
|
||||
,field_2
|
||||
,field_3
|
||||
,field_4
|
||||
,CASE
|
||||
WHEN field_5 IS NULL THEN
|
||||
trunc(SYSDATE)
|
||||
ELSE
|
||||
to_date(field_5
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_5
|
||||
,CASE
|
||||
WHEN field_6 IS NULL THEN
|
||||
NULL
|
||||
ELSE
|
||||
to_date(field_6
|
||||
,'dd/mm/yyyy')
|
||||
END AS field_6
|
||||
,upper(field_7) AS field_7
|
||||
,upper(field_8) AS field_8
|
||||
,upper(field_9) AS field_9
|
||||
,upper(field_10) AS field_10
|
||||
,upper(field_11) AS field_11
|
||||
FROM ext_costs
|
||||
WHERE upper(field_7) = 'LACO') e
|
||||
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_8 = cos.enty_code AND e.field_5 = cos.valid_from AND e.field_11 = cos.mety_code AND e.field_7 = cos.cost_type AND ((e. field_9 IS NULL AND cos.mesc_code IS NULL) OR (e.field_9 = cos.mesc_code)) AND ((e.field_10 IS NULL AND cos.svcpt_code IS NULL) OR (e.field_10 = cos.svcpt_code)))
|
||||
WHEN MATCHED THEN
|
||||
UPDATE
|
||||
SET selling_price = e.field_2
|
||||
,cost_price = e.field_3
|
||||
,delivery_cost = e.field_4
|
||||
,valid_to = e.field_6
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,cost_price
|
||||
,delivery_cost
|
||||
,valid_from
|
||||
,valid_to
|
||||
,cost_type
|
||||
,enty_code
|
||||
,mesc_code
|
||||
,svcpt_code
|
||||
,mety_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,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) log errors reject LIMIT unlimited;
|
||||
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') || ': labour');
|
||||
FOR l_enty IN (SELECT code
|
||||
FROM enquiry_types) LOOP
|
||||
l_cost_enty_code := CASE l_enty.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;
|
||||
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(enty_code) AS enty_code
|
||||
,upper(mesc_code) AS mesc_code
|
||||
,upper(svcpt_code) AS svcpt_code
|
||||
,upper(mety_code) AS mety_code
|
||||
FROM ext_labour_costs
|
||||
WHERE upper(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
|
||||
SET selling_price = e.selling_price
|
||||
,valid_to = e.valid_to
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT
|
||||
(id
|
||||
,regi_code
|
||||
,selling_price
|
||||
,valid_from
|
||||
,valid_to
|
||||
,cost_type
|
||||
,enty_code
|
||||
,mesc_code
|
||||
,svcpt_code
|
||||
,mety_code)
|
||||
VALUES
|
||||
(cost_seq.NEXTVAL
|
||||
,'NETW0' || l_network
|
||||
,e.selling_price
|
||||
,e.valid_from
|
||||
,e.valid_to
|
||||
,'LACO'
|
||||
,l_enty.code
|
||||
,e.mesc_code
|
||||
,e.svcpt_code
|
||||
,e.mety_code) log errors reject LIMIT unlimited;
|
||||
|
||||
pl(to_char(SQL%ROWCOUNT
|
||||
,'FM099G999G999') ||': '|| l_enty.code || ':NETW0' ||
|
||||
l_network || ': labour');
|
||||
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
|
||||
END load_costs;
|
||||
|
||||
|
||||
Reference in New Issue
Block a user