Alter bulk_load routines to match discussions with Gareth regarding costs.

Added 'quotation_text' and 'contact_text' to regions, to be used during quote document generation.

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@3494 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
hardya
2008-02-07 17:52:22 +00:00
parent 9bd9feed2f
commit ee3dcd0ad9
8 changed files with 300 additions and 363 deletions

Binary file not shown.

View File

@@ -1071,50 +1071,54 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
END load_housings;
PROCEDURE load_costs IS
l_cost_enty_code VARCHAR2(20);
BEGIN
pl('load_costs');
IF NOT file_available('COSTS.csv') THEN
pl('COSTS.csv file missing');
IF NOT file_available('LABOUR_COSTS.csv') THEN
pl('LABOUR_COSTS.csv file missing');
RETURN;
END IF;
IF NOT file_available('MATERIAL_COSTS.csv') THEN
pl('MATERIAL_COSTS.csv file missing');
RETURN;
END IF;
--
-- Additional Items
--
MERGE INTO costs cos
USING (SELECT upper(field_1) AS field_1
,field_2
,field_3
,field_4
USING (SELECT upper(adit_code) AS adit_code
,selling_price
,cost_price
,delivery_cost
,CASE
WHEN field_5 IS NULL THEN
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(field_5
to_date(valid_from
,'dd/mm/yyyy')
END AS field_5
END AS valid_from
,CASE
WHEN field_6 IS NULL THEN
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(field_6
to_date(valid_to
,'dd/mm/yyyy')
END AS field_6
,upper(field_7) AS field_7
,upper(field_16) AS field_16
FROM ext_costs
WHERE upper(field_7) = 'AICO') e
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_16 = cos.adit_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'AICO') e
ON (e.adit_code = cos.adit_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'AICO')
WHEN MATCHED THEN
UPDATE
SET selling_price = e.field_2
,cost_price = e.field_3
,delivery_cost = e.field_4
,valid_to = e.field_6
SET selling_price = e.selling_price
,cost_price = e.cost_price
,delivery_cost = e.delivery_cost
,valid_to = e.valid_to
WHEN NOT MATCHED THEN
INSERT
(id
,regi_code
,selling_price
,cost_price
,delivery_cost
@@ -1124,14 +1128,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,adit_code)
VALUES
(cost_seq.NEXTVAL
,e.field_1
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,e.field_6
,e.field_7
,e.field_16) log errors reject LIMIT unlimited;
,e.selling_price
,e.cost_price
,e.delivery_cost
,e.valid_from
,e.valid_to
,'AICO'
,e.adit_code) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': additional_items');
@@ -1139,39 +1142,36 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Base costs
--
MERGE INTO costs cos
USING (SELECT upper(field_1) AS field_1
,field_2
,field_3
,field_4
USING (SELECT upper(bas_code) AS bas_code
,selling_price
,cost_price
,delivery_cost
,CASE
WHEN field_5 IS NULL THEN
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(field_5
to_date(valid_from
,'dd/mm/yyyy')
END AS field_5
END AS valid_from
,CASE
WHEN field_6 IS NULL THEN
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(field_6
to_date(valid_to
,'dd/mm/yyyy')
END AS field_6
,upper(field_7) AS field_7
,upper(field_15) AS field_15
FROM ext_costs
WHERE upper(field_7) = 'BACO') e
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_15 = cos.bas_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'BACO') e
ON (e.bas_code = cos.bas_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'BACO')
WHEN MATCHED THEN
UPDATE
SET selling_price = e.field_2
,cost_price = e.field_3
,delivery_cost = e.field_4
,valid_to = e.field_6
SET selling_price = e.selling_price
,cost_price = e.cost_price
,delivery_cost = e.delivery_cost
,valid_to = e.valid_to
WHEN NOT MATCHED THEN
INSERT
(id
,regi_code
,selling_price
,cost_price
,delivery_cost
@@ -1181,14 +1181,13 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,bas_code)
VALUES
(cost_seq.NEXTVAL
,e.field_1
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,e.field_6
,e.field_7
,e.field_15) log errors reject LIMIT unlimited;
,e.selling_price
,e.cost_price
,e.delivery_cost
,e.valid_from
,e.valid_to
,'BACO'
,e.bas_code) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': bases');
@@ -1196,39 +1195,36 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
-- Housing costs
--
MERGE INTO costs cos
USING (SELECT upper(field_1) AS field_1
,field_2
,field_3
,field_4
USING (SELECT upper(hou_code) AS hou_code
,selling_price
,cost_price
,delivery_cost
,CASE
WHEN field_5 IS NULL THEN
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(field_5
to_date(valid_from
,'dd/mm/yyyy')
END AS field_5
END AS valid_from
,CASE
WHEN field_6 IS NULL THEN
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(field_6
to_date(valid_to
,'dd/mm/yyyy')
END AS field_6
,upper(field_7) AS field_7
,upper(field_14) AS field_14
FROM ext_costs
WHERE upper(field_7) = 'HOCO') e
ON (((e.field_1 = cos.regi_code) OR (e.field_1 IS NULL AND cos.regi_code IS NULL)) AND e.field_14 = cos.hou_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'HOCO') e
ON (e.hou_code = cos.hou_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'HOCO')
WHEN MATCHED THEN
UPDATE
SET selling_price = e.field_2
,cost_price = e.field_3
,delivery_cost = e.field_4
,valid_to = e.field_6
SET selling_price = e.selling_price
,cost_price = e.cost_price
,delivery_cost = e.delivery_cost
,valid_to = e.valid_to
WHEN NOT MATCHED THEN
INSERT
(id
,regi_code
,selling_price
,cost_price
,delivery_cost
@@ -1238,114 +1234,50 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,hou_code)
VALUES
(cost_seq.NEXTVAL
,e.field_1
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,e.field_6
,e.field_7
,e.field_14) log errors reject LIMIT unlimited;
,e.selling_price
,e.cost_price
,e.delivery_cost
,e.valid_from
,e.valid_to
,'HOCO'
,e.hou_code) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': housings');
--
-- Meter costs
--
MERGE INTO costs cos
USING (SELECT upper(field_1) AS field_1
,field_2
,field_3
,field_4
,CASE
WHEN field_5 IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(field_5
,'dd/mm/yyyy')
END AS field_5
,CASE
WHEN field_6 IS NULL THEN
NULL
ELSE
to_date(field_6
,'dd/mm/yyyy')
END AS field_6
,upper(field_7) AS field_7
,upper(field_13) AS field_13
FROM ext_costs
WHERE upper(field_7) = 'MECO') e
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_13 = cos.metr_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
WHEN MATCHED THEN
UPDATE
SET selling_price = e.field_2
,cost_price = e.field_3
,delivery_cost = e.field_4
,valid_to = e.field_6
WHEN NOT MATCHED THEN
INSERT
(id
,regi_code
,selling_price
,cost_price
,delivery_cost
,valid_from
,valid_to
,cost_type
,metr_code)
VALUES
(cost_seq.NEXTVAL
,e.field_1
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,e.field_6
,e.field_7
,e.field_13) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': meters');
--
-- Module costs
--
MERGE INTO costs cos
USING (SELECT DISTINCT upper(field_1) AS field_1
,field_2
,field_3
,field_4
USING (SELECT upper(modu_code) AS modu_code
,selling_price
,cost_price
,delivery_cost
,CASE
WHEN field_5 IS NULL THEN
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(field_5
to_date(valid_from
,'dd/mm/yyyy')
END AS field_5
END AS valid_from
,CASE
WHEN field_6 IS NULL THEN
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(field_6
to_date(valid_to
,'dd/mm/yyyy')
END AS field_6
,upper(field_7) AS field_7
,upper(field_8) AS field_8
,upper(field_9) AS field_9
,upper(field_10) AS field_10
,upper(field_12) AS field_12
FROM ext_costs
WHERE upper(field_7) = 'MOCO') e
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_12 = cos.modu_code AND e.field_5 = cos.valid_from AND e.field_7 = cos.cost_type)
END AS valid_to
FROM ext_material_costs
WHERE upper(cost_type) = 'MOCO') e
ON (e.modu_code = cos.modu_code AND e.valid_from = cos.valid_from AND cos.cost_type = 'MOCO')
WHEN MATCHED THEN
UPDATE
SET selling_price = e.field_2
,cost_price = e.field_3
,delivery_cost = e.field_4
,valid_to = e.field_6
SET selling_price = e.selling_price
,cost_price = e.cost_price
,delivery_cost = e.delivery_cost
,valid_to = e.valid_to
WHEN NOT MATCHED THEN
INSERT
(id
,regi_code
,selling_price
,cost_price
,delivery_cost
@@ -1355,59 +1287,74 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,modu_code)
VALUES
(cost_seq.NEXTVAL
,e.field_1
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,e.field_6
,e.field_7
,e.field_12) log errors reject LIMIT unlimited;
,e.selling_price
,e.cost_price
,e.delivery_cost
,e.valid_from
,e.valid_to
,'MOCO'
,e.modu_code) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': modules');
--
-- Labour costs
--
FOR l_enty IN (SELECT code
FROM enquiry_types) LOOP
l_cost_enty_code := CASE l_enty.code WHEN 'ADDON' THEN 'ADDON' WHEN 'ADVERSARIAL' THEN 'REMOVE' WHEN 'CHANGE CAPACITY' THEN 'CHANGE CAPACITY' WHEN 'EXCHANGE' THEN 'EXCHANGE' WHEN 'INSTALL' THEN 'INSTALL'
WHEN 'OFMAT' THEN 'OFMAT' WHEN 'OTHER' THEN 'OTHER' WHEN 'REMOVE' THEN 'REMOVE' WHEN 'STD EXCHANGE' THEN 'EXCHANGE' WHEN 'STD INSTALL' THEN 'INSTALL' WHEN 'STD REMOVE' THEN 'REMOVE' ELSE NULL END;
FOR l_network IN 1 .. 8 LOOP
MERGE INTO costs cos
USING (SELECT upper(field_1) AS field_1
,field_2
,field_3
,field_4
USING (SELECT CASE l_network
WHEN 1 THEN
netw01_selling_price
WHEN 2 THEN
netw02_selling_price
WHEN 3 THEN
netw03_selling_price
WHEN 4 THEN
netw04_selling_price
WHEN 5 THEN
netw05_selling_price
WHEN 6 THEN
netw06_selling_price
WHEN 7 THEN
netw07_selling_price
WHEN 8 THEN
netw08_selling_price
END AS selling_price
,CASE
WHEN field_5 IS NULL THEN
WHEN valid_from IS NULL THEN
trunc(SYSDATE)
ELSE
to_date(field_5
to_date(valid_from
,'dd/mm/yyyy')
END AS field_5
END AS valid_from
,CASE
WHEN field_6 IS NULL THEN
WHEN valid_to IS NULL THEN
NULL
ELSE
to_date(field_6
to_date(valid_to
,'dd/mm/yyyy')
END AS field_6
,upper(field_7) AS field_7
,upper(field_8) AS field_8
,upper(field_9) AS field_9
,upper(field_10) AS field_10
,upper(field_11) AS field_11
FROM ext_costs
WHERE upper(field_7) = 'LACO') e
ON (nvl(e.field_1, 'NULL') = nvl(cos.regi_code, 'NULL') AND e.field_8 = cos.enty_code AND e.field_5 = cos.valid_from AND e.field_11 = cos.mety_code AND e.field_7 = cos.cost_type AND ((e. field_9 IS NULL AND cos.mesc_code IS NULL) OR (e.field_9 = cos.mesc_code)) AND ((e.field_10 IS NULL AND cos.svcpt_code IS NULL) OR (e.field_10 = cos.svcpt_code)))
END AS valid_to
,upper(enty_code) AS enty_code
,upper(mesc_code) AS mesc_code
,upper(svcpt_code) AS svcpt_code
,upper(mety_code) AS mety_code
FROM ext_labour_costs
WHERE upper(enty_code) = l_cost_enty_code) e
ON (e.enty_code = cos.enty_code AND e.valid_from = cos.valid_from AND e.mety_code = cos.mety_code AND cos.cost_type = 'LACO' AND ((e. mesc_code IS NULL AND cos.mesc_code IS NULL) OR (e.mesc_code = cos.mesc_code)) AND ((e.svcpt_code IS NULL AND cos.svcpt_code IS NULL) OR (e.svcpt_code = cos.svcpt_code)))
WHEN MATCHED THEN
UPDATE
SET selling_price = e.field_2
,cost_price = e.field_3
,delivery_cost = e.field_4
,valid_to = e.field_6
SET selling_price = e.selling_price
,valid_to = e.valid_to
WHEN NOT MATCHED THEN
INSERT
(id
,regi_code
,selling_price
,cost_price
,delivery_cost
,valid_from
,valid_to
,cost_type
@@ -1417,20 +1364,22 @@ CREATE OR REPLACE PACKAGE BODY mip_bulk_load IS
,mety_code)
VALUES
(cost_seq.NEXTVAL
,e.field_1
,e.field_2
,e.field_3
,e.field_4
,e.field_5
,e.field_6
,e.field_7
,e.field_8
,e.field_9
,e.field_10
,e.field_11) log errors reject LIMIT unlimited;
,'NETW0' || l_network
,e.selling_price
,e.valid_from
,e.valid_to
,'LACO'
,l_enty.code
,e.mesc_code
,e.svcpt_code
,e.mety_code) log errors reject LIMIT unlimited;
pl(to_char(SQL%ROWCOUNT
,'FM099G999G999') || ': labour');
,'FM099G999G999') ||': '|| l_enty.code || ':NETW0' ||
l_network || ': labour');
END LOOP;
END LOOP;
END load_costs;

