diff --git a/Data/BulkLoad/DATAITEM_ROLES.csv b/Data/BulkLoad/DATAITEM_ROLES.csv new file mode 100644 index 0000000..75ae781 --- /dev/null +++ b/Data/BulkLoad/DATAITEM_ROLES.csv @@ -0,0 +1,86 @@ +COLUMN_NAME ,Appendix Reference,INSTALL,STD INSTALL,OFMAT,EXCHANGE,STD EXCHANGE,REMOVE,STD REMOVE,ADVERSARIAL,ALTERATION,CAPACITY CHANGE,"ADDONS(EMS,AMR)",OTHER,Notes,DisplaySequence +INSTALL_BUILDING,Address.Building,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,,1 +INSTALL_CITY,Address.City,M,M,M,M,M,M,M,M,M,M,M,M,,2 +FIRST_CONTACT_NAME,Address.Contact Name,M,M,M,M,M,M,M,M,M,M,M,M,,3 +INSTALL_POSTCODE,Address.Post Code,M,M,M,M,M,M,M,M,M,M,M,M,,4 +INSTALL_STREET,Address.Street,M,M,M,M,M,M,M,M,M,M,M,M,,5 +INSTALL_SUB_BUILDING,Address.Sub Building,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,O-M1,,6 +FIRST_ALT_BUILDING,Contact Address.Building,O,O,O,O,O,O,O,O,O,O,O,O,,7 +FIRST_ALT_CITY,Contact Address.City,O,O,O,O,O,O,O,O,O,O,O,O,,8 +FIRST_CONTACT_EMAIL,Contact Address.Email,O,O,O,O,O,O,O,O,O,O,O,O,,9 +SECOND_CONTACT_EMAIL,Second Contact Address.Email,O,O,O,O,O,O,O,O,O,O,O,O,,10 +FIRST_CONTACT_FAX,Contact Address.Fax,O,O,O,O,O,O,O,O,O,O,O,O,,11 +SECOND_CONTACT_FAX,Contact Address.Fax,O,O,O,O,O,O,O,O,O,O,O,O,,12 +FIRST_ALT_POSTCODE,Contact Address.Post Code,O,O,O,O,O,O,O,O,O,O,O,O,,13 +SECOND_CONTACT_TITLE,Second Contact Address.Contact Title,O,O,O,O,O,O,O,O,O,O,O,O,,14 +SECOND_CONTACT_INITIALS,Second Contact Address.Contact Initials,O,O,O,O,O,O,O,O,O,O,O,O,,15 +SECOND_CONTACT_NAME,Second Contact Address.Second Contact Name,O,O,O,O,O,O,O,O,O,O,O,O,,16 +FIRST_CONTACT_TITLE,Contact Address.Contact Title,O,O,O,O,O,O,O,O,O,O,O,O,,17 +FIRST_CONTACT_INITIALS,Contact Address.Contact Initials,O,O,O,O,O,O,O,O,O,O,O,O,,18 +FIRST_ALT_STREET,Contact Address.Street,O,O,O,O,O,O,O,O,O,O,O,O,,19 +FIRST_ALT_SUB_BUILDING,Contact Address.Sub Building,O,O,O,O,O,O,O,O,O,O,O,O,,20 +FIRST_CONTACT_TELEPHONE_1,Contact Address.Telephone1,M,M,M,M,M,M,M,M,M,M,M,M,,21 +SECOND_CONTACT_TELEPHONE_1,Contact Address.Telephone1,O,O,O,O,O,O,O,O,O,O,O,O,,22 +FIRST_CONTACT_TELEPHONE_2,Contact Address.Telephone2,O,O,O,O,O,O,O,O,O,O,O,O,,23 +SECOND_CONTACT_TELEPHONE_2,Contact Address.Telephone2,O,O,O,O,O,O,O,O,O,O,O,O,,24 +AMR_REQUIRED,Job Information.Additional Services.AMR,O-M5,O-M5,H,O-M5,O-M5,H,H,H,O-M5,O-M5,O-M5,O-M5,"The AMR may only be available for the Tripartite suppliers or BG, GW to confirm!",25 +BASE_REQUIRED,Job Information.Additional Services.Base,M,M,H,M,M,H,H,H,M,M,H,M,,26 +BYPASS_REQUIRED,Job Information.Additional Services.By-pass,O,O,H,O,O,H,H,H,O,O,O,O,"If yes, warn user if twin stream is no",27 +CONVERTOR_REQUIRED,Job Information.Additional Services.Convertor,M,M,H,M,M,M,M,M,M,M,M,M,this can be an add-on for removals,28 +EMS_REQUIRED,Job Information.Additional Services.EMS,M,M,H,M,M,H,H,H,M,M,M,M,,29 +HOUSING_REQUIRED,Job Information.Additional Services.Housing,M,M,H,M,M,H,H,H,M,M,H,M,,30 +TWIN_STREAM_REQUIRED,Job Information.Additional Services.Twin Stream,M,M,H,M,M,H,H,H,M,M,H,M,,31 +ANNUAL_QUANTITY,Job Information.Annual Quantity,O,O,O,O,O,H,H,H,O,O,O,O,if > 732 mwh go bespoke,32 +INDICATIVE_TIME,Job Information.Appointment Preference,O,O,O,O,O,O,O,O,O,O,O,O,,33 +DOWNSTREAM_BOOSTER_OR_COMPRESS,Job Information.Booster/Compressor,M,M,M,M,M,H,H,H,M,M,M,M,,34 +EXISTING_METER_SERIAL_NO,Job Information.Existing Asset Serial Number,H,H,M,M,M,M,M,M,M,M,M,O,,35 +EXISTING_MESC_CODE,Job Information.Existing Meter Size,H,H,M,M,M,M,M,M,M,M,O,O,,36 +EXISTING_METY_CODE,Job Information.Meter Type Existing ,H,H,M,M,M,M,M,M,M,M,O,O,,37 +EXISTING_METER_OWNER,Job Information.Gas Act Owner,O,O,M,M,M,M,M,M,M,M,M,O,,38 +INDICATIVE_DATE,Job Information.Indicative Substantial Completion Date,O,O,O,O,O,O,O,O,O,O,O,O,,39 +REQUIRED_IP_DETAILS,Job Information.IP Details,O-M3,H,O-M3,O-M3,H,O-M3,H,O-M3,O-M3,O-M3,O-M3,O-M3,if service pressure is IP,40 +REQUIRED_IP_MBAR,Job Information.IP Mbar,O-M3,H,O-M3,O-M3,H,O-M3,H,O-M3,O-M3,O-M3,O-M3,O-M3,if service pressure is IP,41 +JOB_DESCRIPTION,Job Information.Job Description,O,O,O,O,O,O,O,O,O,O,O,O,,42 +ENTY_CODE,Job Information.Job Type,M,M,M,M,M,M,M,M,M,M,M,M,,43 +LOAD_CONTROL_TYPE,Job Information.Load Control Type,M,M,H,M,M,H,H,H,O,M,O,O,,44 +MARKET_SECTOR_CODE,Job Information.Market Sector Code,O,O,O,O,O,O,O,O,O,O,O,O,,45 +QMAX,Job Information.Measuring Capacity Qmax,M,O-M2,O,M,O-M2,O,O,O,O,M,O,O,,46 +QMIN,Job Information.Measuring Capacity Qmin,O,O,O,O,O,O,O,O,O,O,O,O,,47 +REQUIRED_MESC_CODE,Job Information.Meter Size,H,O-M2,H,H,O-M2,H,H,H,H,O,H,O,,48 +EXISTING_METER_MODEL,Job Information.Model Code,H,H,O,O,O,O,O,O,O,O,O,O,,49 +OTHER_INFORMATION,Job Information.Other Information,O,O,O,O,O,O,O,O,O,O,O,O,,50 +OTHER_PROJECT_REFERENCE,Job Information.Other Related Projects,O,O,O,O,O,O,O,O,O,O,O,O,,51 +REQUIRED_METERING_PRESSURE,Job Information.Required Meter Pressure,M,M,M,M,M,M,M,M,M,M,O,O,,52 +REQUIRED_SVCP_CODE,Job Information.Service Pressure,O-M3,M,O-M3,O-M3,M,O-M3,M,O-M3,O-M3,O-M3,O-M3,O-M3,,53 +EXISTING_METER_ASSET_PROVIDER,Job Information.Supplier / Job Information.Consumer(Meter Asset Manager),O,O,O,O,O,O,O,O,O,O,O,O,,54 +TRANSACTION_REFERENCE,Job Site Details.Transaction Reference,O,O,O,O,O,O,O,O,O,O,O,O,,55 +SECOND_ALT_BUILDING,Second Contact Address.Building,O,O,O,O,O,O,O,O,O,O,O,O,,56 +SECOND_ALT_CITY,Second Contact Address.City,O,O,O,O,O,O,O,O,O,O,O,O,,57 +SECOND_ALT_POSTCODE,Second Contact Address.Post Code,O,O,O,O,O,O,O,O,O,O,O,O,,58 +SECOND_ALT_STREET,Second Contact Address.Street,O,O,O,O,O,O,O,O,O,O,O,O,,59 +SECOND_ALT_SUB_BUILDING,Second Contact Address.Sub Building,O,O,O,O,O,O,O,O,O,O,O,O,,60 +ACCESS_ADDITIONAL,Site Detail.Access Instructions,O,O,O,O,O,O,O,O,O,O,O,O,,61 +ACCESS_PASSWORD,Site Detail.Access Password,O,O,O,O,O,O,O,O,O,O,O,O,,62 +MPRN_ALT,Site Detail.Additional Information,O-M4,O-M4,O,O,O,O,O,O,O,O,O,O,,63 +ALTY_CODE,Site Detail.Asset Location Code,M,M,M,M,M,M,M,M,M,M,M,M,,64 +ASSET_LOCATION_NOTES,Site Detail.Asset Location Notes,O,O,O,O,O,O,O,O,O,O,O,O,,65 +CACA_CODE,Site Detail.Care Category,O,O,O,O,O,O,O,O,O,O,O,O,,66 +MPRN,Site Detail.MPRN,O-M4,O-M4,M,M,M,M,M,M,M,M,M,O,,67 +AGENT_COMT_CODE,Supplier Agent.Telephone1/Telephone2/Fax/Email,M,M,M,M,M,M,M,M,M,M,M,M,,68 +AGENT_CONTACT_VALUE,Supplier Agent.Telephone1/Telephone2/Fax/Email,M,M,M,M,M,M,M,M,M,M,M,M,,69 +ID,Enquiry Reference (not in spec appendix),M,M,M,M,M,M,M,M,M,M,M,M,,70 +EXISTING_LOGGER,Job Information.Logger,H,H,H,O,O,O,O,O,O,O,O,O,,71 +EXISTING_CONVERTOR,Job Information.Existing Convertor,H,H,O,M,M,M,M,M,M,M,O,O,,72 +CREATED_BY,,,,,,,,,,,,,,, +CREATED_ON,,,,,,,,,,,,,,, +UPDATED_BY,,,,,,,,,,,,,,, +UPDATED_ON,,,,,,,,,,,,,,, +,,,,,,,,,,,,,,, +,,,,,,,,,,,,,,, +,,,,,,,,,,,,,,, +,Optional-Mandatory Special Cases,,,,,,,,,,,,,, +,O-M1: INSTALL_SUB_BUILDING AND/OR INSTALL.BUILDING MUST BE COMPLETED,,,,,,,,,,,,,, +,O-M2: IF REQUIRED_MESC_CODE IS NOT COMPLETED THEN QMAX MUST BE COMPLETED,,,,,,,,,,,,,, +,O-M3: IF REQUIRED_SVCP_CODE = 'IP' THEN REQUIRED_IP_DETAILS MUST BE COMPLETED,,,,,,,,,,,,,, +,O-M4: IF MPRN IS NOT COMPLETED THEN MPRN_ALT MUST BE COMPLETED,,,,,,,,,,,,,, +,O-M5: AMR AVAILABILITY IS DETERMINED BY TRIPARTITE AGREEMENT,,,,,,,,,,,,,, diff --git a/Data/BulkLoad/bulk_load.sql b/Data/BulkLoad/bulk_load.sql index f8c6477..0a62189 100644 --- a/Data/BulkLoad/bulk_load.sql +++ b/Data/BulkLoad/bulk_load.sql @@ -2,6 +2,8 @@ DECLARE l_test_load BOOLEAN := upper('&&1') = 'TEST'; l_fat_load BOOLEAN := upper('&&1') = 'FAT'; l_uat_load BOOLEAN := upper('&&1') = 'UAT'; + l_live_load BOOLEAN := upper('&&1') = 'LIVE'; + l_train_load BOOLEAN := upper('&&1') = 'TRAIN'; l_dev_load BOOLEAN := upper(nvl('&&1','DEV')) = 'DEV'; BEGIN @@ -14,6 +16,8 @@ BEGIN mip_bulk_load.g_flow_id := 155; ELSIF l_uat_load THEN mip_bulk_load.g_flow_id := 400; + ELSIF l_train_load THEN + mip_bulk_load.g_flow_id := 800; END IF; IF mip_bulk_load.g_flow_id IS NOT NULL THEN diff --git a/Data/Seed/regi.ctl b/Data/Seed/regi.ctl index 3724355..ad54dfb 100644 --- a/Data/Seed/regi.ctl +++ b/Data/Seed/regi.ctl @@ -3,6 +3,7 @@ INFILE * INTO TABLE regions REPLACE FIELDS TERMINATED BY '|' +TRAILING NULLCOLS ( code ,description @@ -10,12 +11,12 @@ code ,quotation_text ) BEGINDATA -NETW01|SC001 - Scotland|Scotia Gas Networks Ltd| -NETW02|NTH01 - North|North of England Ltd| -NETW03|STH01 - South|Scotia Gas Networks Ltd| -NETW04|WWE01 - Wales and West|Wales and West Utilities Ltd| -NETW05|RDN01 - North London|London Ltd| -NETW06|RDN01 - West Midlands|West Midlands Ltd| -NETW07|RDN01 - North West|North West Ltd| -NETW08|RDN01 - East|East of England Ltd| +NETW01|Scotland|Scotia Gas Networks Ltd| +NETW02|Northern|Northern Gas Network Ltd| +NETW03|Southern|Scotia Gas Networks Ltd| +NETW04|Wales and West|Wales and West Utilities Ltd| +NETW05|North West|National Grid Gas| +NETW06|West Midlands|National Grid Gas| +NETW07|East of England|National Grid Gas| +NETW08|London|National Grid Gas| RDN01|Retained networks|National Grid Metering Ltd| diff --git a/Data/Seed/svcp.ctl b/Data/Seed/svcp.ctl index 4512b2c..7900d9a 100644 --- a/Data/Seed/svcp.ctl +++ b/Data/Seed/svcp.ctl @@ -16,4 +16,3 @@ MP105|MP|MP105 MP180|MP|MP180 MP270|MP|MP270 IP|IP|IP - diff --git a/Data/Seed/syco.ctl b/Data/Seed/syco.ctl index e64000e..7cb3982 100644 --- a/Data/Seed/syco.ctl +++ b/Data/Seed/syco.ctl @@ -3,6 +3,7 @@ INFILE * INTO TABLE system_configuration REPLACE FIELDS TERMINATED BY '|' +TRAILING NULLCOLS ( parameter ,value @@ -12,7 +13,7 @@ BEGINDATA PASSWORD_EXPIRY_LIMIT|30|Password expiry limit in days. USER_ACCOUNT_LOCK|60|Number of days of inactivity before account is locked. EMAIL_ADDRESS_AUTOMATIC_QUOTE|Andrew.Hardy@AdvanticaGroup.com| -EMAIL_FROM_ADDRESS|Joanna.Kingdon@AdvanticaGroup.com|The From field used for emails sent from the sy +EMAIL_FROM_ADDRESS|Joanna.Kingdon@AdvanticaGroup.com|The From field used for emails sent from the system QUOTE_LAPSE_LIMIT|90|The number of days that a quote remains valid for before lapsing. EMAIL_ADDRESS_MANUAL_QUOTE|Andrew.Hardy@AdvanticaGroup.com| EMAIL_ADDRESS_SUPPORT|Andrew.Hardy@AdvanticaGroup.com| diff --git a/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls b/Documentation/Design/DATAITEM_ROLES.xls similarity index 99% rename from Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls rename to Documentation/Design/DATAITEM_ROLES.xls index 5d73c9b..197adcd 100644 Binary files a/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls and b/Documentation/Design/DATAITEM_ROLES.xls differ diff --git a/InstallMIP.cmd b/InstallMIP.cmd index 453da46..4044133 100644 --- a/InstallMIP.cmd +++ b/InstallMIP.cmd @@ -31,6 +31,7 @@ if "%6"=="fat" goto :fat if "%6"=="sat" goto :sat if "%6"=="uat" goto :uat if "%6"=="live" goto :live +if "%6"=="train" goto :train :demo @@ -81,6 +82,10 @@ cd ..\.. goto :bulkload +:train +@echo Training Data uses UAT data +goto :uat + :uat @echo Install UAT data cd Data\uat @@ -106,11 +111,12 @@ cd ..\.. goto :bulkload :bulkload +@echo Perform Bulk Load sqlplus %3/%4@%5 @Data\BulkLoad\bulk_load.sql "%6" goto :done :usage -echo "usage InstallMIP sys_name sys_password app_name app_password db_connect_string [demo|test|fat|sat|uat|live]" +echo "usage InstallMIP sys_name sys_password app_name app_password db_connect_string [demo|test|fat|sat|uat|train|live]" :done diff --git a/Modules/mip_bulk_load.pck b/Modules/mip_bulk_load.pck index 549366f..54cf05d 100644 --- a/Modules/mip_bulk_load.pck +++ b/Modules/mip_bulk_load.pck @@ -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; diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck index bbf5cfc..7ae85c6 100644 --- a/Modules/mip_quotation.pck +++ b/Modules/mip_quotation.pck @@ -1603,6 +1603,40 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); RETURN l_rec_costs; END get_laco; + FUNCTION get_lead_time(p_enty_code enquiry_types.code%TYPE + ,p_mety_code meter_types.code%TYPE + ,p_svcp_code service_pressures.code%TYPE + ,p_qmax NUMBER) RETURN NUMBER IS + l_days NUMBER; + BEGIN + + SELECT days + INTO l_days + FROM (SELECT enty_code + ,mety_code + ,svcp.code AS svcp_code + ,from_qmax + ,to_qmax + ,days + FROM v_lead_times v + ,service_pressures svcp + WHERE v.svcpt_code = svcp.svcpt_code(+)) v + WHERE nvl(p_qmax + ,0) >= v.from_qmax + AND nvl(p_qmax + ,0) < v.to_qmax + AND v.enty_code = p_enty_code + AND v.mety_code = p_mety_code + AND ((v.svcp_code = p_svcp_code) OR + (v.svcp_code IS NULL AND p_svcp_code IS NULL)); + + RETURN l_days; + + EXCEPTION + WHEN no_data_found THEN + RETURN NULL; + END get_lead_time; + PROCEDURE produce_module_quotes(p_enqu IN t_enqu ,p_rfq_prty_id IN parties.id%TYPE ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL @@ -1660,7 +1694,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); ,modu.selling_price AS modu_selling_price ,modu.cost_price AS modu_cost_price ,modu.delivery_cost AS modu_delivery_cost - ,modu.lead_time AS modu_lead_time + ,NULL AS modu_lead_time ,modu.hou_code AS hou_code ,modu.inlet_orientation AS modu_inlet_orientation ,modu.outlet_orientation AS modu_outlet_orientation @@ -1715,7 +1749,6 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); ,selling_price ,cost_price ,delivery_cost - ,lead_time FROM modules modu ,connection_orientations cnor_i ,connection_orientations cnor_o @@ -1745,8 +1778,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); ,metr.qmin ,metr.qnom ,metr.mety_code - FROM meters metr - ) metr + FROM meters metr) metr WHERE modu.svcp_code = p_enqu.required_svcp_code AND modu.outlet_pressure = p_enqu.required_metering_pressure @@ -1769,6 +1801,11 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); l_regi_code WHEN NULL THEN '' ELSE ' for region code ' || l_regi_code END || '.' ,p_internal_or_external => gc_internal_reason); END IF; + + l_rec_module.modu_lead_time := get_lead_time(p_enty_code => p_enqu.enty_code + ,p_mety_code => l_rec_module.mety_code + ,p_svcp_code => p_enqu.required_svcp_code + ,p_qmax => l_rec_module.qmax); IF l_rec_module.modu_lead_time IS NULL THEN l_this_is_automatic_quote := FALSE; add_quote_reason(p_enqu.id diff --git a/Schema/InstallMIP.sql b/Schema/InstallMIP.sql index 0d068bc..3998745 100644 --- a/Schema/InstallMIP.sql +++ b/Schema/InstallMIP.sql @@ -13,6 +13,7 @@ grant execute on plpdf.plpdf_img to &3; create synonym &3..plpdf for plpdf.plpdf; create synonym &3..plpdf_img for plpdf.plpdf_img; +create synonym &3..plpdf_type for plpdf.plpdf_type; connect &3/&4@&5 diff --git a/Schema/ext_cost.pdc b/Schema/ext_cost.pdc index 9a22f8d..88419f8 100644 --- a/Schema/ext_cost.pdc +++ b/Schema/ext_cost.pdc @@ -29,7 +29,7 @@ default directory webmip_bulk_load access parameters ( records delimited by NEWLINE READSIZE 10485760 - skip 2 + skip 3 fields terminated by '|' missing field values are null ( @@ -72,7 +72,7 @@ default directory webmip_bulk_load access parameters ( records delimited by NEWLINE READSIZE 10485760 - skip 3 + skip 2 fields terminated by '|' missing field values are null ( diff --git a/Schema/ext_leadtime.pdc b/Schema/ext_leadtime.pdc new file mode 100644 index 0000000..08dc56f --- /dev/null +++ b/Schema/ext_leadtime.pdc @@ -0,0 +1,38 @@ +BEGIN + FOR l_rec IN (SELECT 1 + FROM user_tables + WHERE table_name = 'EXT_LEADTIMES') LOOP + EXECUTE IMMEDIATE 'DROP TABLE ext_leadtimes'; + END LOOP; +END; +/ +create table ext_leadtimes +( + ENTY_CODE varchar2(240), + METY_CODE varchar2(240), + MESC_CODE varchar2(240), + SVCPT_CODE varchar2(240), + LEAD_TIME varchar2(240) + ) + ORGANIZATION EXTERNAL +( type oracle_loader +default directory webmip_bulk_load +access parameters +( records delimited by NEWLINE + READSIZE 10485760 + skip 2 + fields terminated by ',' + optionally enclosed BY '"' + missing field values are null + ( + ENTY_CODE, + METY_CODE, + MESC_CODE, + SVCPT_CODE, + LEAD_TIME + ) +) +location ('LEADTIMES.csv') +) +reject limit unlimited +/ diff --git a/Schema/ext_meter.pdc b/Schema/ext_meter.pdc index 3d0ce7e..9db51ab 100644 --- a/Schema/ext_meter.pdc +++ b/Schema/ext_meter.pdc @@ -8,46 +8,20 @@ END; / create table ext_meters ( - field_1 varchar2(240), - field_2 varchar2(240), - field_3 varchar2(240), - field_4 varchar2(240), - field_5 varchar2(240), - field_6 varchar2(240), - field_7 varchar2(240), - field_8 varchar2(240), - field_9 varchar2(240), - field_10 varchar2(240), - field_11 varchar2(240), - field_12 varchar2(240), - field_13 varchar2(240), - field_14 varchar2(240), - field_15 varchar2(240), - field_16 varchar2(240), - field_17 varchar2(240), - field_18 varchar2(240), - field_19 varchar2(240), - field_20 varchar2(240), - field_21 varchar2(240), - field_22 varchar2(240), - field_23 varchar2(240), - field_24 varchar2(240), - field_25 varchar2(240), - field_26 varchar2(240), - field_27 varchar2(240), - field_28 varchar2(240), - field_29 varchar2(240), - field_30 varchar2(240), - field_31 varchar2(240), - field_32 varchar2(240), - field_33 varchar2(240), - field_34 varchar2(240), - field_35 varchar2(240), - field_36 varchar2(240), - field_37 varchar2(240), - field_38 varchar2(240), - field_39 varchar2(240), - field_40 varchar2(240) + code varchar2(240), + drwg_code varchar2(240), + mety_code varchar2(240), + manu_ref varchar2(240), + dim_a varchar2(240), + dim_b varchar2(240), + centres varchar2(240), + dim_c varchar2(240), + weight varchar2(240), + qmax varchar2(240), + valid_from varchar2(240), + valid_to varchar2(240), + qnom varchar2(240), + qmin varchar2(240) ) ORGANIZATION EXTERNAL ( type oracle_loader @@ -60,46 +34,20 @@ access parameters optionally enclosed BY '"' missing field values are null ( - field_1, - field_2, - field_3, - field_4, - field_5, - field_6, - field_7, - field_8, - field_9, - field_10, - field_11, - field_12, - 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, - field_31, - field_32, - field_33, - field_34, - field_35, - field_36, - field_37, - field_38, - field_39, - field_40 + code, + drwg_code, + mety_code, + manu_ref, + dim_a, + dim_b, + centres, + dim_c, + weight, + qmax, + valid_from, + valid_to, + qnom, + qmin ) ) location ('METERS.csv') diff --git a/Schema/mip.con b/Schema/mip.con index e39e423..c156325 100644 --- a/Schema/mip.con +++ b/Schema/mip.con @@ -1,6 +1,6 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.con -- --- Generated for Oracle 10g on Fri Feb 08 15:56:52 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Fri Feb 15 16:30:41 2008 by Server Generator 10.1.2.6.18 PROMPT Creating Primary Key on 'SYSTEM_CONFIGURATION' ALTER TABLE SYSTEM_CONFIGURATION @@ -259,6 +259,12 @@ ALTER TABLE CONNECTION_TYPES (CODE)) / +PROMPT Creating Primary Key on 'LEAD_TIMES' +ALTER TABLE LEAD_TIMES + ADD (CONSTRAINT LETI_PK PRIMARY KEY + (ID)) +/ + PROMPT Creating Primary Key on 'METERS' ALTER TABLE METERS ADD (CONSTRAINT METR_PK PRIMARY KEY @@ -465,28 +471,28 @@ ALTER TABLE REGI_ENQU_EXCLUSIONS PROMPT Creating Check Constraint on 'METER_SIZE_CODES' ALTER TABLE METER_SIZE_CODES - ADD (CONSTRAINT AVCON_1202486212_VALID_000 CHECK (VALID_FOR_EXISTING_METER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_VALID_000 CHECK (VALID_FOR_EXISTING_METER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'METER_SIZE_CODES' ALTER TABLE METER_SIZE_CODES - ADD (CONSTRAINT AVCON_1202486212_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'COSTS' ALTER TABLE COSTS - ADD (CONSTRAINT AVCON_1202486212_COST__000 CHECK (COST_TYPE + ADD (CONSTRAINT AVCON_1203093040_COST__000 CHECK (COST_TYPE IN ('LACO', 'BACO', 'MOCO', 'MECO', 'AICO', 'HOCO', 'COST'))) / PROMPT Creating Check Constraint on 'DOCUMENTS' ALTER TABLE DOCUMENTS - ADD (CONSTRAINT AVCON_1202486212_DOCU__000 CHECK (DOCU_TYPE IN ('DOCU', 'INDO', 'EXDO', 'FIDO'))) + ADD (CONSTRAINT AVCON_1203093040_DOCU__000 CHECK (DOCU_TYPE IN ('DOCU', 'INDO', 'EXDO', 'FIDO'))) / PROMPT Creating Check Constraint on 'QUOTES' ALTER TABLE QUOTES - ADD (CONSTRAINT AVCON_1202486212_QUTE__000 CHECK (QUTE_TYPE IN ('AQ', 'MQ', 'QUTE'))) + ADD (CONSTRAINT AVCON_1203093040_QUTE__000 CHECK (QUTE_TYPE IN ('AQ', 'MQ', 'QUTE'))) / PROMPT Creating Check Constraint on 'PARTY_RELATIONSHIPS' @@ -498,17 +504,17 @@ to_parl_rt_code = to_prtp_rt_code)) PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1202486212_TRIPA_000 CHECK (TRIPARTITE_MEMBER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_TRIPA_000 CHECK (TRIPARTITE_MEMBER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1202486212_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED'))) + ADD (CONSTRAINT AVCON_1203093040_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED'))) / PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1202486212_PRTY__000 CHECK (PRTY_TYPE + ADD (CONSTRAINT AVCON_1203093040_PRTY__000 CHECK (PRTY_TYPE IN ('PRTY', 'IO', 'EO', 'MKTP', 'PERS', 'MANU', 'NEMP', 'EMP', 'ORG' ))) / @@ -526,82 +532,82 @@ OR PROMPT Creating Check Constraint on 'DOCUMENT_ROLES' ALTER TABLE DOCUMENT_ROLES - ADD (CONSTRAINT AVCON_1202486212_DORO__000 CHECK (DORO_TYPE IN ('DRRO', 'DORO', 'ENDO', 'QUDO'))) + ADD (CONSTRAINT AVCON_1203093040_DORO__000 CHECK (DORO_TYPE IN ('DRRO', 'DORO', 'ENDO', 'QUDO'))) / PROMPT Creating Check Constraint on 'QUOTE_ITEMS' ALTER TABLE QUOTE_ITEMS - ADD (CONSTRAINT AVCON_1202486212_QUIT__000 CHECK (QUIT_TYPE IN ('LQI', 'AQI', 'BQI', 'MQI', 'QUIT', 'HQI'))) + ADD (CONSTRAINT AVCON_1203093040_QUIT__000 CHECK (QUIT_TYPE IN ('LQI', 'AQI', 'BQI', 'MQI', 'QUIT', 'HQI'))) / PROMPT Creating Check Constraint on 'ROLE_TYPES' ALTER TABLE ROLE_TYPES - ADD (CONSTRAINT AVCON_1202486212_RT_TY_000 CHECK (RT_TYPE IN ('DORT', 'PART', 'RT', 'PCMRT', 'QURT', 'ENRT', 'PRT'))) + ADD (CONSTRAINT AVCON_1203093040_RT_TY_000 CHECK (RT_TYPE IN ('DORT', 'PART', 'RT', 'PCMRT', 'QURT', 'ENRT', 'PRT'))) / - + PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM'))) + ADD (CONSTRAINT AVCON_1203093040_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_EXIST_000 CHECK (EXISTING_LOGGER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_EXIST_000 CHECK (EXISTING_LOGGER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating'))) + ADD (CONSTRAINT AVCON_1203093040_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_EXIST_001 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C'))) + ADD (CONSTRAINT AVCON_1203093040_EXIST_001 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_EXIST_002 CHECK (EXISTING_CONVERTOR IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1203093040_EXIST_002 CHECK (EXISTING_CONVERTOR IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1202486212_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D'))) + ADD (CONSTRAINT AVCON_1203093040_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D'))) / @@ -1026,6 +1032,34 @@ ALTER TABLE PASSWORDS ADD (CONSTRAINT (ID)) / +PROMPT Creating Foreign Key on 'LEAD_TIMES' +ALTER TABLE LEAD_TIMES ADD (CONSTRAINT + LETI_METY_FK FOREIGN KEY + (METY_CODE) REFERENCES METER_TYPES + (CODE)) +/ + +PROMPT Creating Foreign Key on 'LEAD_TIMES' +ALTER TABLE LEAD_TIMES ADD (CONSTRAINT + LETI_MESC_FK FOREIGN KEY + (MESC_CODE) REFERENCES METER_SIZE_CODES + (CODE)) +/ + +PROMPT Creating Foreign Key on 'LEAD_TIMES' +ALTER TABLE LEAD_TIMES ADD (CONSTRAINT + LETI_SVCPT_FK FOREIGN KEY + (SVCPT_CODE) REFERENCES SERVICE_PRESSURE_TYPES + (CODE)) +/ + +PROMPT Creating Foreign Key on 'LEAD_TIMES' +ALTER TABLE LEAD_TIMES ADD (CONSTRAINT + LETI_ENTY_FK FOREIGN KEY + (ENTY_CODE) REFERENCES ENQUIRY_TYPES + (CODE)) +/ + PROMPT Creating Foreign Key on 'METERS' ALTER TABLE METERS ADD (CONSTRAINT METR_DRWG_FK FOREIGN KEY diff --git a/Schema/mip.ind b/Schema/mip.ind index 73dcd5c..2c17548 100644 --- a/Schema/mip.ind +++ b/Schema/mip.ind @@ -1,6 +1,6 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.ind -- --- Generated for Oracle 10g on Fri Feb 08 15:56:52 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Fri Feb 15 16:30:40 2008 by Server Generator 10.1.2.6.18 PROMPT Creating Index 'REGU_RETY_FK_I' @@ -324,6 +324,26 @@ CREATE INDEX PWD_PRTY_FK_I ON PASSWORDS (PRTY_ID) / +PROMPT Creating Index 'LETI_ENTY_FK_I' +CREATE INDEX LETI_ENTY_FK_I ON LEAD_TIMES + (ENTY_CODE) +/ + +PROMPT Creating Index 'LETI_MESC_FK_I' +CREATE INDEX LETI_MESC_FK_I ON LEAD_TIMES + (MESC_CODE) +/ + +PROMPT Creating Index 'LETI_METY_FK_I' +CREATE INDEX LETI_METY_FK_I ON LEAD_TIMES + (METY_CODE) +/ + +PROMPT Creating Index 'LETI_SVCPT_FK_I' +CREATE INDEX LETI_SVCPT_FK_I ON LEAD_TIMES + (SVCPT_CODE) +/ + PROMPT Creating Index 'METR_METY_FK_I' CREATE INDEX METR_METY_FK_I ON METERS (METY_CODE) diff --git a/Schema/mip.sql b/Schema/mip.sql index 596d27f..f9a32ae 100644 --- a/Schema/mip.sql +++ b/Schema/mip.sql @@ -1,6 +1,6 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.sql -- --- Generated for Oracle 10g on Fri Feb 08 15:56:53 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Fri Feb 15 16:30:41 2008 by Server Generator 10.1.2.6.18 SPOOL mip.lst diff --git a/Schema/mip.sqs b/Schema/mip.sqs index ef7fde0..71f471e 100644 --- a/Schema/mip.sqs +++ b/Schema/mip.sqs @@ -1,6 +1,6 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.sqs -- --- Generated for Oracle 10g on Fri Feb 08 15:56:52 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Fri Feb 15 16:30:41 2008 by Server Generator 10.1.2.6.18 PROMPT Creating Sequence 'FLTR_SEQ' CREATE SEQUENCE FLTR_SEQ @@ -66,6 +66,13 @@ CREATE SEQUENCE CNOR_SEQ NOCYCLE / +PROMPT Creating Sequence 'LETI_SEQ' +CREATE SEQUENCE LETI_SEQ + NOMAXVALUE + NOMINVALUE + NOCYCLE +/ + PROMPT Creating Sequence 'DORO_SEQ' CREATE SEQUENCE DORO_SEQ START WITH 20080000 diff --git a/Schema/mip.tab b/Schema/mip.tab index 5efb88f..78a542e 100644 --- a/Schema/mip.tab +++ b/Schema/mip.tab @@ -1,6 +1,6 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.tab -- --- Generated for Oracle 10g on Fri Feb 08 15:56:52 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Fri Feb 15 16:30:40 2008 by Server Generator 10.1.2.6.18 @@ -418,6 +418,17 @@ CREATE TABLE CONNECTION_TYPES ) / +PROMPT Creating Table 'LEAD_TIMES' +CREATE TABLE LEAD_TIMES + (ENTY_CODE VARCHAR2(80) NOT NULL + ,METY_CODE VARCHAR2(80) NOT NULL + ,DAYS INTEGER NOT NULL + ,MESC_CODE VARCHAR2(80) + ,SVCPT_CODE VARCHAR2(80) + ,ID NUMBER(*,0) NOT NULL + ) +/ + PROMPT Creating Table 'METERS' CREATE TABLE METERS (CODE VARCHAR2(80) NOT NULL @@ -442,7 +453,7 @@ CREATE TABLE SLAMSHUT_VALVES (CODE VARCHAR2(80) NOT NULL ,SLTY_CODE VARCHAR2(80) NOT NULL ,SLAMSHUT_SIZE NUMBER - ,SLAMSHUT_SETTING NUMBER NOT NULL + ,SLAMSHUT_SETTING NUMBER ) / diff --git a/Schema/mipExtTables.sql b/Schema/mipExtTables.sql index bed1c73..092da31 100644 --- a/Schema/mipExtTables.sql +++ b/Schema/mipExtTables.sql @@ -6,6 +6,7 @@ @@ext_caveat.pdc @@ext_postcode.pdc @@ext_dataitem_role.pdc +@@ext_leadtime.pdc -- error logs used when merging data from the external tables to their final destinations exec dbms_errlog.create_error_log(dml_table_name => 'meters') @@ -16,3 +17,4 @@ exec dbms_errlog.create_error_log(dml_table_name => 'housings') exec dbms_errlog.create_error_log(dml_table_name => 'costs') exec dbms_errlog.create_error_log(dml_table_name => 'caveat_texts') exec dbms_errlog.create_error_log('postcodes') +exec dbms_errlog.create_error_log('lead_times') diff --git a/Schema/mipViews.sql b/Schema/mipViews.sql index fefac40..e2c7865 100644 --- a/Schema/mipViews.sql +++ b/Schema/mipViews.sql @@ -18,4 +18,5 @@ @@V_current_enquiry_status.vw @@V_current_quote_status.vw @@V_CURRENT_DOCUMENT_STATUS.vw +@@v_lead_times.vw diff --git a/Schema/v_lead_times.vw b/Schema/v_lead_times.vw new file mode 100644 index 0000000..bd7928e --- /dev/null +++ b/Schema/v_lead_times.vw @@ -0,0 +1,28 @@ +CREATE OR REPLACE FORCE VIEW v_lead_times +AS +SELECT enty_code + ,mety_code + ,mesc_code + ,svcpt_code + ,nvl(from_qmax + ,0) AS from_qmax + ,nvl(to_qmax + ,9999999999999999) AS to_qmax + ,days + FROM (SELECT enty_code + ,mety_code + ,mesc_code + ,svcpt_code + ,lag(qmax) over(PARTITION BY enty_code, mety_code, svcpt_code ORDER BY qmax) AS from_qmax + ,qmax AS to_qmax + ,days + FROM (SELECT enty_code + ,mety_code + ,mesc_code + ,svcpt_code + ,qmax + ,days + FROM lead_times leti + ,meter_size_codes mesc + WHERE mesc.code(+) = leti.mesc_code)) +/