From b736bb6136ef861a4c67c9744cb4de611e348615 Mon Sep 17 00:00:00 2001 From: hardya Date: Fri, 16 Nov 2007 16:43:58 +0000 Subject: [PATCH] Modules: Added cout_assert.pck - provides assertion utilities. Added cout_err.pck - 'standard' error logging utilities. Added gen_mandatory.prc - generates packages to provided mandatory field checks. Schema: Changed primary key of ENQUIRIES to an ID (also made sequence ENQU_SEQ available). Changes ENQUIRIES.CONSUMER_NAME to FIRST_CONTACT_NAME. Added tables DATA_ITEMS and DATA_ITEM_ROLES to support Modules/gen_mandatory.prc. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2865 248e525c-4dfb-0310-94bc-949c084e9493 --- Data/Seed/enty.ctl | 9 +- Modules/Modules.sql | 6 + Modules/cout_assert.pck | 180 ++++++++++++++ Modules/cout_err.pck | 478 ++++++++++++++++++++++++++++++++++++++ Modules/gen_mandatory.prc | 454 ++++++++++++++++++++++++++++++++++++ Modules/mip_mandatory.pck | 48 ++++ Modules/mip_quotation.pck | 46 ++++ Modules/mip_security.pck | 200 ++++++++++------ Schema/mip.con | 94 +++++--- Schema/mip.ind | 19 +- Schema/mip.sql | 2 +- Schema/mip.sqs | 9 +- Schema/mip.tab | 35 ++- 13 files changed, 1460 insertions(+), 120 deletions(-) create mode 100644 Modules/cout_assert.pck create mode 100644 Modules/cout_err.pck create mode 100644 Modules/gen_mandatory.prc create mode 100644 Modules/mip_mandatory.pck create mode 100644 Modules/mip_quotation.pck diff --git a/Data/Seed/enty.ctl b/Data/Seed/enty.ctl index 3fd91d7..b514a1d 100644 --- a/Data/Seed/enty.ctl +++ b/Data/Seed/enty.ctl @@ -9,11 +9,14 @@ code ) BEGINDATA INSTALL|Installation of new non-Standard meter -STD INSTALL|Installation of Standard meter +STD INSTALL|Installation of new Standard meter OFMAT|Request for OFGEM Meter Accuracy Test (OFMAT) -EXCHANGE|Exchange of meter +EXCHANGE|Exchange of non-Standard meter REMOVE|Removal of non-Standard meter STD REMOVE|Removal of a Standard meter -RELOCATE|Relocation of meters +RELOCATE|Relocation of a meter ADDON|Purchase of standard add-ons for an existing meter module OTHER|Other +CHANGE CAPACITY|Change of capacity +STD EXCHANGE|Exchange of a Standard meter +ADVERSARIAL|Adversarial removal of a meter diff --git a/Modules/Modules.sql b/Modules/Modules.sql index a92a94f..0bff6ff 100644 --- a/Modules/Modules.sql +++ b/Modules/Modules.sql @@ -3,5 +3,11 @@ set define off @@mip_files.pck @@mip_security.pck +@@mip_quotation.pck +@@mip_parties.pck +@@mip_mandatory.pck +@@mip_enquiry.pck +@@cout_assert.pck +@@cout_err.pck exit \ No newline at end of file diff --git a/Modules/cout_assert.pck b/Modules/cout_assert.pck new file mode 100644 index 0000000..bd3af8e --- /dev/null +++ b/Modules/cout_assert.pck @@ -0,0 +1,180 @@ +CREATE OR REPLACE PACKAGE cout_assert IS + /** + -- Package of assertion routines to make it easy to validate assumptions in a declarative fashion. + -- + */ + + SUBTYPE g_t_substitution_list IS cout_err.g_t_substitution_list; + c_empty_substitution_list g_t_substitution_list; + + /** + Asserts whether the given p_condition is true + #param p_condition The condition to be asserted as TRUE + #param p_message The message to be displayed when the assertion is NOT TRUE + #param p_raise_exception Requests that an exception be raised if the assertion is NOT TRUE + #param p_exception The exception to be raised, if requested + #param p_subsitution_list Table of values to be substituted into the generated exception message + #param p_helper_call_level If being used by a 'helper' procedure, indicates the call above the curremt call to be reported + #usage cout_assert.istrue(p_inmo_type IN ('CR', 'CU', 'INMO', 'CA', 'CT'),p_message => 'Invalid inmo_type passed'); + */ + PROCEDURE istrue(p_condition IN BOOLEAN + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 1); + /** + Asserts whether the given p_value IS NOT NULL + #param p_condition The condition to be asserted as TRUE + #param p_message The message to be displayed when the assertion is NOT TRUE + #param p_raise_exception Requests that an exception be raised if the assertion is NOT TRUE + #param p_exception The exception to be raised, if requested + #param p_subsitution_list Table of values to be substituted into the generated exception message + #usage cout_assert.isnotnull(p_value => l_inst_id,p_message => 'Inventory statement not found'); + */ + PROCEDURE isnotnull(p_value IN VARCHAR2 + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); + /** + Asserts whether the given p_value IS NOT NULL + #param p_condition The condition to be asserted as TRUE + #param p_message The message to be displayed when the assertion is NOT TRUE + #param p_raise_exception Requests that an exception be raised if the assertion is NOT TRUE + #param p_exception The exception to be raised, if requested + #param p_subsitution_list Table of values to be substituted into the generated exception message + */ + PROCEDURE isnotnull(p_value IN DATE + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); + /** + Asserts whether the given p_value IS NOT NULL + #param p_condition The condition to be asserted as TRUE + #param p_message The message to be displayed when the assertion is NOT TRUE + #param p_raise_exception Requests that an exception be raised if the assertion is NOT TRUE + #param p_exception The exception to be raised, if requested + #param p_subsitution_list Table of values to be substituted into the generated exception message + */ + PROCEDURE isnotnull(p_value IN NUMBER + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); + /** + Asserts whether the given p_value IS NOT NULL + #param p_condition The condition to be asserted as TRUE + #param p_message The message to be displayed when the assertion is NOT TRUE + #param p_raise_exception Requests that an exception be raised if the assertion is NOT TRUE + #param p_exception The exception to be raised, if requested + #param p_subsitution_list Table of values to be substituted into the generated exception message + */ + PROCEDURE isnotnull(p_value IN BOOLEAN + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); +END cout_assert; +/ +CREATE OR REPLACE PACKAGE BODY cout_assert IS + + g_header CONSTANT VARCHAR2(160) := '$Header: /Isle Of Grain/database/PLSQL/cout_assert.pck 1 7/01/05 12:54 Gilberta $'; + g_revision CONSTANT VARCHAR2(160) := '$Revision: 1 $'; + + PROCEDURE pl(p_msg VARCHAR2) IS + l_start NUMBER := 1; + l_len CONSTANT NUMBER := 255; + BEGIN + WHILE l_start <= length(p_msg) LOOP + dbms_output.put_line(substr(p_msg + ,l_start + ,l_len)); + l_start := l_start + l_len; + END LOOP; + END pl; + + PROCEDURE istrue(p_condition IN BOOLEAN + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 1) IS + BEGIN + IF NOT p_condition + OR p_condition IS NULL THEN + pl('Assertion Failure!'); + pl(p_message); + IF p_raise_exception THEN + cout_err.report_and_stop(p_exception_number => p_exception + ,p_exception_message => 'Assertion Failure:' || + p_message + ,p_substitution_list => p_substitution_list + ,p_helper_call_level => p_helper_call_level); + ELSE + cout_err.report_and_go(p_exception_number => p_exception + ,p_exception_message => p_message + ,p_substitution_list => p_substitution_list + ,p_helper_call_level => p_helper_call_level); + END IF; + END IF; + END istrue; + + PROCEDURE isnotnull(p_value IN VARCHAR2 + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS + BEGIN + istrue(p_value IS NOT NULL + ,p_message + ,p_raise_exception + ,p_exception + ,p_substitution_list + ,2); + END; + + PROCEDURE isnotnull(p_value IN DATE + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS + BEGIN + istrue(p_value IS NOT NULL + ,p_message + ,p_raise_exception + ,p_exception + ,p_substitution_list + ,2); + END; + + PROCEDURE isnotnull(p_value IN NUMBER + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS + BEGIN + istrue(p_value IS NOT NULL + ,p_message + ,p_raise_exception + ,p_exception + ,p_substitution_list + ,2); + END; + + PROCEDURE isnotnull(p_value IN BOOLEAN + ,p_message IN VARCHAR2 + ,p_raise_exception IN BOOLEAN := TRUE + ,p_exception IN NUMBER := -6502 + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS + BEGIN + istrue(p_value IS NOT NULL + ,p_message + ,p_raise_exception + ,p_exception + ,p_substitution_list + ,2); + END; +END cout_assert; +/ diff --git a/Modules/cout_err.pck b/Modules/cout_err.pck new file mode 100644 index 0000000..fa437bb --- /dev/null +++ b/Modules/cout_err.pck @@ -0,0 +1,478 @@ +CREATE OR REPLACE PACKAGE cout_err IS + + g_header CONSTANT VARCHAR2(160) := '$Header: /Isle Of Grain/Database/PLSQL/cout_err.pck 3 1/04/05 16:13 Hardya $'; + g_revision CONSTANT VARCHAR2(160) := '$Revision: 3 $'; + + /** + -- Package containing the common error utility modules used by the Access Manager application + -- #version $Revision: 3 $ + -- #author Andy Hardy + */ + + /** Specifies logging to be table-based (ERROR_LOGS), this the default log method.*/ + c_table CONSTANT PLS_INTEGER := 1; + /** Specifies logging to be file-based. */ + c_file CONSTANT PLS_INTEGER := 2; + /** Specifies logging to be screen-based. */ + c_screen CONSTANT PLS_INTEGER := 3; + + /** Specifies the substitution values that could be passed into any generated error message */ + TYPE g_t_substitution_list IS TABLE OF VARCHAR2(80) INDEX BY BINARY_INTEGER; + c_empty_substitution_list g_t_substitution_list; + + /** + -- Reports the error and RAISES an exception to halt program execution + #param p_exception_number The exception to be raised, defaults to SQLCODE + #param p_exception_message The message to be logged, defaults to the matching message from EXCEPTION_MESSAGES + #param p_helper_call If TRUE, indicates that this report is being produced through a helper function + #param p_error_group The error group that this error should be reported as a part of + */ + PROCEDURE report_and_stop(p_exception_number IN INTEGER := SQLCODE + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 0 + ,p_error_group IN VARCHAR2 := 'APPLICATION' + ,p_severity IN VARCHAR2 := 'E' + ,p_source IN VARCHAR2 := NULL); + + /** + -- Reports the error and continues program execution + #param p_exception_number The exception to be raised, defaults to SQLCODE + #param p_exception_message The message to be logged, defaults to the matching message from EXCEPTION_MESSAGES + #param p_helper_call If TRUE, indicates that this report is being produced through a helper function + #param p_error_group The error group that this error should be reported as a part of + */ + PROCEDURE report_and_go(p_exception_number IN INTEGER := SQLCODE + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 0 + ,p_error_group IN VARCHAR2 := 'APPLICATION' + ,p_severity IN VARCHAR2 := 'E' + ,p_source IN VARCHAR2 := NULL); + + /** + -- Allows the specification of the log destination + #param p_target The destination (as defined by the constants c_table, c_file and c_screen + #param p_dir If file has been chosen, allows the log directory to be specified + #param p_file If file has been chosen, allows the log filename to be specified + */ + PROCEDURE logto(p_target IN PLS_INTEGER + ,p_dir IN VARCHAR2 := NULL + ,p_file IN VARCHAR2 := NULL); + + /** + -- Returns the current log destination. + #return Returns a value matching c_table, c_file or c_screen + */ + FUNCTION logging_to RETURN PLS_INTEGER; + + /** + Return an identification string to link to the source control system. + */ + FUNCTION about RETURN VARCHAR2; + +END cout_err; +/ +CREATE OR REPLACE PACKAGE BODY cout_err IS + g_target PLS_INTEGER := c_table; + g_file VARCHAR2(2000) := 'err.log'; + g_dir VARCHAR2(2000) := '/export/home/mcdonald/INBOX'; + + g_tapi_exception_number CONSTANT NUMBER := -20999; + + PROCEDURE pl(p_msg VARCHAR2) IS + l_start NUMBER := 1; + l_len CONSTANT NUMBER := 255; + BEGIN + WHILE l_start <= length(p_msg) LOOP + dbms_output.put_line(substr(p_msg + ,l_start + ,l_len)); + l_start := l_start + l_len; + END LOOP; + END pl; + + PROCEDURE who_called_me(p_owner OUT VARCHAR2 + ,p_name OUT VARCHAR2 + ,p_lineno OUT NUMBER + ,p_caller_type OUT VARCHAR2 + ,p_helper_call_level IN NUMBER := 0) AS + l_call_stack VARCHAR2(4096) DEFAULT dbms_utility.format_call_stack; + l_num NUMBER; + l_found_stack BOOLEAN DEFAULT FALSE; + l_line VARCHAR2(255); + l_handle VARCHAR2(20); + l_linenum NUMBER; + l_count NUMBER := 0; + l_required_stack_level NUMBER := 5; + BEGIN + -- + l_required_stack_level := l_required_stack_level + p_helper_call_level; + + LOOP + l_num := instr(l_call_stack + ,chr(10)); + EXIT WHEN(l_count = l_required_stack_level OR l_num IS NULL OR + l_num = 0); + -- + l_line := substr(l_call_stack + ,1 + ,l_num - 1); + l_call_stack := substr(l_call_stack + ,l_num + 1); + -- + IF (NOT l_found_stack) THEN + IF (l_line LIKE '%handle%number%name%') THEN + l_found_stack := TRUE; + END IF; + ELSE + l_count := l_count + 1; + -- l_count = 1 is ME + -- l_count = 2 is MY Caller + -- l_count = 3 is Their Caller, etc + IF (l_count = l_required_stack_level) THEN + l_line := ltrim(l_line); + -- handle is the first part + l_handle := substr(l_line + ,1 + ,instr(l_line + ,' ')); + -- + -- Now, remove the object handle, then the white space from the call. + l_line := substr(l_line + ,length(l_handle) + 1); + l_line := ltrim(l_line); + -- Now we can get the line number. + l_linenum := to_number(substr(l_line + ,1 + ,instr(l_line + ,' '))); + -- Remove the line number, and white space. + l_line := substr(l_line + ,length(l_linenum) + 1); + l_line := ltrim(l_line); + + IF (l_line LIKE 'pr%') THEN + l_num := length('procedure '); + ELSIF (l_line LIKE 'fun%') THEN + l_num := length('function '); + ELSIF (l_line LIKE 'package body%') THEN + l_num := length('package body '); + ELSIF (l_line LIKE 'pack%') THEN + l_num := length('package '); + ELSIF (l_line LIKE 'anonymous%') THEN + l_num := length('anonymous block '); + ELSE + l_num := NULL; + END IF; + IF (l_num IS NOT NULL) THEN + p_caller_type := ltrim(rtrim(upper(substr(l_line + ,1 + ,l_num - 1)))); + ELSE + p_caller_type := 'TRIGGER'; + END IF; + + l_line := substr(l_line + ,nvl(l_num + ,1)); + l_num := instr(l_line + ,'.'); + p_owner := ltrim(rtrim(substr(l_line + ,1 + ,l_num - 1))); + p_name := ltrim(rtrim(substr(l_line + ,l_num + 1))); + p_lineno := l_linenum; + END IF; + END IF; + END LOOP; + END who_called_me; + + PROCEDURE get_exception_message(p_exception_number IN exception_messages.exception_number%TYPE + ,p_message IN OUT exception_messages.message%TYPE + ,p_exme_type IN OUT exception_messages.exme_type%TYPE + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS + l_index PLS_INTEGER; + l_err_msg VARCHAR2(512); + l_err_error VARCHAR2(1); + l_err_msg_type VARCHAR2(3); + l_err_msgid INTEGER; + l_err_loc VARCHAR2(240); + BEGIN + + IF p_exception_number = g_tapi_exception_number THEN + IF cg$errors.pop_head(msg => l_err_msg + ,error => l_err_error + ,msg_type => l_err_msg_type + ,msgid => l_err_msgid + ,loc => l_err_loc) THEN + p_message := l_err_msg; + p_exme_type := substr(l_err_error + ,1 + ,1); + cg$errors.push(msg => l_err_msg + ,error => l_err_error + ,msg_type => l_err_msg_type + ,msgid => l_err_msgid + ,loc => l_err_loc); + ELSE + p_message := 'Unable to retrieve TAPI error'; + p_exme_type := 'E'; + END IF; + ELSE + BEGIN + SELECT to_char(abs(exception_number)) || ': ' || message + ,exme_type + INTO p_message + ,p_exme_type + FROM exception_messages + WHERE exception_number = p_exception_number; + EXCEPTION + WHEN no_data_found THEN + p_message := 'UNABLE TO FIND MESSAGE FOR EXCEPTION ' || + to_char(p_exception_number); + p_exme_type := 'E'; + END; + + l_index := p_substitution_list.FIRST; + + LOOP + EXIT WHEN l_index IS NULL; + p_message := REPLACE(p_message + ,'' + ,p_substitution_list(l_index)); + l_index := p_substitution_list.NEXT(l_index); + END LOOP; + END IF; + + END get_exception_message; + + PROCEDURE log(p_exception_number IN PLS_INTEGER := NULL + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 0 + ,p_error_group IN VARCHAR2 := 'APPLICATION' + ,p_severity IN VARCHAR2 := 'E' + ,p_source IN VARCHAR2 := NULL) IS + PRAGMA AUTONOMOUS_TRANSACTION; + l_exception_number PLS_INTEGER := nvl(p_exception_number + ,SQLCODE); + l_exception_message exception_messages.message%TYPE; + l_exme_type exception_messages.exme_type%TYPE := substr(p_severity + ,1 + ,1); + l_owner VARCHAR2(240); + l_name VARCHAR2(240); + l_lineno NUMBER; + l_caller_type VARCHAR2(240); + + BEGIN + + IF p_exception_number BETWEEN - 20999 AND - 20000 THEN + -- + -- application error, see if we have a matching EXCEPTION_MESSAGE + -- + get_exception_message(p_exception_number => l_exception_number + ,p_substitution_list => p_substitution_list + ,p_message => l_exception_message + ,p_exme_type => l_exme_type); + l_exception_message := nvl(l_exception_message + ,p_exception_message); + ELSE + l_exception_message := nvl(p_exception_message + ,SQLERRM); + END IF; + IF p_source IS NULL THEN + who_called_me(p_owner => l_owner + ,p_name => l_name + ,p_lineno => l_lineno + ,p_caller_type => l_caller_type + ,p_helper_call_level => p_helper_call_level); + END IF; + + IF g_target = c_table THEN + INSERT INTO error_logs + (error_type + ,SOURCE + ,severity + ,ERROR_CODE + ,error_message + ,error_date + ,error_status) + VALUES + (p_error_group + ,nvl(p_source + ,l_name || ' line ' || l_lineno) + ,l_exme_type + ,l_exception_number + ,l_exception_message + ,SYSDATE + ,'N'); + + pl('Error log:' || l_caller_type || ',' || l_name || ',' || l_lineno || ',' || + l_exme_type || ',' || l_exception_number || ',' || + l_exception_message || ',' || + to_char(SYSDATE + ,'mm/dd/yyyy hh24:mi:ss')); + + ELSIF g_target = c_file THEN + DECLARE + fid utl_file.file_type; + BEGIN + fid := utl_file.fopen(g_dir + ,g_file + ,'A'); + utl_file.put_line(fid + ,'Error log:' || p_error_group || ',' || + l_caller_type || ',' || l_name || ',' || + l_lineno || ',' || l_exme_type || ',' || + l_exception_number || ',' || l_exception_message || ',' || + to_char(SYSDATE + ,'mm/dd/yyyy hh24:mi:ss')); + utl_file.fclose(fid); + EXCEPTION + WHEN OTHERS THEN + utl_file.fclose(fid); + END; + ELSIF g_target = c_screen THEN + dbms_output.put_line('Error log:' || p_error_group || ',' || + l_caller_type || ',' || l_name || ',' || + l_lineno || ',' || l_exme_type || ',' || + l_exception_number || ',' || + l_exception_message || ',' || + to_char(SYSDATE + ,'mm/dd/yyyy hh24:mi:ss')); + + END IF; + COMMIT; + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(substr(SQLERRM + ,1 + ,80)); + ROLLBACK; + END; + + PROCEDURE logto(p_target IN PLS_INTEGER + ,p_dir IN VARCHAR2 := NULL + ,p_file IN VARCHAR2 := NULL) IS + BEGIN + g_target := p_target; + g_file := nvl(p_file + ,g_file); + g_dir := nvl(p_dir + ,g_dir); + END; + + FUNCTION logging_to RETURN PLS_INTEGER IS + BEGIN + RETURN g_target; + END; + + PROCEDURE RAISE(p_exception_number IN PLS_INTEGER := NULL + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS + l_exception_number PLS_INTEGER := nvl(p_exception_number + ,SQLCODE); + l_exception_message VARCHAR2(1000) := nvl(p_exception_message + ,SQLERRM); + l_exme_type exception_messages.exme_type%TYPE; + BEGIN + IF l_exception_number BETWEEN - 20999 AND - 20000 THEN + get_exception_message(p_exception_number => l_exception_number + ,p_substitution_list => p_substitution_list + ,p_message => l_exception_message + ,p_exme_type => l_exme_type); + + l_exception_message := nvl(l_exception_message + ,p_exception_message); + + raise_application_error(l_exception_number + ,l_exception_message); /* Use positive error numbers -- lots to choose from! */ + ELSIF l_exception_number > 0 + AND l_exception_number NOT IN (1, 100) THEN + raise_application_error(-20000 + ,l_exception_number || '-' || + l_exception_message); /* Can't EXCEPTION_INIT -1403 */ + ELSIF l_exception_number IN (100, -1403) THEN + RAISE no_data_found; /* Re-raise any other exception. */ + ELSIF l_exception_number != 0 THEN + EXECUTE IMMEDIATE 'DECLARE myexc EXCEPTION; ' || + ' PRAGMA EXCEPTION_INIT (myexc, ' || + to_char(l_exception_number) || ');' || + 'BEGIN RAISE myexc; END;'; + END IF; + END; + + PROCEDURE handle(p_exception_number IN PLS_INTEGER := NULL + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_logerr IN BOOLEAN := TRUE + ,p_reraise IN BOOLEAN := FALSE + ,p_helper_call_level IN NUMBER := 0 + ,p_error_group IN VARCHAR2 := 'APPLICATION' + ,p_severity IN VARCHAR2 := 'E' + ,p_source IN VARCHAR2 := NULL) IS + BEGIN + IF p_logerr THEN + log(p_exception_number + ,p_exception_message + ,p_substitution_list + ,p_helper_call_level => p_helper_call_level + ,p_error_group => p_error_group + ,p_severity => p_severity + ,p_source => p_source); + END IF; + IF p_reraise THEN + cout_err.RAISE(p_exception_number + ,p_exception_message + ,p_substitution_list); + END IF; + END; + + PROCEDURE report_and_stop(p_exception_number IN INTEGER := SQLCODE + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 0 + ,p_error_group IN VARCHAR2 := 'APPLICATION' + ,p_severity IN VARCHAR2 := 'E' + ,p_source IN VARCHAR2 := NULL) IS + BEGIN + handle(p_exception_number + ,p_exception_message + ,p_substitution_list + ,TRUE + ,TRUE + ,p_helper_call_level => p_helper_call_level + ,p_error_group => p_error_group + ,p_severity => p_severity + ,p_source => p_source); + END report_and_stop; + + PROCEDURE report_and_go(p_exception_number IN INTEGER := SQLCODE + ,p_exception_message IN VARCHAR2 := NULL + ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list + ,p_helper_call_level IN NUMBER := 0 + ,p_error_group IN VARCHAR2 := 'APPLICATION' + ,p_severity IN VARCHAR2 := 'E' + ,p_source IN VARCHAR2 := NULL) IS + BEGIN + handle(p_exception_number + ,p_exception_message + ,p_substitution_list + ,TRUE + ,FALSE + ,p_helper_call_level => p_helper_call_level + ,p_error_group => p_error_group + ,p_severity => p_severity + ,p_source => p_source); + END report_and_go; + + FUNCTION about RETURN VARCHAR2 IS + BEGIN + RETURN g_header; + END about; + +END cout_err; +/ diff --git a/Modules/gen_mandatory.prc b/Modules/gen_mandatory.prc new file mode 100644 index 0000000..a8e3908 --- /dev/null +++ b/Modules/gen_mandatory.prc @@ -0,0 +1,454 @@ +CREATE OR REPLACE PROCEDURE gen_mandatory IS + TYPE t_pk_cols IS TABLE OF VARCHAR2(80) INDEX BY BINARY_INTEGER; + l_pk_cols t_pk_cols; + l_cursor_id INTEGER; + l_sql dbms_sql.varchar2a; + l_rows_inserted INTEGER; + + PROCEDURE add_sql(p_sqla IN OUT dbms_sql.varchar2a + ,p_sql IN VARCHAR2) IS + l_idx BINARY_INTEGER := p_sqla.COUNT + 1; + BEGIN + p_sqla(l_idx) := p_sql; + END add_sql; + +BEGIN + + DELETE FROM data_item_roles; + DELETE FROM data_items; + + INSERT INTO data_items + (field_name + ,table_name + ,description) + (SELECT DISTINCT field_name + ,table_name + ,description + FROM data_item_roles_import); + + FOR l_enty IN (SELECT code + FROM enquiry_types) LOOP + BEGIN + l_cursor_id := dbms_sql.open_cursor; + l_sql.DELETE; + add_sql(l_sql + ,'INSERT INTO DATA_ITEM_ROLES'); + add_sql(l_sql + ,' (ENTY_CODE'); + add_sql(l_sql + ,' ,DI_FIELD_NAME'); + add_sql(l_sql + ,' ,DI_TABLE_NAME'); + add_sql(l_sql + ,' ,CONDITION'); + add_sql(l_sql + ,' ,DESCRIPTION'); + add_sql(l_sql + ,' )'); + add_sql(l_sql + ,'('); + add_sql(l_sql + ,'SELECT ''' || l_enty.code || ''''); + add_sql(l_sql + ,' ,field_name'); + add_sql(l_sql + ,' ,table_name'); + add_sql(l_sql + ,' ,substr(diri.' || + REPLACE(l_enty.code + ,' ' + ,'_')); + add_sql(l_sql + ,' ,1'); + add_sql(l_sql + ,' ,1)'); + add_sql(l_sql + ,' ,diri.description'); + add_sql(l_sql + ,' FROM data_item_roles_import diri'); + add_sql(l_sql + ,' WHERE substr(diri.' || + REPLACE(l_enty.code + ,' ' + ,'_')); + add_sql(l_sql + ,' ,1'); + add_sql(l_sql + ,' ,1) IN (''M'',''O'')'); + add_sql(l_sql + ,')'); + --dbms_output.put_line(l_sql); + dbms_sql.parse(l_cursor_id + ,l_sql + ,l_sql.FIRST + ,l_sql.LAST + ,TRUE + ,dbms_sql.native); + l_rows_inserted := dbms_sql.EXECUTE(l_cursor_id); + dbms_sql.close_cursor(l_cursor_id); + EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); + dbms_sql.close_cursor(l_cursor_id); + END; + END LOOP; + + FOR l_tables IN (SELECT DISTINCT di_table_name AS table_name + FROM data_item_roles) LOOP + -- create a package, named MIP_'table'_HELPER + -- include functions: + -- 'table'_check_mandatory - confirm whether all mandatory fields have been completed + -- 'table'_get_field_list - return a list of all the fields applicable to the enquiry type + + FOR l_rec IN (SELECT rownum + ,ucc.column_name + FROM user_cons_columns ucc + ,user_constraints uc + WHERE uc.table_name = upper(l_tables.table_name) + AND uc.constraint_type = 'P' + AND ucc.constraint_name = uc.constraint_name + ORDER BY ucc.position) LOOP + l_pk_cols(l_rec.rownum) := l_rec.column_name; + END LOOP; + + -- + -- START OF PACKAGE SPECIFICATION + -- + + l_sql.DELETE; + + add_sql(l_sql + ,'CREATE OR REPLACE PACKAGE MIP_' || l_tables.table_name || + '_HELPER IS'); + add_sql(l_sql + ,' '); + add_sql(l_sql + ,' -- AUTOMATICALLY GENERATED BY GEN_MANDATORY AT ' || + to_char(SYSDATE + ,'DD-MON-YYYY HH24:MI:SS')); + add_sql(l_sql + ,' '); + + -- + -- CHECK_MANDATORY + -- + add_sql(l_sql + ,'FUNCTION check_mandatory ('); + + FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP + IF l_idx != l_pk_cols.FIRST THEN + add_sql(l_sql + ,' ,P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + ELSE + add_sql(l_sql + ,' P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + END IF; + END LOOP; + + add_sql(l_sql + ,' ,p_mandatory_checks OUT MIP_MANDATORY.T_MANDATORY_CHECKS)'); + add_sql(l_sql + ,' RETURN BOOLEAN;'); + add_sql(l_sql + ,' '); + -- + -- GET_FIELD_LIST + -- + add_sql(l_sql + ,'FUNCTION get_field_list (p_enty_code IN ' || + l_tables.table_name || '.' || 'ENTY_CODE%TYPE)'); + add_sql(l_sql + ,' RETURN MIP_MANDATORY.T_FIELDS;'); + + add_sql(l_sql + ,' '); + -- + -- RECORD_EXISTS + -- + add_sql(l_sql + ,'FUNCTION record_exists ('); + + FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP + IF l_idx != l_pk_cols.FIRST THEN + add_sql(l_sql + ,' ,P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + ELSE + add_sql(l_sql + ,' P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + END IF; + END LOOP; + + add_sql(l_sql + ,' )'); + add_sql(l_sql + ,' RETURN BOOLEAN;'); + add_sql(l_sql + ,' '); + + add_sql(l_sql + ,'END MIP_' || l_tables.table_name || '_HELPER;'); + + l_cursor_id := dbms_sql.open_cursor; + dbms_sql.parse(l_cursor_id + ,l_sql + ,l_sql.FIRST + ,l_sql.LAST + ,TRUE + ,dbms_sql.native); + l_rows_inserted := dbms_sql.EXECUTE(l_cursor_id); + dbms_sql.close_cursor(l_cursor_id); + + -- + -- END OF PACKAGE SPECIFICATION + -- + + -- + -- START OF PACKAGE BODY + -- + l_sql.DELETE; + add_sql(l_sql + ,'CREATE OR REPLACE PACKAGE BODY MIP_' || l_tables.table_name || + '_HELPER IS'); + add_sql(l_sql + ,' '); + add_sql(l_sql + ,' -- AUTOMATICALLY GENERATED BY GEN_MANDATORY AT ' || + to_char(SYSDATE + ,'DD-MON-YYYY HH24:MI:SS')); + add_sql(l_sql + ,' '); + + -- + -- CHECK_MANDATORY + -- + add_sql(l_sql + ,'FUNCTION check_mandatory ('); + + FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP + IF l_idx != l_pk_cols.FIRST THEN + add_sql(l_sql + ,' ,P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + ELSE + add_sql(l_sql + ,' P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + END IF; + END LOOP; + + add_sql(l_sql + ,' ,p_mandatory_checks OUT MIP_MANDATORY.T_MANDATORY_CHECKS)'); + add_sql(l_sql + ,' RETURN BOOLEAN'); + add_sql(l_sql + ,'IS'); + add_sql(l_sql + ,' l_rec ' || l_tables.table_name || '%ROWTYPE;'); + add_sql(l_sql + ,' l_mandatory_checks MIP_MANDATORY.T_MANDATORY_CHECKS;'); + add_sql(l_sql + ,' l_return BOOLEAN;'); + add_sql(l_sql + ,'BEGIN'); + + -- get the record + add_sql(l_sql + ,' SELECT * INTO l_rec'); + add_sql(l_sql + ,' FROM ' || l_tables.table_name); + + FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP + IF l_idx != l_pk_cols.FIRST THEN + add_sql(l_sql + ,' AND ' || l_pk_cols(l_idx) || ' = P_' || + l_pk_cols(l_idx)); + ELSE + add_sql(l_sql + ,' WHERE ' || l_pk_cols(l_idx) || ' = P_' || + l_pk_cols(l_idx)); + END IF; + END LOOP; + + add_sql(l_sql + ,' ;'); + + add_sql(l_sql + ,' '); + + FOR l_checks IN (SELECT di_field_name + ,condition + ,enty_code + ,error_message + FROM data_item_roles) LOOP + + IF l_checks.condition = 'M' THEN + add_sql(l_sql + ,' IF l_rec.ENTY_CODE = ''' || l_checks.enty_code || + ''' AND l_rec.' || l_checks.di_field_name || + ' IS NULL THEN'); + add_sql(l_sql + ,' MIP_MANDATORY.add_error(P_mandatory_checks=>l_mandatory_checks, P_field_name=>''' || + l_checks.di_field_name || ''' ,P_error_message=>''' || + nvl(l_checks.error_message + ,'Mandatory Field') || ''');'); + add_sql(l_sql + ,' END IF;'); + add_sql(l_sql + ,' '); + END IF; + END LOOP; + + add_sql(l_sql + ,' '); + add_sql(l_sql + ,' l_return := NOT(l_mandatory_checks.COUNT > 0);'); + add_sql(l_sql + ,' P_mandatory_checks := l_mandatory_checks;'); + add_sql(l_sql + ,' '); + -- return the overall boolean response + add_sql(l_sql + ,' RETURN l_return;'); + add_sql(l_sql + ,'END check_mandatory;'); + add_sql(l_sql + ,' '); + + -- + -- GET_FIELD_LIST + -- + add_sql(l_sql + ,'FUNCTION get_field_list (p_enty_code IN ' || + l_tables.table_name || '.' || 'ENTY_CODE%TYPE)'); + add_sql(l_sql + ,' RETURN MIP_MANDATORY.T_FIELDS'); + add_sql(l_sql + ,'IS'); + add_sql(l_sql + ,' l_fields MIP_MANDATORY.T_FIELDS;'); + add_sql(l_sql + ,'BEGIN'); + + add_sql(l_sql + ,' '); + + add_sql(l_sql + ,' FOR l_checks IN (SELECT di_field_name'); + add_sql(l_sql + ,' ,condition'); + add_sql(l_sql + ,' ,enty_code'); + add_sql(l_sql + ,' ,error_message'); + add_sql(l_sql + ,' FROM data_item_roles'); + add_sql(l_sql + ,' WHERE enty_code = P_enty_code'); + add_sql(l_sql + ,' ) LOOP'); + add_sql(l_sql + ,' MIP_MANDATORY.add_field(P_fields=>l_fields,P_field_name=>l_checks.di_field_name);'); + add_sql(l_sql + ,' END LOOP;'); + + add_sql(l_sql + ,' '); + + add_sql(l_sql + ,' RETURN l_fields;'); + add_sql(l_sql + ,'END get_field_list;'); + + add_sql(l_sql + ,'FUNCTION record_exists ('); + + FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP + IF l_idx != l_pk_cols.FIRST THEN + add_sql(l_sql + ,' ,P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + ELSE + add_sql(l_sql + ,' P_' || l_pk_cols(l_idx) || ' IN ' || + l_tables.table_name || '.' || l_pk_cols(l_idx) || '%TYPE'); + + END IF; + END LOOP; + + add_sql(l_sql + ,' )'); + add_sql(l_sql + ,' RETURN BOOLEAN'); + add_sql(l_sql + ,'IS '); + add_sql(l_sql + ,'BEGIN '); + + -- get the record + add_sql(l_sql + ,' SELECT * INTO l_rec'); + add_sql(l_sql + ,' FROM ' || l_tables.table_name); + + FOR l_idx IN l_pk_cols.FIRST .. l_pk_cols.LAST LOOP + IF l_idx != l_pk_cols.FIRST THEN + add_sql(l_sql + ,' AND ' || l_pk_cols(l_idx) || ' = P_' || + l_pk_cols(l_idx)); + ELSE + add_sql(l_sql + ,' WHERE ' || l_pk_cols(l_idx) || ' = P_' || + l_pk_cols(l_idx)); + END IF; + END LOOP; + + add_sql(l_sql + ,' ;'); + + add_sql(l_sql + ,' RETURN TRUE;'); + add_sql(l_sql + ,' '); + add_sql(l_sql + ,'EXCEPTION'); + add_sql(l_sql + ,' WHEN NO_DATA_FOUND THEN'); + add_sql(l_sql + ,' RETURN FALSE;'); + add_sql(l_sql + ,' '); + add_sql(l_sql + ,'END record_exists;'); + add_sql(l_sql + ,' '); + add_sql(l_sql + ,'END MIP_' || l_tables.table_name || '_HELPER;'); + + -- + -- END OF PACKAGE BODY + -- + + l_cursor_id := dbms_sql.open_cursor; + dbms_sql.parse(l_cursor_id + ,l_sql + ,l_sql.FIRST + ,l_sql.LAST + ,TRUE + ,dbms_sql.native); + l_rows_inserted := dbms_sql.EXECUTE(l_cursor_id); + dbms_sql.close_cursor(l_cursor_id); + + END LOOP; +END gen_mandatory; +/ diff --git a/Modules/mip_mandatory.pck b/Modules/mip_mandatory.pck new file mode 100644 index 0000000..7c45c8e --- /dev/null +++ b/Modules/mip_mandatory.pck @@ -0,0 +1,48 @@ +CREATE OR REPLACE PACKAGE mip_mandatory IS + + -- Author : HARDYA + -- Created : 15/11/2007 15:44:36 + -- Purpose : Support Mandatory Field Processing + + -- Public type declarations + TYPE t_mandatory_check IS RECORD( + field_name VARCHAR2(80) + ,error_message data_item_roles.error_message%TYPE); + + TYPE t_mandatory_checks IS TABLE OF t_mandatory_check INDEX BY BINARY_INTEGER; + + TYPE t_fields IS TABLE OF VARCHAR2(80) INDEX BY BINARY_INTEGER; + + -- Public function and procedure declarations + + PROCEDURE add_error(p_mandatory_checks IN OUT t_mandatory_checks + ,p_field_name IN VARCHAR2 + ,p_error_message IN VARCHAR2); + + PROCEDURE add_field(p_fields IN OUT t_fields + ,p_field_name IN VARCHAR2); +END mip_mandatory; +/ +CREATE OR REPLACE PACKAGE BODY MIP_MANDATORY IS + + PROCEDURE add_error(p_mandatory_checks IN OUT t_mandatory_checks + ,p_field_name IN VARCHAR2 + ,p_error_message IN VARCHAR2) IS + l_idx NUMBER := p_mandatory_checks.COUNT + 1; + BEGIN + p_mandatory_checks(l_idx).field_name := p_field_name; + p_mandatory_checks(l_idx).error_message := p_error_message; + END; + + PROCEDURE add_field(p_fields IN OUT t_fields + ,p_field_name IN VARCHAR2) IS + l_idx NUMBER := p_fields.COUNT + 1; + BEGIN + p_fields(l_idx) := p_field_name; + END add_field; + +BEGIN + -- Initialization + NULL; +END MIP_MANDATORY; +/ diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck new file mode 100644 index 0000000..e1a1e9a --- /dev/null +++ b/Modules/mip_quotation.pck @@ -0,0 +1,46 @@ +CREATE OR REPLACE PACKAGE mip_quotation IS + + -- Author : HARDYA + -- Created : 15/11/2007 11:27:58 + -- Purpose : Handle life-cycle of quotations + + -- Public type declarations + --type is ; + + -- Public constant declarations + -- constant := ; + + -- Public variable declarations + -- ; + + -- Public function and procedure declarations + -- function ( ) return ; + + FUNCTION ready_for_quote(p_id IN enquiries.id%TYPE) RETURN BOOLEAN; + + PROCEDURE produce_quotes(p_id IN enquiries.id%TYPE); +END mip_quotation; +/ +CREATE OR REPLACE PACKAGE BODY mip_quotation IS + + FUNCTION ready_for_quote(p_id IN enquiries.id%TYPE) RETURN BOOLEAN IS + l_mandatory_checks mip_mandatory.t_mandatory_checks; + BEGIN + RETURN mip_enquiries_helper.check_mandatory(p_id => p_id + ,p_mandatory_checks => l_mandatory_checks); + END ready_for_quote; + + PROCEDURE produce_quotes(p_id IN enquiries.id%TYPE) IS + BEGIN + + cout_assert.istrue(ready_for_quote(p_id) + ,'Not all mandatory fields for Enquiry ID=' || p_id || + ' have been completed'); + + END produce_quotes; + +BEGIN + -- Initialization + NULL; +END mip_quotation; +/ diff --git a/Modules/mip_security.pck b/Modules/mip_security.pck index b774a70..2be458d 100644 --- a/Modules/mip_security.pck +++ b/Modules/mip_security.pck @@ -1,19 +1,18 @@ CREATE OR REPLACE PACKAGE mip_security AS --PROCEDURE add_user(p_username IN VARCHAR2, p_password IN VARCHAR2); + FUNCTION get_user_status(p_username IN VARCHAR2) RETURN VARCHAR2; + PROCEDURE login(p_uname IN VARCHAR2, + p_password IN VARCHAR2, + p_session_id IN VARCHAR2, + p_flow_page IN VARCHAR2); - PROCEDURE login(p_uname IN VARCHAR2 - ,p_password IN VARCHAR2 - ,p_session_id IN VARCHAR2 - ,p_flow_page IN VARCHAR2); + FUNCTION get_hash(p_username IN VARCHAR2, p_password IN VARCHAR2) + RETURN VARCHAR2; - FUNCTION get_hash(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) RETURN VARCHAR2; + PROCEDURE valid_user2(p_username IN VARCHAR2, p_password IN VARCHAR2); - PROCEDURE valid_user(p_username IN VARCHAR2 - ,p_password IN VARCHAR2); - - FUNCTION valid_user(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) RETURN BOOLEAN; + FUNCTION valid_user(p_username IN VARCHAR2, p_password IN VARCHAR2) + RETURN BOOLEAN; FUNCTION user_screen(p_username IN VARCHAR2) RETURN BOOLEAN; @@ -24,34 +23,75 @@ CREATE OR REPLACE PACKAGE mip_security AS -- -- absence of the page or item from the access controls table -- infers that access to the page and item is always allowed - FUNCTION access_allowed(p_username IN VARCHAR2 - ,p_page_number IN NUMBER - ,p_item_name IN VARCHAR2 DEFAULT NULL) + FUNCTION access_allowed(p_username IN VARCHAR2, + p_page_number IN NUMBER, + p_item_name IN VARCHAR2 DEFAULT NULL) RETURN BOOLEAN; + PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2); END mip_security; / CREATE OR REPLACE PACKAGE BODY mip_security AS - PROCEDURE login(p_uname IN VARCHAR2 - ,p_password IN VARCHAR2 - ,p_session_id IN VARCHAR2 - ,p_flow_page IN VARCHAR2) IS + + /* + returns the current status of the user + */ + FUNCTION get_user_status(p_username IN VARCHAR2) RETURN VARCHAR2 AS + l_status VARCHAR2(10); BEGIN - wwv_flow_custom_auth_std.login(p_uname => p_uname - ,p_password => p_password - ,p_session_id => p_session_id - ,p_flow_page => p_flow_page || ':' || 1); + SELECT p.status + INTO l_status + FROM parties p + WHERE upper(p.username) = upper(p_username); + + RETURN l_status; + EXCEPTION + WHEN no_data_found THEN + raise_application_error(-20000, 'User not found in the system'); + -- + END get_user_status; + -- + + /* + logs the user into the system and registers with APEX. + */ + PROCEDURE login(p_uname IN VARCHAR2, + p_password IN VARCHAR2, + p_session_id IN VARCHAR2, + p_flow_page IN VARCHAR2) IS + BEGIN + IF get_user_status(p_uname) = 'OPEN' THEN + wwv_flow_custom_auth_std.login(p_uname => p_uname, + p_password => p_password, + p_session_id => p_session_id, + p_flow_page => p_flow_page); + ELSIF get_user_status(p_uname) = 'EXPIRED' THEN + -- we need to update the password + wwv_flow_custom_auth_std.login(p_uname => p_uname, + p_password => p_password, + p_session_id => p_session_id, + p_flow_page => v('APP_ID') || ':102'); + ELSE -- user password has been locked. Log them off and tell them + wwv_flow_custom_auth_std.login(p_uname => p_uname, + p_password => p_password, + p_session_id => p_session_id, + p_flow_page => v('APP_ID') || ':500:&NOTIFICATION_MESSAGE=User account has expired, please contact the system administrator.'); + END IF; EXCEPTION WHEN OTHERS THEN RAISE; END login; - FUNCTION get_hash(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) RETURN VARCHAR2 AS + /* + gets the has value of the password for storing in the database. + + --*/ + FUNCTION get_hash(p_username IN VARCHAR2, p_password IN VARCHAR2) + RETURN VARCHAR2 AS BEGIN RETURN dbms_obfuscation_toolkit.md5(input_string => upper(p_username) || '/' || - upper(p_password)); + p_password); END get_hash; /* @@ -60,45 +100,41 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS changed the table to use to be the MIP parties table */ - PROCEDURE valid_user(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) AS + PROCEDURE valid_user2(p_username IN VARCHAR2, p_password IN VARCHAR2) AS l_password_created_on DATE; - BEGIN - + BEGIN SELECT created_on - INTO l_password_created_on - FROM (SELECT pwd.prty_id - ,pwd.password_hash - ,MAX(pwd.created_on) over(PARTITION BY pwd.prty_id) AS latest_pwd_date - ,pwd.created_on - FROM passwords pwd - ,parties prty - WHERE prty.username = p_username - AND pwd.prty_id = prty.id) pwd - WHERE pwd.created_on = pwd.latest_pwd_date - AND pwd.password_hash = get_hash(p_username - ,p_password); - + INTO l_password_created_on + FROM (SELECT pwd.prty_id + ,pwd.password_hash + ,MAX(pwd.created_on) over(PARTITION BY pwd.prty_id) AS latest_pwd_date + ,pwd.created_on + FROM passwords pwd + ,parties prty + WHERE upper(prty.username) = upper(p_username) + AND pwd.prty_id = prty.id) pwd + WHERE pwd.created_on = pwd.latest_pwd_date + AND pwd.password_hash = get_hash(p_username + ,p_password); + EXCEPTION WHEN no_data_found THEN - raise_application_error(-20000 - ,'Invalid username / password.'); - END valid_user; + raise_application_error(-20000, 'Invalid username / password.'); + END valid_user2; - FUNCTION valid_user(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) RETURN BOOLEAN AS + FUNCTION valid_user(p_username IN VARCHAR2, p_password IN VARCHAR2) + RETURN BOOLEAN AS BEGIN - valid_user(p_username - ,p_password); + valid_user2(p_username, p_password); RETURN TRUE; EXCEPTION WHEN OTHERS THEN RETURN FALSE; END valid_user; - FUNCTION access_allowed(p_username IN VARCHAR2 - ,p_page_number IN NUMBER - ,p_item_name IN VARCHAR2 DEFAULT NULL) + FUNCTION access_allowed(p_username IN VARCHAR2, + p_page_number IN NUMBER, + p_item_name IN VARCHAR2 DEFAULT NULL) RETURN BOOLEAN IS l_access_allowed VARCHAR2(3); BEGIN @@ -108,15 +144,15 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS -- if null is returned from the query, it implies that there -- is no access control against the given page and item - IF p_page_number IN (101, 500) THEN + IF p_page_number IN (101, 102, 500) THEN RETURN TRUE; END IF; SELECT access_allowed INTO l_access_allowed - FROM (SELECT accl.page_number - ,accl.rt_code - ,parl.rt_code - ,CASE + FROM (SELECT accl.page_number, + accl.rt_code, + parl.rt_code, + CASE WHEN accl.rt_code IS NULL THEN 'YES' WHEN accl.rt_code = parl.rt_code THEN @@ -124,25 +160,19 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS ELSE 'NO' END access_allowed - FROM (SELECT prty.username - ,rt_code - FROM parties prty - ,party_roles parl + FROM (SELECT prty.username, rt_code + FROM parties prty, party_roles parl WHERE parl.prty_id = prty.id - AND upper(prty.username) = upper(p_username)) parl - ,access_controls accl + AND upper(prty.username) = upper(p_username)) parl, + access_controls accl WHERE accl.rt_code = parl.rt_code(+) AND accl.page_number = p_page_number - AND (upper(nvl(accl.item - ,'NOCONTROL')) = - upper(nvl(p_item_name - ,nvl(accl.item - ,'NOCONTROL')))) + AND (upper(nvl(accl.item, 'NOCONTROL')) = + upper(nvl(p_item_name, nvl(accl.item, 'NOCONTROL')))) ORDER BY parl.rt_code) WHERE rownum < 2; - IF nvl(l_access_allowed - ,'YES') = 'YES' THEN + IF nvl(l_access_allowed, 'YES') = 'YES' THEN RETURN TRUE; ELSE RETURN FALSE; @@ -150,8 +180,8 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS EXCEPTION WHEN no_data_found THEN - raise_application_error(-20000 - ,'Application Error: Item Name ' || + raise_application_error(-20000, + 'Application Error: Item Name ' || p_item_name || ' for page ' || p_page_number || ' is missing from the ACCESS_CONTROLS table'); END access_allowed; @@ -185,6 +215,32 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS WHEN OTHERS THEN RETURN FALSE; END admin_screen; + -- + + /* + creates a new password + */ + PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2) IS + l_prty_id NUMBER; + --sql_str VARCHAR2(250) := ''; + BEGIN + SELECT id + INTO l_prty_id + FROM parties + WHERE upper(username) = upper(p_username); + + INSERT INTO passwords(prty_id, password_hash, created_on, created_by) + VALUES (l_prty_id, get_hash(p_username, p_password), SYSDATE, NULL); + + -- now we ned to update the user's status to OPEN + UPDATE parties + SET status = 'OPEN' + WHERE id = l_prty_id; + + EXCEPTION + WHEN OTHERS THEN + raise_application_error(-20002, SQLERRM); + END new_password; END mip_security; / diff --git a/Schema/mip.con b/Schema/mip.con index 90a2b42..15b9294 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 Thu Nov 15 10:19:01 2007 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Thu Nov 15 16:13:29 2007 by Server Generator 10.1.2.6.18 PROMPT Creating Primary Key on 'REGULATORS' ALTER TABLE REGULATORS @@ -46,6 +46,15 @@ ALTER TABLE CONTACT_MECHANISMS (ID)) / +PROMPT Creating Primary Key on 'DATA_ITEM_ROLES' +ALTER TABLE DATA_ITEM_ROLES + ADD (CONSTRAINT DIR_PK PRIMARY KEY + (CONDITION + ,ENTY_CODE + ,DI_TABLE_NAME + ,DI_FIELD_NAME)) +/ + PROMPT Creating Primary Key on 'PARTY_ADDRESS_ROLES' ALTER TABLE PARTY_ADDRESS_ROLES ADD (CONSTRAINT PAR_PK PRIMARY KEY @@ -149,7 +158,7 @@ ALTER TABLE ENQUIRY_EVENTS ADD (CONSTRAINT ENEV_PK PRIMARY KEY (EVENT_DATE ,ENST_CODE - ,ENQU_CODE)) + ,ENQU_ID)) / PROMPT Creating Primary Key on 'PARTIES' @@ -164,6 +173,13 @@ ALTER TABLE ENQUIRY_TYPES (CODE)) / +PROMPT Creating Primary Key on 'DATA_ITEMS' +ALTER TABLE DATA_ITEMS + ADD (CONSTRAINT DI_PK PRIMARY KEY + (TABLE_NAME + ,FIELD_NAME)) +/ + PROMPT Creating Primary Key on 'QUOTE_ITEMS' ALTER TABLE QUOTE_ITEMS ADD (CONSTRAINT QUIT_PK PRIMARY KEY @@ -223,7 +239,7 @@ PROMPT Creating Primary Key on 'ENQUIRY_ROLES' ALTER TABLE ENQUIRY_ROLES ADD (CONSTRAINT ENRO_PK PRIMARY KEY (PRTY_ID - ,ENQU_CODE + ,ENQU_ID ,RT_CODE)) / @@ -236,7 +252,7 @@ ALTER TABLE ACCESS_CONTROLS PROMPT Creating Primary Key on 'ENQUIRIES' ALTER TABLE ENQUIRIES ADD (CONSTRAINT ENQU_PK PRIMARY KEY - (CODE)) + (ID)) / PROMPT Creating Primary Key on 'BASES' @@ -327,20 +343,20 @@ ALTER TABLE COSTS (AICO_CODE)) / - + PROMPT Creating Check Constraint on 'METER_SIZE_CODES' ALTER TABLE METER_SIZE_CODES - ADD (CONSTRAINT AVCON_1195121941_VALID_000 CHECK (VALID_FOR_EXISTING_METER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_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_1195121941_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'COSTS' ALTER TABLE COSTS - ADD (CONSTRAINT AVCON_1195121941_COST__000 CHECK (COST_TYPE IN ('HOCO', 'BACO', 'COST', 'AICO', 'MOCO', 'MECO'))) + ADD (CONSTRAINT AVCON_1195143208_COST__000 CHECK (COST_TYPE IN ('HOCO', 'BACO', 'COST', 'AICO', 'MOCO', 'MECO'))) / PROMPT Creating Check Constraint on 'PARTY_RELATIONSHIPS' @@ -352,84 +368,84 @@ to_parl_rt_code = to_prtp_rt_code)) PROMPT Creating Check Constraint on 'QUOTES' ALTER TABLE QUOTES - ADD (CONSTRAINT AVCON_1195121941_QUTE__000 CHECK (QUTE_TYPE IN ('QUTE', 'SQ', 'AQ', 'MQ'))) + ADD (CONSTRAINT AVCON_1195143208_QUTE__000 CHECK (QUTE_TYPE IN ('QUTE', 'AQ', 'SQ', 'MQ'))) / PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1195121941_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED'))) + ADD (CONSTRAINT AVCON_1195143208_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED'))) / PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1195121941_PRTY__000 CHECK (PRTY_TYPE + ADD (CONSTRAINT AVCON_1195143208_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_1195121941_RT_TY_000 CHECK (RT_TYPE IN ('ENRT', 'QURT', 'PRT', 'PCMRT', 'PART', 'RT'))) + ADD (CONSTRAINT AVCON_1195143208_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_1195121941_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM'))) + ADD (CONSTRAINT AVCON_1195143208_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_LOGGE_000 CHECK (LOGGER_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_LOGGE_000 CHECK (LOGGER_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating'))) + ADD (CONSTRAINT AVCON_1195143208_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D'))) + ADD (CONSTRAINT AVCON_1195143208_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1195143208_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1195121941_EXIST_000 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C'))) + ADD (CONSTRAINT AVCON_1195143208_EXIST_000 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C'))) / @@ -472,6 +488,22 @@ ALTER TABLE CONTACT_MECHANISMS ADD (CONSTRAINT (CODE)) / +PROMPT Creating Foreign Key on 'DATA_ITEM_ROLES' +ALTER TABLE DATA_ITEM_ROLES ADD (CONSTRAINT + DIR_ENTY_FK FOREIGN KEY + (ENTY_CODE) REFERENCES ENQUIRY_TYPES + (CODE)) +/ + +PROMPT Creating Foreign Key on 'DATA_ITEM_ROLES' +ALTER TABLE DATA_ITEM_ROLES ADD (CONSTRAINT + DIR_DI_FK FOREIGN KEY + (DI_TABLE_NAME + ,DI_FIELD_NAME) REFERENCES DATA_ITEMS + (TABLE_NAME + ,FIELD_NAME)) +/ + PROMPT Creating Foreign Key on 'PARTY_ADDRESS_ROLES' ALTER TABLE PARTY_ADDRESS_ROLES ADD (CONSTRAINT PAR_PADDR_FK FOREIGN KEY @@ -605,8 +637,8 @@ ALTER TABLE PARTY_RELATIONSHIPS ADD (CONSTRAINT PROMPT Creating Foreign Key on 'QUOTES' ALTER TABLE QUOTES ADD (CONSTRAINT QUTE_ENQU_FK FOREIGN KEY - (ENQU_CODE) REFERENCES ENQUIRIES - (CODE)) + (ENQU_ID) REFERENCES ENQUIRIES + (ID)) / PROMPT Creating Foreign Key on 'QUOTE_EVENTS' @@ -647,8 +679,8 @@ ALTER TABLE PARTY_ADDRESSES ADD (CONSTRAINT PROMPT Creating Foreign Key on 'ENQUIRY_EVENTS' ALTER TABLE ENQUIRY_EVENTS ADD (CONSTRAINT ENEV_ENQU_FK FOREIGN KEY - (ENQU_CODE) REFERENCES ENQUIRIES - (CODE)) + (ENQU_ID) REFERENCES ENQUIRIES + (ID)) / PROMPT Creating Foreign Key on 'ENQUIRY_EVENTS' @@ -731,8 +763,8 @@ ALTER TABLE SLAMSHUT_VALVES ADD (CONSTRAINT PROMPT Creating Foreign Key on 'ENQUIRY_ROLES' ALTER TABLE ENQUIRY_ROLES ADD (CONSTRAINT ENRO_ENQU_FK FOREIGN KEY - (ENQU_CODE) REFERENCES ENQUIRIES - (CODE)) + (ENQU_ID) REFERENCES ENQUIRIES + (ID)) / PROMPT Creating Foreign Key on 'ENQUIRY_ROLES' diff --git a/Schema/mip.ind b/Schema/mip.ind index 49c99e6..f68f639 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 Thu Nov 15 10:19:01 2007 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Thu Nov 15 16:13:28 2007 by Server Generator 10.1.2.6.18 PROMPT Creating Index 'REGU_RETY_FK_I' @@ -30,6 +30,17 @@ CREATE INDEX COME_COMT_FK_I ON CONTACT_MECHANISMS (COMT_CODE) / +PROMPT Creating Index 'DIR_DI_FK_I' +CREATE INDEX DIR_DI_FK_I ON DATA_ITEM_ROLES + (DI_TABLE_NAME + ,DI_FIELD_NAME) +/ + +PROMPT Creating Index 'DIR_ENTY_FK_I' +CREATE INDEX DIR_ENTY_FK_I ON DATA_ITEM_ROLES + (ENTY_CODE) +/ + PROMPT Creating Index 'PAR_PADDR_FK_I' CREATE INDEX PAR_PADDR_FK_I ON PARTY_ADDRESS_ROLES (PADDR_PRTY_ID @@ -121,7 +132,7 @@ CREATE INDEX PREL_PARL_TO_FK_I ON PARTY_RELATIONSHIPS PROMPT Creating Index 'QUTE_ENQU_FK_I' CREATE INDEX QUTE_ENQU_FK_I ON QUOTES - (ENQU_CODE) + (ENQU_ID) / PROMPT Creating Index 'QUEV_QUST_FK_I' @@ -156,7 +167,7 @@ CREATE INDEX ENEV_ENST_FK_I ON ENQUIRY_EVENTS PROMPT Creating Index 'ENEV_ENQU_FK_I' CREATE INDEX ENEV_ENQU_FK_I ON ENQUIRY_EVENTS - (ENQU_CODE) + (ENQU_ID) / PROMPT Creating Index 'QUIT_QUTE_FK_I' @@ -221,7 +232,7 @@ CREATE INDEX ENRO_PRTY_FK_I ON ENQUIRY_ROLES PROMPT Creating Index 'ENRO_ENQU_FK_I' CREATE INDEX ENRO_ENQU_FK_I ON ENQUIRY_ROLES - (ENQU_CODE) + (ENQU_ID) / PROMPT Creating Index 'ACCL_RT_FK_I' diff --git a/Schema/mip.sql b/Schema/mip.sql index bfe7e65..c50ec01 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 Thu Nov 15 10:19:01 2007 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Thu Nov 15 16:13:29 2007 by Server Generator 10.1.2.6.18 SPOOL mip.lst diff --git a/Schema/mip.sqs b/Schema/mip.sqs index e2dc0f8..91ffe15 100644 --- a/Schema/mip.sqs +++ b/Schema/mip.sqs @@ -1,7 +1,14 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.sqs -- --- Generated for Oracle 10g on Thu Nov 15 10:19:01 2007 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Thu Nov 15 16:13:29 2007 by Server Generator 10.1.2.6.18 +PROMPT Creating Sequence 'ENQU_SEQ' +CREATE SEQUENCE ENQU_SEQ + NOMAXVALUE + NOMINVALUE + NOCYCLE +/ + PROMPT Creating Sequence 'COST_SEQ' CREATE SEQUENCE COST_SEQ NOMAXVALUE diff --git a/Schema/mip.tab b/Schema/mip.tab index 1fe7eaf..f65e54a 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 Thu Nov 15 10:19:01 2007 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Thu Nov 15 16:13:28 2007 by Server Generator 10.1.2.6.18 @@ -63,6 +63,17 @@ CREATE TABLE CONTACT_MECHANISMS ) / +PROMPT Creating Table 'DATA_ITEM_ROLES' +CREATE TABLE DATA_ITEM_ROLES + (DI_FIELD_NAME VARCHAR2(240) NOT NULL + ,DI_TABLE_NAME VARCHAR2(240) NOT NULL + ,ENTY_CODE VARCHAR2(80) NOT NULL + ,CONDITION VARCHAR2(30) NOT NULL + ,ERROR_MESSAGE VARCHAR2(80) NOT NULL + ,DESCRIPTION VARCHAR2(80) + ) +/ + PROMPT Creating Table 'PARTY_ADDRESS_ROLES' CREATE TABLE PARTY_ADDRESS_ROLES (START_DATE DATE NOT NULL @@ -171,7 +182,7 @@ CREATE TABLE PARTY_RELATIONSHIPS PROMPT Creating Table 'QUOTES' CREATE TABLE QUOTES - (ENQU_CODE VARCHAR2(80) NOT NULL + (ENQU_ID NUMBER NOT NULL ,DOCUMENT_LOCATION VARCHAR2(255) ,VALID_FROM DATE ,VALID_UNTIL DATE @@ -212,7 +223,7 @@ CREATE TABLE PARTY_ADDRESSES PROMPT Creating Table 'ENQUIRY_EVENTS' CREATE TABLE ENQUIRY_EVENTS - (ENQU_CODE VARCHAR2(80) NOT NULL + (ENQU_ID NUMBER NOT NULL ,ENST_CODE VARCHAR2(80) NOT NULL ,EVENT_DATE DATE NOT NULL ) @@ -233,7 +244,7 @@ CREATE TABLE PARTIES ,GT_7B_CONTRACT_REF VARCHAR2(25) ,ADVERSARIAL_CONTRACT_REF VARCHAR2(25) ,USERNAME VARCHAR2(80) - ,STATUS VARCHAR2(6) + ,STATUS VARCHAR2(7) ,FIRST_NAME VARCHAR2(80) ,LAST_NAME VARCHAR2(80) ,PERSONAL_TITLE VARCHAR2(6) @@ -250,6 +261,14 @@ CREATE TABLE ENQUIRY_TYPES ) / +PROMPT Creating Table 'DATA_ITEMS' +CREATE TABLE DATA_ITEMS + (FIELD_NAME VARCHAR2(240) NOT NULL + ,TABLE_NAME VARCHAR2(240) NOT NULL + ,DESCRIPTION VARCHAR2(240) + ) +/ + PROMPT Creating Table 'QUOTE_ITEMS' CREATE TABLE QUOTE_ITEMS (ITEM_SEQUENCE NUMBER NOT NULL @@ -339,7 +358,7 @@ CREATE TABLE SLAMSHUT_VALVES PROMPT Creating Table 'ENQUIRY_ROLES' CREATE TABLE ENQUIRY_ROLES - (ENQU_CODE VARCHAR2(80) NOT NULL + (ENQU_ID NUMBER NOT NULL ,PRTY_ID NUMBER(*,0) NOT NULL ,RT_CODE VARCHAR2(80) NOT NULL ,START_DATE DATE @@ -359,8 +378,7 @@ CREATE TABLE ACCESS_CONTROLS PROMPT Creating Table 'ENQUIRIES' CREATE TABLE ENQUIRIES - (CODE VARCHAR2(80) NOT NULL - ,REQUIRED_MESC_CODE VARCHAR2(80) + (ID NUMBER NOT NULL ,FIRST_CONTACT_FAX VARCHAR2(15) ,FIRST_CONTACT_EMAIL VARCHAR2(240) ,SECOND_CONTACT_TELEPHONE_1 VARCHAR2(15) @@ -391,10 +409,11 @@ CREATE TABLE ENQUIRIES ,EXISTING_MESC_CODE VARCHAR2(80) ,EXISTING_SVCP_CODE VARCHAR2(80) ,METY_CODE VARCHAR2(80) + ,REQUIRED_MESC_CODE VARCHAR2(80) ,REQUIRED_SVCP_CODE VARCHAR2(80) ,AGENT_CONTACT_VALUE VARCHAR2(240) ,TRANSACTION_REFERENCE VARCHAR2(80) - ,CONSUMER_NAME VARCHAR2(80) + ,FIRST_CONTACT_NAME VARCHAR2(80) ,SECOND_CONTACT_TELEPHONE_2 VARCHAR2(15) ,SECOND_CONTACT_EMAIL VARCHAR2(240) ,INSTALL_SUB_BUILDING VARCHAR2(40)