From dfd3210818abd4e6c9b355b76aa3da0315f887ee Mon Sep 17 00:00:00 2001 From: hardya Date: Fri, 15 Feb 2008 18:01:40 +0000 Subject: [PATCH] Bulk Load: Changes to default values for 'unknown' items, inclusion of LeadTimes.csv MIP_QUOTATION: Changes to make use of LeadTimes.csv git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3605 248e525c-4dfb-0310-94bc-949c084e9493 --- Data/BulkLoad/DATAITEM_ROLES.csv | 86 ++++ Data/BulkLoad/bulk_load.sql | 4 + Data/Seed/regi.ctl | 17 +- Data/Seed/svcp.ctl | 1 - Data/Seed/syco.ctl | 3 +- ...cationReference.xls => DATAITEM_ROLES.xls} | Bin 38400 -> 38400 bytes InstallMIP.cmd | 8 +- Modules/mip_bulk_load.pck | 456 +++++++++++------- Modules/mip_quotation.pck | 45 +- Schema/InstallMIP.sql | 1 + Schema/ext_cost.pdc | 4 +- Schema/ext_leadtime.pdc | 38 ++ Schema/ext_meter.pdc | 108 ++--- Schema/mip.con | 86 +++- Schema/mip.ind | 22 +- Schema/mip.sql | 2 +- Schema/mip.sqs | 9 +- Schema/mip.tab | 15 +- Schema/mipExtTables.sql | 2 + Schema/mipViews.sql | 1 + Schema/v_lead_times.vw | 28 ++ 21 files changed, 635 insertions(+), 301 deletions(-) create mode 100644 Data/BulkLoad/DATAITEM_ROLES.csv rename Documentation/Design/{DatabaseItemToFunctionalSpecificationReference.xls => DATAITEM_ROLES.xls} (99%) create mode 100644 Schema/ext_leadtime.pdc create mode 100644 Schema/v_lead_times.vw 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 5d73c9bc8c30d8d098de7548267f91f8bc91203a..197adcd896ee688d6d43bc8db32b4f879761c613 100644 GIT binary patch delta 52 zcmZoz!_=^bX@dq6KMw= 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)) +/