diff --git a/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls b/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls index b7e8ab7..ce2c50d 100644 Binary files a/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls and b/Documentation/Design/DatabaseItemToFunctionalSpecificationReference.xls differ diff --git a/Modules/cout_assert.pck b/Modules/cout_assert.pck index bd3af8e..72bbdd2 100644 --- a/Modules/cout_assert.pck +++ b/Modules/cout_assert.pck @@ -6,6 +6,8 @@ CREATE OR REPLACE PACKAGE cout_assert IS SUBTYPE g_t_substitution_list IS cout_err.g_t_substitution_list; c_empty_substitution_list g_t_substitution_list; + + g_default_exception_number NUMBER := -20000; /** Asserts whether the given p_condition is true @@ -20,7 +22,7 @@ CREATE OR REPLACE PACKAGE cout_assert IS PROCEDURE istrue(p_condition IN BOOLEAN ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list ,p_helper_call_level IN NUMBER := 1); /** @@ -35,7 +37,7 @@ CREATE OR REPLACE PACKAGE cout_assert IS PROCEDURE isnotnull(p_value IN VARCHAR2 ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); /** Asserts whether the given p_value IS NOT NULL @@ -48,7 +50,7 @@ CREATE OR REPLACE PACKAGE cout_assert IS PROCEDURE isnotnull(p_value IN DATE ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); /** Asserts whether the given p_value IS NOT NULL @@ -61,7 +63,7 @@ CREATE OR REPLACE PACKAGE cout_assert IS PROCEDURE isnotnull(p_value IN NUMBER ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); /** Asserts whether the given p_value IS NOT NULL @@ -74,7 +76,7 @@ CREATE OR REPLACE PACKAGE cout_assert IS PROCEDURE isnotnull(p_value IN BOOLEAN ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list); END cout_assert; / @@ -82,7 +84,7 @@ 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; @@ -98,7 +100,7 @@ CREATE OR REPLACE PACKAGE BODY cout_assert IS PROCEDURE istrue(p_condition IN BOOLEAN ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list ,p_helper_call_level IN NUMBER := 1) IS BEGIN @@ -124,7 +126,7 @@ CREATE OR REPLACE PACKAGE BODY cout_assert IS PROCEDURE isnotnull(p_value IN VARCHAR2 ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS BEGIN istrue(p_value IS NOT NULL @@ -138,7 +140,7 @@ CREATE OR REPLACE PACKAGE BODY cout_assert IS PROCEDURE isnotnull(p_value IN DATE ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS BEGIN istrue(p_value IS NOT NULL @@ -152,7 +154,7 @@ CREATE OR REPLACE PACKAGE BODY cout_assert IS PROCEDURE isnotnull(p_value IN NUMBER ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS BEGIN istrue(p_value IS NOT NULL @@ -166,7 +168,7 @@ CREATE OR REPLACE PACKAGE BODY cout_assert IS PROCEDURE isnotnull(p_value IN BOOLEAN ,p_message IN VARCHAR2 ,p_raise_exception IN BOOLEAN := TRUE - ,p_exception IN NUMBER := -6502 + ,p_exception IN NUMBER := g_default_exception_number ,p_substitution_list IN g_t_substitution_list := c_empty_substitution_list) IS BEGIN istrue(p_value IS NOT NULL diff --git a/Modules/cout_err.pck b/Modules/cout_err.pck index 51a10c4..1492d41 100644 --- a/Modules/cout_err.pck +++ b/Modules/cout_err.pck @@ -246,7 +246,7 @@ CREATE OR REPLACE PACKAGE BODY cout_err IS BEGIN - IF p_exception_number BETWEEN - 20999 AND - 20000 THEN + IF p_exception_number BETWEEN - 20999 AND - 20001 THEN -- -- application error, see if we have a matching EXCEPTION_MESSAGE -- diff --git a/Modules/gen_mandatory.prc b/Modules/gen_mandatory.prc index ee23190..f31b23b 100644 --- a/Modules/gen_mandatory.prc +++ b/Modules/gen_mandatory.prc @@ -15,17 +15,6 @@ CREATE OR REPLACE PROCEDURE gen_mandatory IS BEGIN DELETE FROM data_item_roles; - DELETE FROM data_items; - - INSERT INTO data_items - (field_name - ,table_name - ,description) - (SELECT DISTINCT field_name - ,'ENQUIRIES' as table_name - ,description - FROM ext_dataitem_roles - WHERE field_name IS NOT NULL); FOR l_enty IN (SELECT code FROM enquiry_types) LOOP @@ -37,13 +26,15 @@ BEGIN add_sql(l_sql ,' (ENTY_CODE'); add_sql(l_sql - ,' ,DI_FIELD_NAME'); + ,' ,FIELD_NAME'); add_sql(l_sql - ,' ,DI_TABLE_NAME'); + ,' ,TABLE_NAME'); add_sql(l_sql ,' ,CONDITION'); add_sql(l_sql ,' ,DESCRIPTION'); + add_sql(l_sql + ,' ,DISPLAY_SEQUENCE'); add_sql(l_sql ,' )'); add_sql(l_sql @@ -51,15 +42,17 @@ BEGIN add_sql(l_sql ,'SELECT ''' || l_enty.code || ''''); add_sql(l_sql - ,' ,''ENQUIRIES'' as field_name'); + ,' ,field_name'); add_sql(l_sql - ,' ,table_name'); + ,' ,''ENQUIRIES'' as table_name'); add_sql(l_sql ,' ,diri.' || REPLACE(l_enty.code ,' ' ,'_')); add_sql(l_sql ,' ,diri.description'); + add_sql(l_sql + ,' ,diri.display_sequence'); add_sql(l_sql ,' FROM ext_dataitem_roles diri'); add_sql(l_sql @@ -89,7 +82,7 @@ BEGIN END; END LOOP; - FOR l_tables IN (SELECT DISTINCT di_table_name AS table_name + FOR l_tables IN (SELECT DISTINCT table_name AS table_name FROM data_item_roles) LOOP -- create a package, named MIP_'table'_HELPER -- include functions: @@ -125,9 +118,24 @@ BEGIN add_sql(l_sql ,' '); + add_sql(l_sql + ,' SUBTYPE T_REC_' || l_tables.table_name || ' IS ' || + l_tables.table_name || '%ROWTYPE;'); + add_sql(l_sql + ,' '); -- -- CHECK_MANDATORY -- + add_sql(l_sql + ,'FUNCTION check_mandatory (p_rec in T_REC_' || + l_tables.table_name); + add_sql(l_sql + ,' ,p_mandatory_checks OUT MIP_MANDATORY.T_MANDATORY_CHECKS)'); + add_sql(l_sql + ,' RETURN BOOLEAN;'); + add_sql(l_sql + ,' '); + add_sql(l_sql ,'FUNCTION check_mandatory ('); @@ -151,6 +159,7 @@ BEGIN ,' RETURN BOOLEAN;'); add_sql(l_sql ,' '); + -- -- GET_FIELD_LIST -- @@ -225,6 +234,79 @@ BEGIN -- -- CHECK_MANDATORY -- + add_sql(l_sql + ,'FUNCTION check_mandatory (p_rec in T_REC_' || + l_tables.table_name); + 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_mandatory_checks MIP_MANDATORY.T_MANDATORY_CHECKS;'); + add_sql(l_sql + ,' l_return BOOLEAN;'); + + add_sql(l_sql + ,' '); + + add_sql(l_sql + ,'BEGIN'); + + add_sql(l_sql + ,' cout_assert.isnotnull(p_rec.id,''NULL enquiry id'');'); + add_sql(l_sql + ,' cout_assert.isnotnull(p_rec.enty_code,''NULL enquiry ENTY_CODE'');'); + FOR l_checks IN (SELECT field_name + ,condition + ,enty_code + ,error_message + FROM data_item_roles) LOOP + + IF l_checks.condition = 'M' THEN + add_sql(l_sql + ,' IF p_rec.ENTY_CODE = ''' || l_checks.enty_code || + ''' AND p_rec.' || l_checks.field_name || + ' IS NULL THEN'); + add_sql(l_sql + ,' MIP_MANDATORY.add_error(P_mandatory_checks=>l_mandatory_checks, P_field_name=>''' || + l_checks.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 + ,' MIP_HELPER_SPECIAL_CASES.table_' || l_tables.table_name || + '(p_rec => p_rec, p_mandatory_checks=>l_mandatory_checks);'); + + 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 + ,' '); + + -- + -- Check_mandatory - second version + -- add_sql(l_sql ,'FUNCTION check_mandatory ('); @@ -249,11 +331,7 @@ BEGIN 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;'); + ,' l_rec T_REC_' || l_tables.table_name || ';'); add_sql(l_sql ,'BEGIN'); @@ -279,53 +357,13 @@ BEGIN ,' ;'); 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; - + ,' RETURN CHECK_MANDATORY(p_rec => l_rec, p_mandatory_checks => p_mandatory_checks);'); add_sql(l_sql - ,' '); - - add_sql(l_sql, - ' MIP_HELPER_SPECIAL_CASES.table_'||l_tables.table_name||'(p_rec => l_rec, p_mandatory_checks=>l_mandatory_checks);'); - + ,' '); add_sql(l_sql - ,' '); + ,'END CHECK_MANDATORY;'); 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 -- @@ -345,7 +383,7 @@ BEGIN ,' '); add_sql(l_sql - ,' FOR l_checks IN (SELECT di_field_name'); + ,' FOR l_checks IN (SELECT field_name'); add_sql(l_sql ,' ,condition'); add_sql(l_sql @@ -359,7 +397,7 @@ BEGIN 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);'); + ,' MIP_MANDATORY.add_field(p_fields=>l_fields,p_field_name=>l_checks.field_name);'); add_sql(l_sql ,' END LOOP;'); diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck index 1801aa7..f8bc5e1 100644 --- a/Modules/mip_quotation.pck +++ b/Modules/mip_quotation.pck @@ -23,6 +23,22 @@ CREATE OR REPLACE PACKAGE mip_quotation IS ,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks ,p_enquiry_is_ready OUT BOOLEAN); + /** Validate an enquiry row of date for mandatory fields + Store the results for later retrieval (must be same transaction) + + %param p_rec enquiry data to be validated + */ + PROCEDURE validate(p_rec IN mip_enquiries_helper.t_rec_enquiries); + + /** Retrieve the results of a mandatory field validation for the given field + Must be performed in the same transaction as the validate + + %param p_field_name enquiry field who validation message is required + %return validation error message or NULL if validation was successful + */ + FUNCTION validation_result(p_enqu_id IN enquiries.id%TYPE + ,p_field_name IN VARCHAR2) RETURN VARCHAR2; + /** Generate quotes in response to a 'request for quote' against an enquiry %param p_enqu_id the id of the enquiry to be checked @@ -99,6 +115,7 @@ CREATE OR REPLACE PACKAGE mip_quotation IS ,p_event_date IN DATE DEFAULT SYSDATE); PROCEDURE lapse_quotes_job; + END mip_quotation; / CREATE OR REPLACE PACKAGE BODY mip_quotation IS @@ -124,7 +141,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS g_email_plain_body CLOB; g_email_html_body CLOB; - gc_newline CONSTANT CHAR(1) DEFAULT chr(13); + gc_newline CONSTANT CHAR(2) DEFAULT chr(10) || chr(13); TYPE t_rec_additional_costs IS RECORD( adit_code additional_items.code%TYPE @@ -189,7 +206,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS PROCEDURE accept_quote(p_qute_id IN quotes.id%TYPE ,p_prty_id IN parties.id%TYPE - ,p_owner_prty_id IN parties.id%TYPE + ,p_owner_prty_id IN parties.id%TYPE DEFAULT NULL ,p_description quote_events.description%TYPE DEFAULT NULL ,p_event_date IN DATE DEFAULT SYSDATE) IS BEGIN @@ -618,6 +635,70 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); ,''); END close_body; + PROCEDURE produce_enquiry_entry_details(p_enqu_id IN enquiries.id%TYPE) IS + l_enty_code enquiries.enty_code%TYPE; + + FUNCTION return_value(p_enqu_id IN enquiries.id%TYPE + ,p_field_name IN VARCHAR2) RETURN VARCHAR2 IS + l_sql VARCHAR2(240); + l_cursor_id INTEGER; + l_rows INTEGER; + l_return VARCHAR2(80); + BEGIN + + l_cursor_id := dbms_sql.open_cursor; + l_sql := 'select ' || p_field_name || + ' from enquiries where id = :id'; + + dbms_sql.parse(l_cursor_id + ,l_sql + ,dbms_sql.native); + + dbms_sql.bind_variable(l_cursor_id + ,':id' + ,p_enqu_id); + + dbms_sql.define_column(l_cursor_id + ,1 + ,l_return + ,80); + + l_rows := dbms_sql.execute_and_fetch(l_cursor_id); + + dbms_sql.column_value(l_cursor_id + ,1 + ,l_return); + + dbms_sql.close_cursor(l_cursor_id); + + RETURN l_return; + + END return_value; + + BEGIN + pl('produce_enquiry_entry_details'); + al(' '); + al(' '); + al(get_system_name || + ' recorded the following details against this enquiry:'); + + SELECT enty_code + INTO l_enty_code + FROM enquiries + WHERE id = p_enqu_id; + + FOR l_rec IN (SELECT dir.field_name + ,dir.description + FROM data_item_roles dir + WHERE dir.enty_code = l_enty_code + ORDER BY dir.display_sequence) LOOP + + al(l_rec.description || ': ' || + return_value(p_enqu_id => p_enqu_id + ,p_field_name => l_rec.field_name)); + END LOOP; + END produce_enquiry_entry_details; + PROCEDURE produce_reasoning_summary(p_enqu_id IN enquiries.id%TYPE) IS BEGIN pl('produce_reasoning_summary'); @@ -751,10 +832,15 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); close_body; - mip_email.send_email_clob(p_recipient => l_email_recipient - ,p_body => g_email_plain_body - ,p_body_html => g_email_html_body - ,p_subject => l_email_subject); + BEGIN + mip_email.send_email_clob(p_recipient => l_email_recipient + ,p_body => g_email_plain_body + ,p_body_html => g_email_html_body + ,p_subject => l_email_subject); + EXCEPTION + WHEN OTHERS THEN + pl('mip_email.send_email_clob returned ' || SQLERRM); + END; END email_quotes_available; @@ -762,7 +848,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); l_agent_comt_code enquiries.agent_comt_code%TYPE; l_agent_contact_value enquiries.agent_contact_value%TYPE; l_email_recipient system_configuration.VALUE%TYPE; - l_email_subject VARCHAR2(80); + l_email_subject VARCHAR2(240); l_agent_first_name parties.first_name%TYPE; l_agent_last_name parties.last_name%TYPE; l_agent_prty_id parties.id%TYPE; @@ -784,15 +870,26 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); AND enquiry_events.enqu_id = enquiries.id AND enquiry_events.enst_code = 'SUBMITTED'; - l_agent_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_enqu_id - ,p_rolecode => 'ENQ OWN'); + BEGIN + l_agent_prty_id := mip_enquiry.get_enquiry_role(p_enquiryid => p_enqu_id + ,p_rolecode => 'ENQ OWN'); + EXCEPTION + WHEN OTHERS THEN + pl('mip_enquiry.get_enquiry_role returned ' || SQLERRM); + RAISE; + END; - SELECT first_name - ,last_name - INTO l_agent_first_name - ,l_agent_last_name - FROM parties - WHERE id = l_agent_prty_id; + BEGIN + SELECT first_name + ,last_name + INTO l_agent_first_name + ,l_agent_last_name + FROM parties + WHERE id = l_agent_prty_id; + EXCEPTION + WHEN OTHERS THEN + pl('Error finding agent - prty_id=' || l_agent_prty_id); + END; IF l_agent_comt_code = 'EMAIL' THEN l_email_recipient := l_agent_contact_value; @@ -833,10 +930,16 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); close_body; - mip_email.send_email_clob(p_recipient => l_email_recipient - ,p_body => g_email_plain_body - ,p_body_html => g_email_html_body - ,p_subject => l_email_subject); + BEGIN + mip_email.send_email_clob(p_recipient => l_email_recipient + ,p_body => g_email_plain_body + ,p_body_html => g_email_html_body + ,p_subject => l_email_subject); + EXCEPTION + WHEN OTHERS THEN + pl('mip_email.send_email_clob returned ' || SQLERRM); + RAISE; + END; END email_rfq_submitted; PROCEDURE email_request_for_mq(p_enqu_id IN enquiries.id%TYPE) IS @@ -868,16 +971,27 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); al(' '); al('Current Service Level Agreements dictate that a manual quote be provided within 6 days'); + al('Data Entered:'); + + al('Enquiry type: ' || get_enty_description(p_enqu_id)); + + produce_enquiry_entry_details(p_enqu_id); + produce_reasoning_summary(p_enqu_id); close_body; - mip_email.send_email_clob(p_recipient => get_manual_quote_recipient - ,p_body => g_email_plain_body - ,p_body_html => g_email_html_body - ,p_subject => l_system_name || - ': Request for a Manual Quote for Enquiry Reference Number: ' || - p_enqu_id); + BEGIN + mip_email.send_email_clob(p_recipient => get_manual_quote_recipient + ,p_body => g_email_plain_body + ,p_body_html => g_email_html_body + ,p_subject => l_system_name || + ': Request for a Manual Quote for Enquiry Reference Number: ' || + p_enqu_id); + EXCEPTION + WHEN OTHERS THEN + pl('mip_email.send_email_clob returned ' || SQLERRM); + END; END email_request_for_mq; @@ -901,13 +1015,18 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); close_body; - mip_email.send_email_clob(p_recipient => get_support_recipient - ,p_body => g_email_plain_body - ,p_body_html => g_email_html_body - ,p_subject => get_system_name || ' : ' || - p_subject || - ' : Enquiry Reference Number: ' || - p_enqu_id); + BEGIN + mip_email.send_email_clob(p_recipient => get_support_recipient + ,p_body => g_email_plain_body + ,p_body_html => g_email_html_body + ,p_subject => get_system_name || ' : ' || + p_subject || + ' : Enquiry Reference Number: ' || + p_enqu_id); + EXCEPTION + WHEN OTHERS THEN + pl('mip_email.send_email_clob returned ' || SQLERRM); + END; END email_support; PROCEDURE request_manual_quote(p_enqu_id IN enquiries.id%TYPE @@ -930,7 +1049,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); ,p_mandatory_checks OUT mip_mandatory.t_mandatory_checks ,p_enquiry_is_ready OUT BOOLEAN) IS BEGIN - pl('ready_for_quote(1)'); + pl('ready_for_quote(1) - enqu_id=' || p_enqu_id); p_enquiry_is_ready := mip_enquiries_helper.check_mandatory(p_id => p_enqu_id ,p_mandatory_checks => p_mandatory_checks); @@ -940,7 +1059,7 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); l_mandatory_checks mip_mandatory.t_mandatory_checks; l_enquiry_is_ready BOOLEAN; BEGIN - pl('ready_for_quote(2)'); + pl('ready_for_quote(2) - enqu_id=' || p_enqu_id); ready_for_quote(p_enqu_id => p_enqu_id ,p_mandatory_checks => l_mandatory_checks @@ -948,6 +1067,61 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); RETURN l_enquiry_is_ready; END ready_for_quote; + PROCEDURE validate(p_rec IN mip_enquiries_helper.t_rec_enquiries) IS + l_mandatory_checks mip_mandatory.t_mandatory_checks; + l_idx NUMBER; + BEGIN + pl('validate enqu_id=' || p_rec.id || ', enty_code=' || + p_rec.enty_code); + DELETE FROM validation_results + WHERE enqu_id = p_rec.id; + IF NOT + mip_enquiries_helper.check_mandatory(p_rec => p_rec + ,p_mandatory_checks => l_mandatory_checks) THEN + l_idx := l_mandatory_checks.FIRST; + LOOP + EXIT WHEN l_idx IS NULL; + INSERT INTO validation_results + (enqu_id + ,field_name + ,error_message) + VALUES + (p_rec.id + ,l_mandatory_checks(l_idx).field_name + ,l_mandatory_checks(l_idx).error_message); + l_idx := l_mandatory_checks.NEXT(l_idx); + END LOOP; + END IF; + + EXCEPTION + WHEN OTHERS THEN + pl('validate:' || SQLERRM); + RAISE; + END validate; + + FUNCTION validation_result(p_enqu_id IN enquiries.id%TYPE + ,p_field_name IN VARCHAR2) RETURN VARCHAR2 IS + l_error_message gtt_mandatory_checks.error_message%TYPE; + BEGIN + pl('validation_result enqu_id=' || p_enqu_id || ', field_name=' || + p_field_name); + + SELECT error_message + INTO l_error_message + FROM validation_results + WHERE field_name = upper(p_field_name) + AND enqu_id = p_enqu_id; + pl('returning ' || l_error_message); + RETURN l_error_message; + EXCEPTION + WHEN no_data_found THEN + pl('Nothing found'); + RETURN NULL; + WHEN OTHERS THEN + pl('validation_result:' || SQLERRM); + RAISE; + END validation_result; + FUNCTION return_mandatory_messages(p_enqu_id IN enquiries.id%TYPE) RETURN VARCHAR2 IS l_mandatory_messages VARCHAR2(4000); @@ -1052,17 +1226,19 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); -- Site survey required for: -- Relocation -- Exchange where upgrade is greater than 1 'U' size - SELECT svcpt_code - INTO l_svcpt_code - FROM service_pressures - WHERE code = p_enqu.required_svcp_code; - IF l_svcpt_code = 'LP' THEN - IF p_enqu.enty_code = 'ALTERATION' THEN - p_manual_or_automatic_quote := gc_manual_quote; - add_quote_reason(p_enqu.id - ,'Site Survey is required for alteration (relocation or reposition) of an existing meter.'); - END IF; -- RELOCATE - IF p_enqu.enty_code IN ('EXCHANGE', 'STD EXCHANGE') THEN + + IF p_enqu.enty_code = 'ALTERATION' THEN + p_manual_or_automatic_quote := gc_manual_quote; + add_quote_reason(p_enqu.id + ,'Site Survey is required for alteration (relocation or reposition) of an existing meter.'); + END IF; -- RELOCATE + + IF p_enqu.enty_code IN ('EXCHANGE', 'STD EXCHANGE') THEN +-- SELECT svcpt_code +-- INTO l_svcpt_code +-- FROM service_pressures +-- WHERE code = p_enqu.required_svcp_code; +-- IF l_svcpt_code = 'LP' THEN l_existing_meter_size_code := p_enqu.existing_mesc_code; l_required_meter_size_code := p_enqu.required_mesc_code; IF l_required_meter_size_code IS NULL THEN @@ -1077,8 +1253,9 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); l_existing_meter_size_code || ' to ' || l_required_meter_size_code || '.'); END IF; - END IF; -- EXCHANGE - END IF; -- svcpt_code = 'LP' +-- END IF; -- svcpt_code = 'LP' + END IF; -- EXCHANGE + END survey_required; FUNCTION tripartite_agreement_satisfied(p_enqu_id IN enquiries.id%TYPE) @@ -2458,6 +2635,10 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); l_enqu t_enqu; BEGIN pl('produce_quotes'); + IF NOT ready_for_quote(p_enqu_id) THEN + pl('Not all mandatory fields for Enquiry ID=' || p_enqu_id || + ' have been completed'); + END IF; cout_assert.istrue(ready_for_quote(p_enqu_id) ,'Not all mandatory fields for Enquiry ID=' || p_enqu_id || ' have been completed'); @@ -2508,6 +2689,6 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); BEGIN -- Initialization - NULL; + pl('mip_quotation'); END mip_quotation; / diff --git a/Schema/ext_dataitem_role.pdc b/Schema/ext_dataitem_role.pdc index 193998f..d0232b9 100644 --- a/Schema/ext_dataitem_role.pdc +++ b/Schema/ext_dataitem_role.pdc @@ -15,7 +15,9 @@ create table ext_dataitem_roles alteration varchar2(240), capacity_change varchar2(240), addon varchar2(240), - other varchar2(240) + other varchar2(240), + notes VARCHAR2(240), + display_sequence NUMBER ) ORGANIZATION EXTERNAL ( type oracle_loader @@ -41,7 +43,9 @@ access parameters alteration , capacity_change , addon , - other + other , + notes , + display_sequence ) ) location ('DATAITEM_ROLES.csv') diff --git a/Schema/mip.con b/Schema/mip.con index ab552ef..ea26ddf 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 Tue Jan 22 17:48:45 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Mon Jan 28 18:35:24 2008 by Server Generator 10.1.2.6.18 PROMPT Creating Primary Key on 'SYSTEM_CONFIGURATION' ALTER TABLE SYSTEM_CONFIGURATION @@ -49,10 +49,10 @@ ALTER TABLE QUOTE_REASONING 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)) + (TABLE_NAME + ,FIELD_NAME + ,CONDITION + ,ENTY_CODE)) / PROMPT Creating Primary Key on 'CONTACT_MECHANISMS' @@ -219,13 +219,6 @@ 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 'DOCUMENT_ROLES' ALTER TABLE DOCUMENT_ROLES ADD (CONSTRAINT DORO_PK PRIMARY KEY @@ -463,28 +456,28 @@ ALTER TABLE REGI_ENQU_EXCLUSIONS PROMPT Creating Check Constraint on 'METER_SIZE_CODES' ALTER TABLE METER_SIZE_CODES - ADD (CONSTRAINT AVCON_1201024124_VALID_000 CHECK (VALID_FOR_EXISTING_METER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_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_1201024124_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_VALID_001 CHECK (VALID_FOR_NEW_METER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'COSTS' ALTER TABLE COSTS - ADD (CONSTRAINT AVCON_1201024124_COST__000 CHECK (COST_TYPE + ADD (CONSTRAINT AVCON_1201545323_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_1201024124_DOCU__000 CHECK (DOCU_TYPE IN ('DOCU', 'INDO', 'EXDO', 'FIDO'))) + ADD (CONSTRAINT AVCON_1201545323_DOCU__000 CHECK (DOCU_TYPE IN ('DOCU', 'INDO', 'EXDO', 'FIDO'))) / PROMPT Creating Check Constraint on 'QUOTES' ALTER TABLE QUOTES - ADD (CONSTRAINT AVCON_1201024124_QUTE__000 CHECK (QUTE_TYPE IN ('AQ', 'MQ', 'QUTE'))) + ADD (CONSTRAINT AVCON_1201545323_QUTE__000 CHECK (QUTE_TYPE IN ('AQ', 'MQ', 'QUTE'))) / PROMPT Creating Check Constraint on 'PARTY_RELATIONSHIPS' @@ -496,21 +489,21 @@ to_parl_rt_code = to_prtp_rt_code)) PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1201024124_TRIPA_000 CHECK (TRIPARTITE_MEMBER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_TRIPA_000 CHECK (TRIPARTITE_MEMBER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1201024124_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED'))) + ADD (CONSTRAINT AVCON_1201545323_STATU_000 CHECK (STATUS IN ('OPEN', 'EXPIRED', 'LOCKED'))) / PROMPT Creating Check Constraint on 'PARTIES' ALTER TABLE PARTIES - ADD (CONSTRAINT AVCON_1201024124_PRTY__000 CHECK (PRTY_TYPE + ADD (CONSTRAINT AVCON_1201545323_PRTY__000 CHECK (PRTY_TYPE IN ('PRTY', 'IO', 'EO', 'MKTP', 'PERS', 'MANU', 'NEMP', 'EMP', 'ORG' ))) / - + PROMPT Creating Check Constraint on 'DOCUMENT_ROLES' ALTER TABLE DOCUMENT_ROLES ADD (CONSTRAINT DORO_CK CHECK (( @@ -524,82 +517,82 @@ OR PROMPT Creating Check Constraint on 'DOCUMENT_ROLES' ALTER TABLE DOCUMENT_ROLES - ADD (CONSTRAINT AVCON_1201024124_DORO__000 CHECK (DORO_TYPE IN ('DRRO', 'DORO', 'ENDO', 'QUDO'))) + ADD (CONSTRAINT AVCON_1201545323_DORO__000 CHECK (DORO_TYPE IN ('DRRO', 'DORO', 'ENDO', 'QUDO'))) / PROMPT Creating Check Constraint on 'QUOTE_ITEMS' ALTER TABLE QUOTE_ITEMS - ADD (CONSTRAINT AVCON_1201024124_QUIT__000 CHECK (QUIT_TYPE IN ('LQI', 'AQI', 'BQI', 'MQI', 'QUIT', 'HQI'))) + ADD (CONSTRAINT AVCON_1201545323_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_1201024124_RT_TY_000 CHECK (RT_TYPE IN ('DORT', 'PART', 'RT', 'PCMRT', 'QURT', 'ENRT', 'PRT'))) + ADD (CONSTRAINT AVCON_1201545323_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_1201024124_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_DOWNS_000 CHECK (DOWNSTREAM_BOOSTER_OR_COMPRESS IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM'))) + ADD (CONSTRAINT AVCON_1201545323_INDIC_000 CHECK (INDICATIVE_TIME IN ('DY', 'AM', 'PM'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_HOUSI_000 CHECK (HOUSING_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_BASE__000 CHECK (BASE_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_CONVE_000 CHECK (CONVERTOR_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_AMR_R_000 CHECK (AMR_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_EMS_R_000 CHECK (EMS_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_TWIN__000 CHECK (TWIN_STREAM_REQUIRED IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_EXIST_000 CHECK (EXISTING_LOGGER IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_EXIST_000 CHECK (EXISTING_LOGGER IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating'))) + ADD (CONSTRAINT AVCON_1201545323_LOAD__000 CHECK (LOAD_CONTROL_TYPE IN ('Constant', 'On/Off', 'Modulating'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_EXIST_001 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C'))) + ADD (CONSTRAINT AVCON_1201545323_EXIST_001 CHECK (EXISTING_METER_OWNER IN ('S', 'T', 'C'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_EXIST_002 CHECK (EXISTING_CONVERTOR IN ('YES', 'NO'))) + ADD (CONSTRAINT AVCON_1201545323_EXIST_002 CHECK (EXISTING_CONVERTOR IN ('YES', 'NO'))) / PROMPT Creating Check Constraint on 'ENQUIRIES' ALTER TABLE ENQUIRIES - ADD (CONSTRAINT AVCON_1201024124_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D'))) + ADD (CONSTRAINT AVCON_1201545323_MARKE_000 CHECK (MARKET_SECTOR_CODE IN ('I', 'D'))) / @@ -642,15 +635,6 @@ ALTER TABLE DATA_ITEM_ROLES ADD (CONSTRAINT (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 'CONTACT_MECHANISMS' ALTER TABLE CONTACT_MECHANISMS ADD (CONSTRAINT COME_COMT_FK FOREIGN KEY diff --git a/Schema/mip.ind b/Schema/mip.ind index b17fe2c..f3c501a 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 Tue Jan 22 17:48:44 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Mon Jan 28 18:35:24 2008 by Server Generator 10.1.2.6.18 PROMPT Creating Index 'REGU_RETY_FK_I' @@ -25,12 +25,6 @@ CREATE INDEX QURE_ENQU_FK_I ON QUOTE_REASONING (ENQU_ID) / -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) diff --git a/Schema/mip.sql b/Schema/mip.sql index bfb0510..579476e 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 Tue Jan 22 17:48:45 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Mon Jan 28 18:35:25 2008 by Server Generator 10.1.2.6.18 SPOOL mip.lst diff --git a/Schema/mip.sqs b/Schema/mip.sqs index 593079c..aceeaea 100644 --- a/Schema/mip.sqs +++ b/Schema/mip.sqs @@ -1,6 +1,6 @@ -- C:\Andy\svn\WEBMIP\Schema\mip.sqs -- --- Generated for Oracle 10g on Tue Jan 22 17:48:45 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Mon Jan 28 18:35:24 2008 by Server Generator 10.1.2.6.18 PROMPT Creating Sequence 'FLTR_SEQ' CREATE SEQUENCE FLTR_SEQ diff --git a/Schema/mip.tab b/Schema/mip.tab index be2cad6..672ec79 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 Tue Jan 22 17:48:44 2008 by Server Generator 10.1.2.6.18 +-- Generated for Oracle 10g on Mon Jan 28 18:35:24 2008 by Server Generator 10.1.2.6.18 @@ -52,12 +52,14 @@ CREATE TABLE QUOTE_REASONING 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 + (ENTY_CODE VARCHAR2(80) NOT NULL + ,TABLE_NAME VARCHAR2(240) NOT NULL + ,FIELD_NAME VARCHAR2(240) NOT NULL ,CONDITION VARCHAR2(30) NOT NULL - ,ERROR_MESSAGE VARCHAR2(250) ,DESCRIPTION VARCHAR2(80) + ,DISPLAY_SEQUENCE VARCHAR2(240) + ,ERROR_MESSAGE VARCHAR2(250) + ,NOTES VARCHAR2(240) ) / @@ -314,14 +316,6 @@ 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 'DOCUMENT_ROLES' CREATE TABLE DOCUMENT_ROLES (DOCU_ID NUMBER(*,0) NOT NULL