mip_quotation.pck - create quote entries for manual quotes. Automatic quotes call PDF build routine. Mark automatic quotes as available.

mip_bulk_load.pck - initial work on bulk data load .

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3181 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-01-09 20:06:30 +00:00
parent 8b2ced5818
commit a3765e8f3c
2 changed files with 665 additions and 40 deletions

View File

@@ -5,17 +5,148 @@ CREATE OR REPLACE PACKAGE mip_bulk_load IS
-- Purpose : Bulk data load routines
PROCEDURE load_meters;
PROCEDURE load_modules;
END mip_bulk_load;
/
CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
PROCEDURE load_manufacturers IS
g_unknown_manufacturer_id parties.id%TYPE;
PROCEDURE get_globals IS
BEGIN
BEGIN
SELECT id
INTO g_unknown_manufacturer_id
FROM parties
WHERE NAME = 'UNKNOWN'
AND prty_type = 'MANU';
EXCEPTION
WHEN no_data_found THEN
INSERT INTO parties
(id
,NAME
,manu_ref
,description
,prty_type
,created_on
,created_by)
VALUES
(prty_seq.NEXTVAL
,'UNKNOWN'
,'UNKNOWN'
,'Unknown Manufacturer - inserted for bulk load'
,'MANU'
,SYSDATE
,USER)
RETURNING id INTO g_unknown_manufacturer_id;
END;
BEGIN
INSERT INTO meter_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Meter Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO housing_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Housing Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO regulator_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Regulator Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO filter_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Filter Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO relief_valve_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Relief Valve Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO slamshut_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Slamshut Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO service_pressure_types
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Service Pressure Type - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
BEGIN
INSERT INTO drawings
(code
,description)
VALUES
('UNKNOWN'
,'Unknown Drawing - inserted for bulk load');
EXCEPTION
WHEN dup_val_on_index THEN
NULL;
END;
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_meter) e_metr
FROM ext_meters) e_metr
ON (upper(e_metr.field_1) = upper(prty.manu_ref))
WHEN NOT MATCHED THEN
INSERT
@@ -29,7 +160,7 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
VALUES
(upper(e_metr.field_1)
,e_metr.field_1
,'Inserted missing manufacturer (EXT_METR)'
,'Inserted missing manufacturer - ' || p_reason
,SYSDATE
,USER
,'MANU'
@@ -39,9 +170,359 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
PROCEDURE load_meters IS
BEGIN
load_manufacturers;
-- Meter Types
INSERT INTO meter_types
(code
,description
)
(SELECT manu_ref
,'Inserted for load_meters'
FROM (SELECT DISTINCT upper(field_3) AS manu_ref
FROM ext_meters
WHERE field_3 IS NOT NULL)
WHERE manu_ref NOT IN (SELECT manu_ref
FROM parties));
-- Manufacturers
INSERT INTO parties
(id
,manu_ref
,description
,prty_type
,created_on
,created_by)
(SELECT prty_seq.NEXTVAL
,manu_ref
,'Inserted for load_meters'
,'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 parties));
-- Drawings
INSERT INTO drawings
(code
,description)
(SELECT code
,'Inserted for load_modules'
FROM (SELECT DISTINCT field_4 AS code
FROM ext_meters
WHERE field_4 IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM 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
,upper(field_4) AS field_4
,field_5
,field_6
,field_7
,field_8
,field_9
,field_10
,field_11
,field_12
,field_13
,field_14
FROM ext_meters) e
ON (e.field_1 = metr.code)
WHEN MATCHED THEN
UPDATE
SET drwg_code = e.field_2
,mety_code = e.field_3
,prty_id = (SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e.field_4)
AND p.prty_type = 'MANU')
,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 = CASE WHEN e.field_11 IS NULL THEN SYSDATE ELSE to_date(e.field_11, 'dd/mm/yyyy') END
,valid_to = CASE WHEN e.field_12 IS NULL THEN NULL ELSE to_date(e.field_12, 'dd/mm/yyyy') END
,qnom = e.field_13
,qmin = e.field_14
WHEN NOT MATCHED THEN
INSERT
(code
,drwg_code
,mety_code
,prty_id
,dim_a
,dim_b
,centres
,dim_c
,weight
,qmax
,valid_from
,valid_to
,qnom
,qmin)
VALUES
(e.field_1
,e.field_2
,e.field_3
,(SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e.field_4)
AND p.prty_type = 'MANU')
,e.field_5
,e.field_6
,e.field_7
,e.field_8
,e.field_9
,e.field_10
,CASE WHEN e.field_11 IS NULL THEN SYSDATE ELSE to_date(e.field_11
,'dd/mm/yyyy') END
,CASE WHEN e.field_12 IS NULL THEN NULL ELSE to_date(e.field_12
,'dd/mm/yyyy') END
,e.field_13
,e.field_14) log errors reject LIMIT unlimited;
END load_meters;
PROCEDURE load_modules IS
BEGIN
-- Add any missing foreign key objects
-- Connection types
INSERT INTO connection_types
(code
,description)
(SELECT code
,'Inserted for load_modules'
FROM (SELECT DISTINCT code
FROM (SELECT field_2 AS code
FROM ext_modules
UNION
SELECT field_3
FROM ext_modules))
WHERE code NOT IN (SELECT code
FROM connection_types));
-- Drawings
INSERT INTO drawings
(code
,description)
(SELECT code
,'Inserted for load_modules'
FROM (SELECT DISTINCT field_4 AS code
FROM ext_modules
WHERE field_4 IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM drawings));
-- Manufacturers
INSERT INTO parties
(id
,manu_ref
,description
,prty_type
,created_on
,created_by)
(SELECT prty_seq.NEXTVAL
,manu_ref
,'Inserted for load_modules'
,'MANU'
,SYSDATE
,USER
FROM (SELECT DISTINCT upper(field_30) AS manu_ref
FROM ext_modules
WHERE field_30 IS NOT NULL)
WHERE manu_ref NOT IN (SELECT manu_ref
FROM parties));
-- 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(field_5,'UNKNOWN') AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
FROM meters));
-- Relief valves
INSERT INTO relief_valves
(code
,rvty_code
,relief_valve_size
,relief_valve_setting)
(SELECT code
,'UNKNOWN'
,999
,999
FROM (SELECT DISTINCT field_6 AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
FROM relief_valves));
-- Slamshut valves
INSERT INTO slamshut_valves
(code
,slty_code
,slamshut_size
,slamshut_setting)
(SELECT code
,'UNKNOWN'
,999
,999
FROM (SELECT DISTINCT field_7 AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
FROM slamshut_valves));
-- Service pressures
INSERT INTO service_pressures
(code
,svcpt_code
,description)
(SELECT code
,'UNKNOWN'
,'Inserted for load_modules'
FROM (SELECT DISTINCT field_8 AS code
FROM ext_modules)
WHERE code NOT IN (SELECT code
FROM service_pressures));
-- Bases
INSERT INTO bases
(code
,drwg_code
,description
,dim_a
,dim_b
,dim_c
,dim_d
,dim_e
,dim_f
,dim_g
,dim_h
,dim_i
,depth)
(SELECT code
,'UNKNOWN'
,'Inserted for load_modules'
,999
,999
,999
,999
,999
,999
,999
,999
,999
,999
FROM (SELECT DISTINCT field_15 AS code
FROM ext_modules
WHERE field_15 IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM bases));
-- Housings
INSERT INTO housings
(code
,drwg_code
,hoty_code
,prty_id
,description
,dim_l
,dim_w
,dim_h
,weight)
(SELECT code
,'UNKNOWN'
,'UNKNOWN'
,g_unknown_manufacturer_id
,'Inserted for load_modules'
,999
,999
,999
,999
FROM (SELECT DISTINCT field_16 AS code
FROM ext_modules
WHERE field_16 IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM housings));
-- Regulators
INSERT INTO regulators
(code
,rety_code
,description
,regulator_size
,lock_up)
(SELECT code
,'UNKNOWN'
,'Inserted for load_modules'
,999
,999
FROM (SELECT DISTINCT field_25 AS code
FROM ext_modules
WHERE field_25 IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM regulators));
-- Filters
INSERT INTO filters
(code
,fity_code
,filter_size)
(SELECT code
,'UNKNOWN'
,999
FROM (SELECT DISTINCT field_26 AS code
FROM ext_modules
WHERE field_26 IS NOT NULL)
WHERE code NOT IN (SELECT code
FROM filters));
-- Connection orientations
INSERT INTO connection_orientations
(code
,description)
(SELECT code
,'Inserted for load_modules'
FROM (SELECT DISTINCT code
FROM (SELECT field_27 AS code
FROM ext_modules
UNION
SELECT 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
@@ -54,49 +535,139 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,field_10
,field_11
,field_12
FROM ext_meter) e_metr
ON (e_metr.field_2 = metr.code)
,field_13
,field_14
,field_15
,field_16
,field_17
,field_18
,field_19
,field_20
,field_21
,field_22
,field_23
,field_24
,field_25
,field_26
,field_27
,field_28
,field_29
,field_30
FROM ext_modules) e
ON (e.field_1 = modu.code)
WHEN MATCHED THEN
UPDATE
SET prty_id = (SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e_metr.field_1)
AND p.prty_type = 'MANU')
,mety_code = e_metr.field_4
SET outlet_cnty_code = e.field_2
,inlet_cnty_code = e.field_3
,drwg_code = e.field_4
,metr_code = e.field_5
,reva_code = e.field_6
,slva_code = e.field_7
,svcp_code = e.field_8
,weight = e.field_9
,inlet_height = e.field_10
,inlet_size = e.field_11
,outlet_pressure = e.field_12
,outlet_height = e.field_13
,outlet_size = e.field_14
,bas_code = e.field_15
,hou_code = e.field_16
,dim_a = e.field_17
,dim_b = e.field_18
,dim_c = e.field_19
,dim_e = e.field_20
,dim_h = e.field_22
,valid_from = CASE WHEN e.field_23 IS NULL THEN trunc(SYSDATE)
ELSE to_date(e.field_23
,'dd/mm/yyyy')END
,valid_to = CASE WHEN e.field_24 IS NULL THEN NULL
ELSE to_date(e.field_24
,'dd/mm/yyyy')END
,regu_code = e.field_25
,fltr_code = e.field_26
,inlet_cnor_code = e.field_27
,outlet_cnor_code = e.field_28
,lead_time = e.field_29
,prty_id = (SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e.field_30)
AND p.prty_type = 'MANU')
WHEN NOT MATCHED THEN
INSERT
(metr.code
,metr.prty_id
,metr.mety_code
,metr.dim_a
,metr.dim_b
,metr.centres
,metr.dim_c
,metr.weight
,metr.qmax
,metr.valid_from
,metr.qnom
,metr.qmin)
(code
,drwg_code
,fltr_code
,inlet_cnor_code
,inlet_cnty_code
,metr_code
,outlet_cnor_code
,outlet_cnty_code
,prty_id
,regu_code
,reva_code
,slva_code
,svcp_code
,lead_time
,weight
,inlet_height
,inlet_size
,outlet_pressure
,outlet_height
,outlet_size
,dim_a
,dim_b
,dim_c
,dim_d
,dim_e
,dim_h
,valid_from
,bas_code
,hou_code
,valid_to)
VALUES
(e_metr.field_2
(e.field_1
,e.field_4
,e.field_26
,e.field_27
,e.field_3
,e.field_5
,e.field_28
,e.field_2 -- outlet_cnty_code
,(SELECT id
FROM parties p
WHERE upper(p.manu_ref) = upper(e_metr.field_1)
WHERE upper(p.manu_ref) = upper(e.field_30)
AND p.prty_type = 'MANU')
,e_metr.field_4
,e_metr.field_5
,e_metr.field_6
,e_metr.field_7
,e_metr.field_8
,e_metr.field_9
,e_metr.field_10
,SYSDATE
,e_metr.field_11
,e_metr.field_12) log errors reject LIMIT unlimited;
END load_meters;
,e.field_25
,e.field_6
,e.field_7
,e.field_8
,e.field_29
,e.field_9
,e.field_10
,e.field_11 -- inlet size
,e.field_12
,e.field_13
,e.field_14
,e.field_17
,e.field_18
,e.field_19
,e.field_20
,e.field_21
,e.field_22
,CASE WHEN e.field_23 IS NULL THEN trunc(SYSDATE)
ELSE to_date(e.field_23
,'dd/mm/yyyy')END
,e.field_15
,e.field_16
,CASE WHEN e.field_24 IS NULL THEN NULL
ELSE to_date(e.field_24
,'dd/mm/yyyy')END) log errors reject LIMIT unlimited;
END load_modules;
BEGIN
-- Initialization
NULL;
get_globals;
END mip_bulk_load;
/

