Scheme Changes:
Replaced Access_Controls with APEX_AUTHORISATION Created POSTCODES, ERROR_LOGS and SYSTEM_CONFIGURATION. Added missing columns to ENQUIRIES, REGULATORS, etc. Added views V_PROFILE_RT_CODE_FOR_ENRO.vw, V_PARTY_RELATIONSHIPS.vw, V_LATEST_RT_CODE_FOR_ENRO.vw. Modules: Added cout_err.pck, cout_system_configuration.pck. Data: Added Data/Demo files Added Data/Seed files for postcodes, regions and DatabaseItemToFunctionalSpecificationReference.csv Documentation: Added Documentation/pldoc for plsqldoc-generated files. Added Documentation/SupportingDocumentation/Regions to hold region definition information. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2890 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
@@ -7,5 +7,6 @@ grant connect, resource to &3 identified by &4;
|
||||
connect &3/&4@&5
|
||||
|
||||
@@mip
|
||||
@@mipViews
|
||||
|
||||
exit
|
||||
13
Schema/V_LATEST_RT_CODE_FOR_ENRO.vw
Normal file
13
Schema/V_LATEST_RT_CODE_FOR_ENRO.vw
Normal file
@@ -0,0 +1,13 @@
|
||||
CREATE OR REPLACE VIEW V_LATEST_RT_CODE_FOR_ENRO AS
|
||||
/** Show rows from enquiry_roles where they represent the latest instance of an rt_code
|
||||
associated with an an enquiry.
|
||||
*/
|
||||
SELECT prty_id
|
||||
,rt_code
|
||||
,start_date
|
||||
,end_date
|
||||
,enqu_id
|
||||
FROM (SELECT enro.*
|
||||
,MAX(start_date) over(PARTITION BY rt_code, enqu_id) AS max_date_rt_code
|
||||
FROM enquiry_roles enro)
|
||||
WHERE start_date = max_date_rt_code;
|
||||
52
Schema/V_PARTY_RELATIONSHIPS.vw
Normal file
52
Schema/V_PARTY_RELATIONSHIPS.vw
Normal file
@@ -0,0 +1,52 @@
|
||||
CREATE OR REPLACE VIEW V_PARTY_RELATIONSHIPS AS
|
||||
/** Show parties involved in the party_relationships through party_roles to parties
|
||||
*/
|
||||
SELECT from_parl.prty_id AS from_parl_prty_id
|
||||
,prtp.from_rt_code
|
||||
,to_parl.prty_id AS to_parl_prty_id
|
||||
,prtp.to_rt_code
|
||||
,prtp.description
|
||||
,greatest(from_parl.start_date
|
||||
,prel.start_date
|
||||
,to_parl.start_date) AS effective_start
|
||||
,least(nvl(from_parl.end_date
|
||||
,to_date('31-dec-2099'
|
||||
,'dd-mon-yyyy'))
|
||||
,nvl(to_parl.end_date
|
||||
,to_date('31-dec-2099'
|
||||
,'dd-mon-yyyy'))
|
||||
,nvl(prel.end_date
|
||||
,to_date('31-dec-2099'
|
||||
,'dd-mon-yyyy'))) AS effective_end
|
||||
FROM (SELECT prty.first_name
|
||||
,prty.last_name
|
||||
,prty.username
|
||||
,parl.prty_id
|
||||
,parl.rt_code
|
||||
,parl.id
|
||||
,parl.start_date
|
||||
,parl.end_date
|
||||
FROM parties prty
|
||||
,party_roles parl
|
||||
WHERE parl.prty_id = prty.id) from_parl
|
||||
,(SELECT prty.first_name
|
||||
,prty.last_name
|
||||
,prty.username
|
||||
,parl.prty_id
|
||||
,parl.rt_code
|
||||
,parl.id
|
||||
,parl.start_date
|
||||
,parl.end_date
|
||||
FROM parties prty
|
||||
,party_roles parl
|
||||
WHERE parl.prty_id = prty.id) to_parl
|
||||
,party_relationship_types prtp
|
||||
,party_relationships prel
|
||||
WHERE prel.from_parl_id = from_parl.id
|
||||
AND prel.from_parl_prty_id = from_parl.prty_id
|
||||
AND prel.from_parl_rt_code = from_parl.rt_code
|
||||
AND prel.to_parl_id = to_parl.id
|
||||
AND prel.to_parl_prty_id = to_parl.prty_id
|
||||
AND prel.to_parl_rt_code = to_parl.rt_code
|
||||
AND prtp.from_rt_code = prel.from_parl_rt_code
|
||||
AND prtp.to_rt_code = prel.to_parl_rt_code;
|
||||
18
Schema/V_PROFILE_RT_CODE_FOR_ENRO.vw
Normal file
18
Schema/V_PROFILE_RT_CODE_FOR_ENRO.vw
Normal file
@@ -0,0 +1,18 @@
|
||||
CREATE OR REPLACE VIEW V_PROFILE_RT_CODE_FOR_ENRO AS
|
||||
/** Show rows from enquiry_roles along with start_date of the next instance of the same rt_code
|
||||
and enquiry.
|
||||
*/
|
||||
SELECT prty_id
|
||||
,rt_code
|
||||
,start_date
|
||||
,end_date
|
||||
,next_start_date
|
||||
,enqu_id
|
||||
FROM (SELECT enro.prty_id
|
||||
,enro.rt_code
|
||||
,enro.start_date
|
||||
,enro.end_date
|
||||
,enqu_id
|
||||
,lead(start_date
|
||||
,1) over(PARTITION BY rt_code, enqu_id ORDER BY start_date) AS next_start_date
|
||||
FROM enquiry_roles enro);
|
||||
141
Schema/mip.con
141
Schema/mip.con
@@ -1,7 +1,13 @@
|
||||
-- C:\Andy\svn\WEBMIP\Schema\mip.con
|
||||
--
|
||||
-- Generated for Oracle 10g on Thu Nov 15 16:13:29 2007 by Server Generator 10.1.2.6.18
|
||||
-- Generated for Oracle 10g on Mon Nov 26 14:57:47 2007 by Server Generator 10.1.2.6.18
|
||||
|
||||
PROMPT Creating Primary Key on 'SYSTEM_CONFIGURATION'
|
||||
ALTER TABLE SYSTEM_CONFIGURATION
|
||||
ADD (CONSTRAINT SYCO_PK PRIMARY KEY
|
||||
(PARAMETER))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'REGULATORS'
|
||||
ALTER TABLE REGULATORS
|
||||
ADD (CONSTRAINT REGU_PK PRIMARY KEY
|
||||
@@ -112,7 +118,8 @@ ALTER TABLE QUOTE_ROLES
|
||||
ADD (CONSTRAINT QURO_PK PRIMARY KEY
|
||||
(PRTY_ID
|
||||
,QUTE_ID
|
||||
,RT_CODE))
|
||||
,RT_CODE
|
||||
,START_DATE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'PARTY_RELATIONSHIPS'
|
||||
@@ -173,6 +180,12 @@ ALTER TABLE ENQUIRY_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'POSTCODES'
|
||||
ALTER TABLE POSTCODES
|
||||
ADD (CONSTRAINT POCO_PK PRIMARY KEY
|
||||
(ID))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'DATA_ITEMS'
|
||||
ALTER TABLE DATA_ITEMS
|
||||
ADD (CONSTRAINT DI_PK PRIMARY KEY
|
||||
@@ -217,6 +230,12 @@ ALTER TABLE CONNECTION_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'ERROR_LOGS'
|
||||
ALTER TABLE ERROR_LOGS
|
||||
ADD (CONSTRAINT ERLO_PK PRIMARY KEY
|
||||
(ERLO_ID))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'ENQUIRY_STATUS_TYPES'
|
||||
ALTER TABLE ENQUIRY_STATUS_TYPES
|
||||
ADD (CONSTRAINT ENST_PK PRIMARY KEY
|
||||
@@ -240,13 +259,8 @@ ALTER TABLE ENQUIRY_ROLES
|
||||
ADD (CONSTRAINT ENRO_PK PRIMARY KEY
|
||||
(PRTY_ID
|
||||
,ENQU_ID
|
||||
,RT_CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'ACCESS_CONTROLS'
|
||||
ALTER TABLE ACCESS_CONTROLS
|
||||
ADD (CONSTRAINT ACCL_PK PRIMARY KEY
|
||||
(ID))
|
||||
,RT_CODE
|
||||
,START_DATE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'ENQUIRIES'
|
||||
@@ -286,6 +300,15 @@ ALTER TABLE METER_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'APEX_AUTHORIZATION'
|
||||
ALTER TABLE APEX_AUTHORIZATION
|
||||
ADD (CONSTRAINT AUTH_PK PRIMARY KEY
|
||||
(PRIVILEGE
|
||||
,COMPONENT_TYPE
|
||||
,COMPONENT_NAME
|
||||
,RT_CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Primary Key on 'MODULES'
|
||||
ALTER TABLE MODULES
|
||||
ADD (CONSTRAINT MODU_PK PRIMARY KEY
|
||||
@@ -343,20 +366,27 @@ ALTER TABLE COSTS
|
||||
(AICO_CODE))
|
||||
/
|
||||
|
||||
|
||||
PROMPT Creating Unique Key on 'POSTCODES'
|
||||
ALTER TABLE POSTCODES
|
||||
ADD (CONSTRAINT POCO_POCO_UK UNIQUE
|
||||
(OUTCODE
|
||||
,INCODE))
|
||||
/
|
||||
|
||||
|
||||
PROMPT Creating Check Constraint on 'METER_SIZE_CODES'
|
||||
ALTER TABLE METER_SIZE_CODES
|
||||
ADD (CONSTRAINT AVCON_1195143208_VALID_000 CHECK (VALID_FOR_EXISTING_METER IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_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_1195143208_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'COSTS'
|
||||
ALTER TABLE COSTS
|
||||
ADD (CONSTRAINT AVCON_1195143208_COST__000 CHECK (COST_TYPE IN ('HOCO', 'BACO', 'COST', 'AICO', 'MOCO', 'MECO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_COST__000 CHECK (COST_TYPE IN ('HOCO', 'BACO', 'MECO', 'COST', 'AICO', 'LACO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'PARTY_RELATIONSHIPS'
|
||||
@@ -368,86 +398,86 @@ to_parl_rt_code = to_prtp_rt_code))
|
||||
|
||||
PROMPT Creating Check Constraint on 'QUOTES'
|
||||
ALTER TABLE QUOTES
|
||||
ADD (CONSTRAINT AVCON_1195143208_QUTE__000 CHECK (QUTE_TYPE IN ('QUTE', 'AQ', 'SQ', 'MQ')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_QUTE__000 CHECK (QUTE_TYPE IN ('QUTE', 'AQ', 'SQ', 'MQ')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'PARTIES'
|
||||
ALTER TABLE PARTIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'PARTIES'
|
||||
ALTER TABLE PARTIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_PRTY__000 CHECK (PRTY_TYPE
|
||||
ADD (CONSTRAINT AVCON_1196089066_PRTY__000 CHECK (PRTY_TYPE
|
||||
IN ('PRTY', 'IO', 'EO', 'MKTP', 'PERS', 'MANU', 'NEMP', 'EMP', 'ORG'
|
||||
)))
|
||||
/
|
||||
|
||||
|
||||
PROMPT Creating Check Constraint on 'ROLE_TYPES'
|
||||
ALTER TABLE ROLE_TYPES
|
||||
ADD (CONSTRAINT AVCON_1195143208_RT_TY_000 CHECK (RT_TYPE IN ('ENRT', 'QURT', 'PRT', 'PCMRT', 'PART', 'RT')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_RT_TY_000 CHECK (RT_TYPE IN ('ENRT', 'QURT', 'PRT', 'PCMRT', 'PART', 'RT')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_LOGGE_000 CHECK (LOGGER_REQUIRED IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_LOGGE_000 CHECK (LOGGER_REQUIRED IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO')))
|
||||
/
|
||||
|
||||
PROMPT Creating Check Constraint on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES
|
||||
ADD (CONSTRAINT AVCON_1195143208_EXIST_000 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C')))
|
||||
ADD (CONSTRAINT AVCON_1196089066_EXIST_000 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C')))
|
||||
/
|
||||
|
||||
|
||||
|
||||
PROMPT Creating Foreign Key on 'REGULATORS'
|
||||
ALTER TABLE REGULATORS ADD (CONSTRAINT
|
||||
@@ -522,6 +552,13 @@ ALTER TABLE PARTY_ADDRESS_ROLES ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_ENTY_FK FOREIGN KEY
|
||||
(ENTY_CODE) REFERENCES ENQUIRY_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_HOU_FK FOREIGN KEY
|
||||
@@ -536,6 +573,13 @@ ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_MESC_FK FOREIGN KEY
|
||||
(MESC_CODE) REFERENCES METER_SIZE_CODES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_MODU_FK FOREIGN KEY
|
||||
@@ -550,6 +594,13 @@ ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_METY_FK FOREIGN KEY
|
||||
(METY_CODE) REFERENCES METER_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_BAS_FK FOREIGN KEY
|
||||
@@ -557,6 +608,13 @@ ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'COSTS'
|
||||
ALTER TABLE COSTS ADD (CONSTRAINT
|
||||
COST_SVCPT_FK FOREIGN KEY
|
||||
(SVCPT_CODE) REFERENCES SERVICE_PRESSURE_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'PARTY_CONTACT_MECHANISM_ROLES'
|
||||
ALTER TABLE PARTY_CONTACT_MECHANISM_ROLES ADD (CONSTRAINT
|
||||
PCMR_RT_FK FOREIGN KEY
|
||||
@@ -690,6 +748,13 @@ ALTER TABLE ENQUIRY_EVENTS ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'POSTCODES'
|
||||
ALTER TABLE POSTCODES ADD (CONSTRAINT
|
||||
POCO_REGI_FK FOREIGN KEY
|
||||
(REGI_CODE) REFERENCES REGIONS
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'QUOTE_ITEMS'
|
||||
ALTER TABLE QUOTE_ITEMS ADD (CONSTRAINT
|
||||
QUIT_BAS_FK FOREIGN KEY
|
||||
@@ -781,13 +846,6 @@ ALTER TABLE ENQUIRY_ROLES ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'ACCESS_CONTROLS'
|
||||
ALTER TABLE ACCESS_CONTROLS ADD (CONSTRAINT
|
||||
ACCL_RT_FK FOREIGN KEY
|
||||
(RT_CODE) REFERENCES ROLE_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'ENQUIRIES'
|
||||
ALTER TABLE ENQUIRIES ADD (CONSTRAINT
|
||||
ENQU_ALTY_FK FOREIGN KEY
|
||||
@@ -872,6 +930,13 @@ ALTER TABLE PARTY_RELATIONSHIP_TYPES ADD (CONSTRAINT
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'APEX_AUTHORIZATION'
|
||||
ALTER TABLE APEX_AUTHORIZATION ADD (CONSTRAINT
|
||||
AUTH_RT_FK FOREIGN KEY
|
||||
(RT_CODE) REFERENCES ROLE_TYPES
|
||||
(CODE))
|
||||
/
|
||||
|
||||
PROMPT Creating Foreign Key on 'MODULES'
|
||||
ALTER TABLE MODULES ADD (CONSTRAINT
|
||||
MODU_SLVA_FK FOREIGN KEY
|
||||
|
||||
@@ -1,6 +1,6 @@
|
||||
-- C:\Andy\svn\WEBMIP\Schema\mip.ind
|
||||
--
|
||||
-- Generated for Oracle 10g on Thu Nov 15 16:13:28 2007 by Server Generator 10.1.2.6.18
|
||||
-- Generated for Oracle 10g on Mon Nov 26 14:57:47 2007 by Server Generator 10.1.2.6.18
|
||||
|
||||
|
||||
PROMPT Creating Index 'REGU_RETY_FK_I'
|
||||
@@ -53,6 +53,26 @@ CREATE INDEX PAR_RT_FK_I ON PARTY_ADDRESS_ROLES
|
||||
(RT_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'COST_METY_FK_I'
|
||||
CREATE INDEX COST_METY_FK_I ON COSTS
|
||||
(METY_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'COST_SVCPT_FK_I'
|
||||
CREATE INDEX COST_SVCPT_FK_I ON COSTS
|
||||
(SVCPT_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'COST_MESC_FK_I'
|
||||
CREATE INDEX COST_MESC_FK_I ON COSTS
|
||||
(MESC_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'COST_ENTY_FK_I'
|
||||
CREATE INDEX COST_ENTY_FK_I ON COSTS
|
||||
(ENTY_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'COST_BAS_FK_I'
|
||||
CREATE INDEX COST_BAS_FK_I ON COSTS
|
||||
(BAS_CODE)
|
||||
@@ -170,6 +190,22 @@ CREATE INDEX ENEV_ENQU_FK_I ON ENQUIRY_EVENTS
|
||||
(ENQU_ID)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'POCO_POSTCODE_I'
|
||||
CREATE INDEX POCO_POSTCODE_I ON POSTCODES
|
||||
(outcode||' '||incode)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'POCO_REGI_FK_I'
|
||||
CREATE INDEX POCO_REGI_FK_I ON POSTCODES
|
||||
(REGI_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'POCO_POCO_I'
|
||||
CREATE INDEX POCO_POCO_I ON POSTCODES
|
||||
(OUTCODE
|
||||
,INCODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'QUIT_QUTE_FK_I'
|
||||
CREATE INDEX QUIT_QUTE_FK_I ON QUOTE_ITEMS
|
||||
(QUTE_ID)
|
||||
@@ -235,9 +271,9 @@ CREATE INDEX ENRO_ENQU_FK_I ON ENQUIRY_ROLES
|
||||
(ENQU_ID)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'ACCL_RT_FK_I'
|
||||
CREATE INDEX ACCL_RT_FK_I ON ACCESS_CONTROLS
|
||||
(RT_CODE)
|
||||
PROMPT Creating Index 'ENRO_ENQ_OWN_ROLE_I'
|
||||
CREATE UNIQUE INDEX ENRO_ENQ_OWN_ROLE_I ON ENQUIRY_ROLES
|
||||
(mip_table_constraints.enq_rt_code(rt_code))
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'ENQU_METY_FK_I'
|
||||
@@ -300,6 +336,11 @@ CREATE INDEX PRTP_RT_FROM_FK_I ON PARTY_RELATIONSHIP_TYPES
|
||||
(FROM_RT_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'AUTH_RT_FK_I'
|
||||
CREATE INDEX AUTH_RT_FK_I ON APEX_AUTHORIZATION
|
||||
(RT_CODE)
|
||||
/
|
||||
|
||||
PROMPT Creating Index 'MODU_CNOR_OUTLET_FK_I'
|
||||
CREATE INDEX MODU_CNOR_OUTLET_FK_I ON MODULES
|
||||
(OUTLET_CNOR_CODE)
|
||||
|
||||
@@ -1,6 +1,6 @@
|
||||
-- C:\Andy\svn\WEBMIP\Schema\mip.sql
|
||||
--
|
||||
-- Generated for Oracle 10g on Thu Nov 15 16:13:29 2007 by Server Generator 10.1.2.6.18
|
||||
-- Generated for Oracle 10g on Mon Nov 26 14:57:48 2007 by Server Generator 10.1.2.6.18
|
||||
|
||||
|
||||
SPOOL mip.lst
|
||||
|
||||
@@ -1,6 +1,6 @@
|
||||
-- C:\Andy\svn\WEBMIP\Schema\mip.sqs
|
||||
--
|
||||
-- Generated for Oracle 10g on Thu Nov 15 16:13:29 2007 by Server Generator 10.1.2.6.18
|
||||
-- Generated for Oracle 10g on Mon Nov 26 14:57:47 2007 by Server Generator 10.1.2.6.18
|
||||
|
||||
PROMPT Creating Sequence 'ENQU_SEQ'
|
||||
CREATE SEQUENCE ENQU_SEQ
|
||||
@@ -23,15 +23,15 @@ CREATE SEQUENCE PRTY_SEQ
|
||||
NOCYCLE
|
||||
/
|
||||
|
||||
PROMPT Creating Sequence 'ACCL_SEQ'
|
||||
CREATE SEQUENCE ACCL_SEQ
|
||||
PROMPT Creating Sequence 'QUTE_SEQ'
|
||||
CREATE SEQUENCE QUTE_SEQ
|
||||
NOMAXVALUE
|
||||
NOMINVALUE
|
||||
NOCYCLE
|
||||
/
|
||||
|
||||
PROMPT Creating Sequence 'QUTE_SEQ'
|
||||
CREATE SEQUENCE QUTE_SEQ
|
||||
PROMPT Creating Sequence 'POCO_SEQ'
|
||||
CREATE SEQUENCE POCO_SEQ
|
||||
NOMAXVALUE
|
||||
NOMINVALUE
|
||||
NOCYCLE
|
||||
|
||||
104
Schema/mip.tab
104
Schema/mip.tab
@@ -1,9 +1,17 @@
|
||||
-- C:\Andy\svn\WEBMIP\Schema\mip.tab
|
||||
--
|
||||
-- Generated for Oracle 10g on Thu Nov 15 16:13:28 2007 by Server Generator 10.1.2.6.18
|
||||
-- Generated for Oracle 10g on Mon Nov 26 14:57:47 2007 by Server Generator 10.1.2.6.18
|
||||
|
||||
|
||||
|
||||
PROMPT Creating Table 'SYSTEM_CONFIGURATION'
|
||||
CREATE TABLE SYSTEM_CONFIGURATION
|
||||
(PARAMETER VARCHAR2(240) NOT NULL
|
||||
,VALUE VARCHAR2(240)
|
||||
,DESCRIPTION VARCHAR2(240)
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'REGULATORS'
|
||||
CREATE TABLE REGULATORS
|
||||
(CODE VARCHAR2(80) NOT NULL
|
||||
@@ -107,8 +115,12 @@ CREATE TABLE COSTS
|
||||
,DELIVERY_COST NUMBER(*,2)
|
||||
,VALID_TO DATE
|
||||
,HOU_CODE VARCHAR2(80)
|
||||
,METR_CODE VARCHAR2(80)
|
||||
,ENTY_CODE VARCHAR2(80)
|
||||
,MESC_CODE VARCHAR2(80)
|
||||
,METY_CODE VARCHAR2(80)
|
||||
,MODU_CODE VARCHAR2(80)
|
||||
,SVCPT_CODE VARCHAR2(80)
|
||||
,METR_CODE VARCHAR2(80)
|
||||
,ID NUMBER(*,0) NOT NULL
|
||||
,COST_TYPE VARCHAR2(10) NOT NULL
|
||||
)
|
||||
@@ -159,7 +171,7 @@ CREATE TABLE QUOTE_ROLES
|
||||
(PRTY_ID NUMBER(*,0) NOT NULL
|
||||
,QUTE_ID NUMBER(*,0) NOT NULL
|
||||
,RT_CODE VARCHAR2(80) NOT NULL
|
||||
,START_DATE DATE
|
||||
,START_DATE DATE DEFAULT SYSDATE NOT NULL
|
||||
,END_DATE DATE
|
||||
,DESCRIPTION VARCHAR2(80)
|
||||
)
|
||||
@@ -261,6 +273,15 @@ CREATE TABLE ENQUIRY_TYPES
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'POSTCODES'
|
||||
CREATE TABLE POSTCODES
|
||||
(REGI_CODE VARCHAR2(80) NOT NULL
|
||||
,OUTCODE VARCHAR2(4) NOT NULL
|
||||
,INCODE VARCHAR2(3)
|
||||
,ID NUMBER(*,0) NOT NULL
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'DATA_ITEMS'
|
||||
CREATE TABLE DATA_ITEMS
|
||||
(FIELD_NAME VARCHAR2(240) NOT NULL
|
||||
@@ -331,6 +352,50 @@ CREATE TABLE CONNECTION_TYPES
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'ERROR_LOGS'
|
||||
CREATE TABLE ERROR_LOGS
|
||||
(ERLO_ID NUMBER NOT NULL
|
||||
,ERROR_TYPE VARCHAR2(25) NOT NULL
|
||||
,SOURCE VARCHAR2(240) NOT NULL
|
||||
,SEVERITY VARCHAR2(1) NOT NULL
|
||||
,ERROR_CODE VARCHAR2(240) NOT NULL
|
||||
,ERROR_MESSAGE VARCHAR2(2000) NOT NULL
|
||||
,ERROR_DATE DATE NOT NULL
|
||||
,ERROR_STATUS VARCHAR2(1)
|
||||
,CREATED_BY NUMBER DEFAULT 0 NOT NULL
|
||||
,CREATED_ON DATE NOT NULL
|
||||
,UPDATED_BY NUMBER
|
||||
,UPDATED_ON DATE NOT NULL
|
||||
)
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.ERROR_TYPE IS 'The type of error.'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.SOURCE IS 'The source of the error.'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.SEVERITY IS 'The severity of the error.'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.ERROR_CODE IS 'The code for the error'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.ERROR_MESSAGE IS 'The message from the error'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.ERROR_DATE IS 'The date and time the error was logged.'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.ERROR_STATUS IS 'The status of the error'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.CREATED_BY IS 'The unique indentifier for a user of the system'
|
||||
/
|
||||
|
||||
COMMENT ON COLUMN ERROR_LOGS.UPDATED_BY IS 'The unique indentifier for a user of the system'
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'ENQUIRY_STATUS_TYPES'
|
||||
CREATE TABLE ENQUIRY_STATUS_TYPES
|
||||
(CODE VARCHAR2(80) NOT NULL
|
||||
@@ -361,21 +426,12 @@ CREATE TABLE ENQUIRY_ROLES
|
||||
(ENQU_ID NUMBER NOT NULL
|
||||
,PRTY_ID NUMBER(*,0) NOT NULL
|
||||
,RT_CODE VARCHAR2(80) NOT NULL
|
||||
,START_DATE DATE
|
||||
,START_DATE DATE DEFAULT SYSDATE NOT NULL
|
||||
,END_DATE DATE
|
||||
,DESCRIPTION VARCHAR2(80)
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'ACCESS_CONTROLS'
|
||||
CREATE TABLE ACCESS_CONTROLS
|
||||
(PAGE_NUMBER NUMBER NOT NULL
|
||||
,RT_CODE VARCHAR2(80)
|
||||
,ITEM VARCHAR2(80)
|
||||
,ID NUMBER(*,0) NOT NULL
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'ENQUIRIES'
|
||||
CREATE TABLE ENQUIRIES
|
||||
(ID NUMBER NOT NULL
|
||||
@@ -385,12 +441,12 @@ CREATE TABLE ENQUIRIES
|
||||
,SECOND_CONTACT_FAX VARCHAR2(15)
|
||||
,INSTALL_BUILDING VARCHAR2(40)
|
||||
,INSTALL_CITY VARCHAR2(40)
|
||||
,INSTALL_POSTCODE VARCHAR2(7)
|
||||
,INSTALL_POSTCODE VARCHAR2(8)
|
||||
,SECOND_ALT_SUB_BUILDING VARCHAR2(40)
|
||||
,FIRST_ALT_BUILDING VARCHAR2(40)
|
||||
,SECOND_ALT_STREET VARCHAR2(60)
|
||||
,SECOND_ALT_CITY VARCHAR2(40)
|
||||
,SECOND_ALT_POSTCODE VARCHAR2(7)
|
||||
,SECOND_ALT_POSTCODE VARCHAR2(8)
|
||||
,ASSET_LOCATION_NOTES VARCHAR2(100)
|
||||
,MPRN NUMBER(30,0)
|
||||
,REQUIRED_METERING_PRESSURE NUMBER
|
||||
@@ -402,7 +458,6 @@ CREATE TABLE ENQUIRIES
|
||||
,QMAX NUMBER
|
||||
,EXISTING_METER_MODEL VARCHAR2(10)
|
||||
,OTHER_INFORMATION VARCHAR2(250)
|
||||
,CREATED_ON DATE NOT NULL
|
||||
,ALTY_CODE VARCHAR2(80)
|
||||
,CACA_CODE VARCHAR2(80)
|
||||
,ENTY_CODE VARCHAR2(80)
|
||||
@@ -421,7 +476,7 @@ CREATE TABLE ENQUIRIES
|
||||
,SECOND_CONTACT_NAME VARCHAR2(80)
|
||||
,FIRST_ALT_STREET VARCHAR2(60)
|
||||
,FIRST_ALT_CITY VARCHAR2(40)
|
||||
,FIRST_ALT_POSTCODE VARCHAR2(7)
|
||||
,FIRST_ALT_POSTCODE VARCHAR2(8)
|
||||
,SECOND_ALT_BUILDING VARCHAR2(40)
|
||||
,ACCESS_PASSWORD VARCHAR2(30)
|
||||
,ACCESS_ADDITIONAL VARCHAR2(210)
|
||||
@@ -432,12 +487,12 @@ CREATE TABLE ENQUIRIES
|
||||
,AMR_REQUIRED VARCHAR2(3)
|
||||
,EMS_REQUIRED VARCHAR2(3)
|
||||
,BYPASS_REQUIRED VARCHAR2(40)
|
||||
,BYPASS_OTHER VARCHAR2(40)
|
||||
,LOGGER_REQUIRED VARCHAR2(3)
|
||||
,LOAD_CONTROL_TYPE VARCHAR2(10)
|
||||
,EXISTING_METER_ASSET_PROVIDER VARCHAR2(210)
|
||||
,MARKET_SECTOR_CODE VARCHAR2(1) DEFAULT 'I'
|
||||
,JOB_DESCRIPTION VARCHAR2(500)
|
||||
,CREATED_BY NUMBER NOT NULL
|
||||
,AGENT_COMT_CODE VARCHAR2(80)
|
||||
,FIRST_CONTACT_TELEPHONE_1 VARCHAR2(15)
|
||||
,FIRST_CONTACT_TELEPHONE_2 VARCHAR2(15)
|
||||
@@ -448,8 +503,6 @@ CREATE TABLE ENQUIRIES
|
||||
,QMIN NUMBER
|
||||
,EXISTING_METER_SERIAL_NO VARCHAR2(14)
|
||||
,EXISTING_METER_OWNER VARCHAR2(1)
|
||||
,UPDATED_BY NUMBER
|
||||
,UPDATED_ON DATE
|
||||
)
|
||||
/
|
||||
|
||||
@@ -499,6 +552,15 @@ CREATE TABLE METER_TYPES
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'APEX_AUTHORIZATION'
|
||||
CREATE TABLE APEX_AUTHORIZATION
|
||||
(RT_CODE VARCHAR2(80) NOT NULL
|
||||
,COMPONENT_NAME VARCHAR2(80) NOT NULL
|
||||
,COMPONENT_TYPE VARCHAR2(1) DEFAULT 'P' NOT NULL
|
||||
,PRIVILEGE VARCHAR2(1) DEFAULT 'A' NOT NULL
|
||||
)
|
||||
/
|
||||
|
||||
PROMPT Creating Table 'MODULES'
|
||||
CREATE TABLE MODULES
|
||||
(CODE VARCHAR2(80) NOT NULL
|
||||
@@ -586,7 +648,7 @@ CREATE TABLE ADDRESSES
|
||||
,BUILDING VARCHAR2(40) NOT NULL
|
||||
,STREET VARCHAR2(60) NOT NULL
|
||||
,CITY VARCHAR2(40) NOT NULL
|
||||
,POSTCODE VARCHAR2(7) NOT NULL
|
||||
,POSTCODE VARCHAR2(8) NOT NULL
|
||||
)
|
||||
/
|
||||
|
||||
|
||||
3
Schema/mipViews.sql
Normal file
3
Schema/mipViews.sql
Normal file
@@ -0,0 +1,3 @@
|
||||
@@V_LATEST_RT_CODE_FOR_ENRO.vw
|
||||
@@V_PROFILE_RT_CODE_FOR_ENRO.vw
|
||||
@@V_PARTY_RELATIONSHIPS.vw
|
||||
Reference in New Issue
Block a user