View File

@@ -1,53 +1,27 @@
BEGIN
FOR l_rec IN (SELECT 1
FOR l_rec IN (SELECT table_name
FROM user_tables
WHERE table_name = 'EXT_COSTS') LOOP
EXECUTE IMMEDIATE 'DROP TABLE ext_costs';
WHERE table_name IN ('EXT_COSTS', 'EXT_LABOUR_COSTS', 'EXT_MATERIAL_COSTS')) LOOP
EXECUTE IMMEDIATE 'DROP TABLE '||l_rec.table_name;
END LOOP;
END;
/
create table ext_costs
create table ext_labour_costs
(
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)
netw01_selling_price varchar2(240),
netw02_selling_price varchar2(240),
netw03_selling_price varchar2(240),
netw04_selling_price varchar2(240),
netw05_selling_price varchar2(240),
netw06_selling_price varchar2(240),
netw07_selling_price varchar2(240),
netw08_selling_price varchar2(240),
valid_from varchar2(240),
valid_to varchar2(240),
enty_code varchar2(240),
mesc_code varchar2(240),
svcpt_code varchar2(240),
mety_code varchar2(240)
)
ORGANIZATION EXTERNAL
( type oracle_loader
@@ -55,54 +29,66 @@ default directory webmip_bulk_load
access parameters
( records delimited by NEWLINE
READSIZE 10485760
skip 1
fields terminated by ','
optionally enclosed BY '"'
skip 2
fields terminated 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
netw01_selling_price,
netw02_selling_price,
netw03_selling_price,
netw04_selling_price,
netw05_selling_price,
netw06_selling_price,
netw07_selling_price,
netw08_selling_price,
valid_from,
valid_to,
enty_code,
mesc_code,
svcpt_code,
mety_code
)
)
location ('COSTS.csv')
location ('LABOUR_COSTS.csv')
)
reject limit unlimited
/
create table ext_material_costs
(
selling_price varchar2(240),
cost_price varchar2(240),
delivery_cost varchar2(240),
valid_from varchar2(240),
valid_to varchar2(240),
cost_type varchar2(240),
modu_code varchar2(240),
hou_code varchar2(240),
bas_code varchar2(240),
adit_code varchar2(240)
)
ORGANIZATION EXTERNAL
( type oracle_loader
default directory webmip_bulk_load
access parameters
( records delimited by NEWLINE
READSIZE 10485760
skip 3
fields terminated by '|'
missing field values are null
(
selling_price,
cost_price,
delivery_cost,
valid_from,
valid_to,
cost_type,
modu_code,
hou_code,
bas_code,
adit_code
)
)
location ('MATERIAL_COSTS.csv')
)
reject limit unlimited
/