View File

@@ -349,6 +349,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
l_regi_code regions.code%TYPE := mip_regions.get_region_for_postcode(p_enqu.install_postcode);
l_qute_id quotes.id%TYPE;
l_additional_costs t_rec_additional_costs;
l_quote_document VARCHAR2(240);
BEGIN
cout_assert.istrue(p_enqu.enty_code IN ('INSTALL', 'STD INSTALL')
,'Attempted to produce an install quote for enquiry of type ' ||
@@ -881,19 +882,68 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
,l_rec_module.lifting_gear_lead_time
,'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;
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => 'Produced Quote Document ' ||
l_quote_document || '.'
,p_internal_or_external => g_internal_reason);
INSERT INTO quote_events
(event_date
,qust_code
,qute_id)
VALUES
(SYSDATE
,'AV' -- Available
,l_qute_id);
END IF; -- automatic quote
END LOOP;
IF l_produced_automatic_quote THEN
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => 'Produced an automatic quote.'
,p_reason => '-- Produced an automatic quote.'
,p_internal_or_external => g_internal_reason);
ELSE
add_quote_reason(p_enqu_id => p_enqu.id
,p_reason => 'Manual quote required.'
,p_reason => '-- 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;
@@ -941,6 +991,10 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS
--
END IF; -- manual or automatic quote
EXCEPTION
WHEN OTHERS THEN
cout_err.report_and_stop;
END produce_quotes;
BEGIN