Files
mip/Modules/mip_bulk_load.pck
hardya 9e182d32cc BULK LOAD - added support drawings, bases and housings
QUOTATION - moved costing of labour outside of main query, provide more details on failure to produce automatic quote.

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3206 248e525c-4dfb-0310-94bc-949c084e9493
2008-01-11 17:26:52 +00:00

947 lines
26 KiB
Plaintext

CREATE OR REPLACE PACKAGE mip_bulk_load IS
-- Author : HARDYA
-- Created : 08/01/2008 14:26:14
-- Purpose : Bulk data load routines
PROCEDURE load_meters;
PROCEDURE load_modules;
PROCEDURE load_drawings;
PROCEDURE load_bases;
PROCEDURE load_all;
END mip_bulk_load;
/
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
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_meters IS
BEGIN
-- Meter Types
INSERT INTO meter_types
(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
FROM meter_types));
-- 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_meters'
FROM (SELECT DISTINCT upper(field_2) AS code
FROM ext_meters
WHERE field_2 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 upper(field_2) AS code
FROM ext_modules
UNION
SELECT upper(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 upper(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(upper(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 upper(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 upper(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 upper(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 upper(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 upper(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 upper(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 upper(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 upper(field_27) AS code
FROM ext_modules
UNION
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 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
,upper(field_15) AS field_15 -- base
,upper(field_16) AS field_16 -- housing
,field_17
,field_18
,field_19
,field_20
,field_21
,field_22
,field_23
,field_24
,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
,upper(field_30) AS field_30 -- MANU_REF
FROM ext_modules) e
ON (e.field_1 = modu.code)
WHEN MATCHED THEN
UPDATE
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 p.manu_ref = e.field_30
AND p.prty_type = 'MANU')
WHEN NOT MATCHED THEN
INSERT
(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.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.field_30)
AND p.prty_type = 'MANU')
,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;
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;
END mip_bulk_load;
/