View File

@@ -1,6 +1,6 @@
-- C:\Andy\svn\WEBMIP\Schema\mip.con
--
-- Generated for Oracle 10g on Tue Feb 05 12:03:58 2008 by Server Generator 10.1.2.6.18
-- Generated for Oracle 10g on Thu Feb 07 17:41:04 2008 by Server Generator 10.1.2.6.18
PROMPT Creating Primary Key on 'SYSTEM_CONFIGURATION'
ALTER TABLE SYSTEM_CONFIGURATION
@@ -453,28 +453,28 @@ ALTER TABLE REGI_ENQU_EXCLUSIONS
PROMPT Creating Check Constraint on 'METER_SIZE_CODES'
ALTER TABLE METER_SIZE_CODES
ADD (CONSTRAINT AVCON_1202213037_VALID_000 CHECK (VALID_FOR_EXISTING_METER IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_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_1202213037_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'COSTS'
ALTER TABLE COSTS
ADD (CONSTRAINT AVCON_1202213037_COST__000 CHECK (COST_TYPE
ADD (CONSTRAINT AVCON_1202406063_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_1202213037_DOCU__000 CHECK (DOCU_TYPE IN ('DOCU', 'INDO', 'EXDO', 'FIDO')))
ADD (CONSTRAINT AVCON_1202406063_DOCU__000 CHECK (DOCU_TYPE IN ('DOCU', 'INDO', 'EXDO', 'FIDO')))
/
PROMPT Creating Check Constraint on 'QUOTES'
ALTER TABLE QUOTES
ADD (CONSTRAINT AVCON_1202213037_QUTE__000 CHECK (QUTE_TYPE IN ('AQ', 'MQ', 'QUTE')))
ADD (CONSTRAINT AVCON_1202406063_QUTE__000 CHECK (QUTE_TYPE IN ('AQ', 'MQ', 'QUTE')))
/
PROMPT Creating Check Constraint on 'PARTY_RELATIONSHIPS'
@@ -486,17 +486,17 @@ to_parl_rt_code = to_prtp_rt_code))
PROMPT Creating Check Constraint on 'PARTIES'
ALTER TABLE PARTIES
ADD (CONSTRAINT AVCON_1202213037_TRIPA_000 CHECK (TRIPARTITE_MEMBER IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_TRIPA_000 CHECK (TRIPARTITE_MEMBER IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'PARTIES'
ALTER TABLE PARTIES
ADD (CONSTRAINT AVCON_1202213037_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED')))
ADD (CONSTRAINT AVCON_1202406063_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED')))
/
PROMPT Creating Check Constraint on 'PARTIES'
ALTER TABLE PARTIES
ADD (CONSTRAINT AVCON_1202213037_PRTY__000 CHECK (PRTY_TYPE
ADD (CONSTRAINT AVCON_1202406063_PRTY__000 CHECK (PRTY_TYPE
IN ('PRTY', 'IO', 'EO', 'MKTP', 'PERS', 'MANU', 'NEMP', 'EMP', 'ORG'
)))
/
@@ -514,82 +514,82 @@ OR
PROMPT Creating Check Constraint on 'DOCUMENT_ROLES'
ALTER TABLE DOCUMENT_ROLES
ADD (CONSTRAINT AVCON_1202213037_DORO__000 CHECK (DORO_TYPE IN ('DRRO', 'DORO', 'ENDO', 'QUDO')))
ADD (CONSTRAINT AVCON_1202406063_DORO__000 CHECK (DORO_TYPE IN ('DRRO', 'DORO', 'ENDO', 'QUDO')))
/
PROMPT Creating Check Constraint on 'QUOTE_ITEMS'
ALTER TABLE QUOTE_ITEMS
ADD (CONSTRAINT AVCON_1202213037_QUIT__000 CHECK (QUIT_TYPE IN ('LQI', 'AQI', 'BQI', 'MQI', 'QUIT', 'HQI')))
ADD (CONSTRAINT AVCON_1202406063_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_1202213037_RT_TY_000 CHECK (RT_TYPE IN ('DORT', 'PART', 'RT', 'PCMRT', 'QURT', 'ENRT', 'PRT')))
ADD (CONSTRAINT AVCON_1202406063_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_1202213037_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM')))
ADD (CONSTRAINT AVCON_1202406063_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_EXIST_000 CHECK (EXISTING_LOGGER IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_EXIST_000 CHECK (EXISTING_LOGGER IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating')))
ADD (CONSTRAINT AVCON_1202406063_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_EXIST_001 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C')))
ADD (CONSTRAINT AVCON_1202406063_EXIST_001 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_EXIST_002 CHECK (EXISTING_CONVERTOR IN ('YES', 'NO')))
ADD (CONSTRAINT AVCON_1202406063_EXIST_002 CHECK (EXISTING_CONVERTOR IN ('YES', 'NO')))
/
PROMPT Creating Check Constraint on 'ENQUIRIES'
ALTER TABLE ENQUIRIES
ADD (CONSTRAINT AVCON_1202213037_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D')))
ADD (CONSTRAINT AVCON_1202406063_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D')))
/

View File

@@ -1,6 +1,6 @@
-- C:\Andy\svn\WEBMIP\Schema\mip.ind
--
-- Generated for Oracle 10g on Tue Feb 05 12:03:58 2008 by Server Generator 10.1.2.6.18
-- Generated for Oracle 10g on Thu Feb 07 17:41:04 2008 by Server Generator 10.1.2.6.18
PROMPT Creating Index 'REGU_RETY_FK_I'

View File

@@ -1,6 +1,6 @@
-- C:\Andy\svn\WEBMIP\Schema\mip.sql
--
-- Generated for Oracle 10g on Tue Feb 05 12:03:59 2008 by Server Generator 10.1.2.6.18
-- Generated for Oracle 10g on Thu Feb 07 17:41:04 2008 by Server Generator 10.1.2.6.18
SPOOL mip.lst

View File

@@ -1,6 +1,6 @@
-- C:\Andy\svn\WEBMIP\Schema\mip.sqs
--
-- Generated for Oracle 10g on Tue Feb 05 12:03:58 2008 by Server Generator 10.1.2.6.18
-- Generated for Oracle 10g on Thu Feb 07 17:41:04 2008 by Server Generator 10.1.2.6.18
PROMPT Creating Sequence 'FLTR_SEQ'
CREATE SEQUENCE FLTR_SEQ

View File

@@ -1,6 +1,6 @@
-- C:\Andy\svn\WEBMIP\Schema\mip.tab
--
-- Generated for Oracle 10g on Tue Feb 05 12:03:58 2008 by Server Generator 10.1.2.6.18
-- Generated for Oracle 10g on Thu Feb 07 17:41:04 2008 by Server Generator 10.1.2.6.18
@@ -128,6 +128,8 @@ PROMPT Creating Table 'REGIONS'
CREATE TABLE REGIONS
(CODE VARCHAR2(80) NOT NULL
,DESCRIPTION VARCHAR2(80)
,CONTACT_TEXT VARCHAR2(80)
,QUOTATION_TEXT VARCHAR2(80)
)
/
@@ -269,7 +271,7 @@ CREATE TABLE SERVICE_PRESSURES
PROMPT Creating Table 'ENQUIRY_EVENTS'
CREATE TABLE ENQUIRY_EVENTS
(ENQU_ID NUMBER NOT NULL
,ENST_CODE VARCHAR2(80)
,ENST_CODE VARCHAR2(80) NOT NULL
,DESCRIPTION VARCHAR2(250)
,EVENT_DATE DATE NOT NULL
,ID NUMBER(*,0) NOT NULL