From 759f63c635d09fd2233879b5aeb2e0139e84ea07 Mon Sep 17 00:00:00 2001 From: hardya Date: Mon, 7 Apr 2008 15:25:13 +0000 Subject: [PATCH] MIP_ENQUIRY.pck - address back-end of #439. mip_quotation.pck - address back-end of #442. mip_security.pck - track CGI environment variables as part of #454. mip_quotation.pck - store files with the correct flow_id; git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@4733 248e525c-4dfb-0310-94bc-949c084e9493 --- Modules/MIP_ENQUIRY.pck | 220 ++++++++++++++---------- Modules/mip_quotation.pck | 226 +++++++++++++++++++++--- Modules/mip_quotation_document.pck | 2 +- Modules/mip_security.pck | 267 +++++++++++++++++++---------- 4 files changed, 504 insertions(+), 211 deletions(-) diff --git a/Modules/MIP_ENQUIRY.pck b/Modules/MIP_ENQUIRY.pck index 154e1cd..47b320e 100644 --- a/Modules/MIP_ENQUIRY.pck +++ b/Modules/MIP_ENQUIRY.pck @@ -15,7 +15,6 @@ CREATE OR REPLACE PACKAGE mip_enquiry IS ,required_mesc_code meters.mesc_code%TYPE); -- Public function and procedure declarations - FUNCTION delete_enquiry(p_enquiryid IN NUMBER) RETURN BOOLEAN; FUNCTION can_enquiry_be_deleted(p_enquiryid IN NUMBER) RETURN BOOLEAN; FUNCTION get_enquiry_status(p_enquiryid IN NUMBER) RETURN VARCHAR2; @@ -73,6 +72,26 @@ CREATE OR REPLACE PACKAGE mip_enquiry IS ,p_existing_mesc_code meters.mesc_code%TYPE ,p_required_mesc_code meters.mesc_code%TYPE ,p_existing_metr_code meters.code%TYPE) RETURN BOOLEAN; + + /* + FUNCTION delete_enquiry + - This function returns the deletion status of the enquiry provided + %param p_enqu_id id of the enquiry to be deleted + %param p_message reason for not deleting enquiry + %return boolean + {*} TRUE - all quotes have been deleted + {*} FALSE or UNKNOWN - quotes have not been deleted + */ + FUNCTION delete_enquiry(p_enqu_id IN enquiries.id%TYPE + ,p_message OUT VARCHAR2) RETURN BOOLEAN; + + /* + FUNCTION delete_enquiry + - This function returns the deletion status of the enquiry provided + %param p_enqu_id id of the enquiry to be deleted + %return reason for not deleting enquiry or NULL + */ + FUNCTION delete_enquiry(p_enqu_id IN enquiries.id%TYPE) RETURN VARCHAR2; END mip_enquiry; / CREATE OR REPLACE PACKAGE BODY mip_enquiry IS @@ -87,66 +106,8 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS ,p_in => p_in); /* $END*/ END pl; + /* - FUNCTION delete_enquiry - - This function returns the status of the enquiry provided - %param p_enquiryid - the enquiry we want to delete. - %return boolean - whether the enquiry was deleted or not - */ - FUNCTION delete_enquiry(p_enquiryid IN NUMBER) RETURN BOOLEAN AS - l_uri documents.uri%TYPE; - l_doc_id documents.id%TYPE; - l_count NUMBER := 0; - CURSOR c_get_doc_id(cp_enq_id NUMBER) IS - SELECT id - FROM document_roles - WHERE enqu_id = cp_enq_id; - CURSOR c_get_uri(cp_id NUMBER) IS - SELECT uri - FROM documents - WHERE id = cp_id; - CURSOR c_get_document_files(cp_enq_id NUMBER) IS - SELECT documents.uri - FROM documents - ,document_roles - WHERE document_roles.enqu_id = cp_enq_id - AND documents.id = document_roles.docu_id; - BEGIN - --select count(*) into l_count from quotes where quotes.enqu_id=p_enquiryid; - --if l_count > 0 then - -- return false; - --end if; - IF NOT c_get_doc_id%ISOPEN THEN - OPEN c_get_doc_id(p_enquiryid); - END IF; - FETCH c_get_doc_id - INTO l_doc_id; - CLOSE c_get_doc_id; - - IF NOT c_get_uri%ISOPEN THEN - OPEN c_get_uri(l_doc_id); - END IF; - FETCH c_get_uri - INTO l_uri; - CLOSE c_get_uri; - - DELETE enquiry_roles - WHERE enquiry_roles.enqu_id = p_enquiryid; - DELETE enquiry_events - WHERE enquiry_events.enqu_id = p_enquiryid; - FOR doc_rec IN c_get_document_files(p_enquiryid) LOOP - DELETE wwv_flow_files - WHERE wwv_flow_files.NAME = doc_rec.uri; - END LOOP; - DELETE document_roles - WHERE document_roles.enqu_id = p_enquiryid; - DELETE documents - WHERE documents.id = l_doc_id; - DELETE enquiries - WHERE enquiries.id = p_enquiryid; - RETURN TRUE; - END delete_enquiry; - /* FUNCTION can_enquiry_be_deleted - This function returns the status of the enquiry provided - and associated quotes to see if it can be deleted @@ -156,14 +117,13 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS FUNCTION can_enquiry_be_deleted(p_enquiryid IN NUMBER) RETURN BOOLEAN AS -- cursor to get the current enquiry CURSOR c_check_all_quotes(cp_enqu_id NUMBER) IS - select count(qute_id) - from v_current_quote_status - where QUTE_ID in - (SELECT ID - FROM quotes - WHERE enqu_id = cp_enqu_id) - and QUST_CODE in ('SELECTED','ACCEPTED'); - l_quotes_cannot_del number := 0; + SELECT COUNT(qute_id) + FROM v_current_quote_status + WHERE qute_id IN (SELECT id + FROM quotes + WHERE enqu_id = cp_enqu_id) + AND qust_code IN ('SELECTED', 'ACCEPTED'); + l_quotes_cannot_del NUMBER := 0; BEGIN IF NOT c_check_all_quotes%ISOPEN THEN OPEN c_check_all_quotes(p_enquiryid); @@ -172,12 +132,67 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS FETCH c_check_all_quotes INTO l_quotes_cannot_del; CLOSE c_check_all_quotes; - if l_quotes_cannot_del > 0 then - return false; - else - return true; - end if; + IF l_quotes_cannot_del > 0 THEN + RETURN FALSE; + ELSE + RETURN TRUE; + END IF; END can_enquiry_be_deleted; + + /* + FUNCTION delete_enquiry + - This function returns the status of the enquiry provided + %param p_enquiryid - the enquiry we want to delete. + %return boolean - whether the enquiry was deleted or not + */ + FUNCTION delete_enquiry(p_enqu_id IN enquiries.id%TYPE + ,p_message OUT VARCHAR2) RETURN BOOLEAN IS + l_enquiry_deleted BOOLEAN := TRUE; + BEGIN + pl('delete_enquiry:entry:' || p_enqu_id + ,$$PLSQL_LINE); + -- + -- attempt to delete all associated quotes + -- + IF NOT + mip_quotation.delete_quotes_for_enquiry(p_enqu_id => p_enqu_id + ,p_message => p_message) THEN + -- unable to delete quotations + l_enquiry_deleted := FALSE; + ELSE + -- + -- delete all associations with this enquiry + -- + + DELETE FROM quote_reasoning + WHERE enqu_id = p_enqu_id; + + DELETE FROM enquiry_events + WHERE enqu_id = p_enqu_id; + + DELETE FROM enquiry_roles + WHERE enqu_id = p_enqu_id; + + DELETE FROM enquiries + WHERE id = p_enqu_id; + + END IF; + + RETURN(l_enquiry_deleted = TRUE); + END delete_enquiry; + + FUNCTION delete_enquiry(p_enqu_id IN enquiries.id%TYPE) RETURN VARCHAR2 IS + l_message VARCHAR2(240); + l_dummy BOOLEAN; + BEGIN + pl('delete_enquiry(msg):entry:' || p_enqu_id); + + l_dummy := delete_enquiry(p_enqu_id => p_enqu_id + ,p_message => l_message); + + pl('delete_enquiry(msg):exit:' || l_message); + RETURN(l_message); + END delete_enquiry; /* FUNCTION get_enquiry_status - This function returns the status of the enquiry provided @@ -242,7 +257,9 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS ,p_partyid IN NUMBER ,p_rolecode IN VARCHAR2) RETURN BOOLEAN AS BEGIN - pl('set_enquiry_role:entry:'||p_enquiryid||':'||p_partyid||':'||p_rolecode,$$plsql_line); + pl('set_enquiry_role:entry:' || p_enquiryid || ':' || p_partyid || ':' || + p_rolecode + ,$$PLSQL_LINE); INSERT INTO enquiry_roles (enqu_id ,prty_id @@ -254,12 +271,14 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS ,SYSDATE ,p_rolecode); - pl('set_enquiry_role:exit',$$plsql_line); + pl('set_enquiry_role:exit' + ,$$PLSQL_LINE); RETURN TRUE; -- - EXCEPTION - WHEN OTHERS THEN - pl('set_enquiry_role:EXCEPTION:'||SQLERRM,$$plsql_line); + EXCEPTION + WHEN OTHERS THEN + pl('set_enquiry_role:EXCEPTION:' || SQLERRM + ,$$PLSQL_LINE); RAISE; END set_enquiry_role; -- @@ -278,8 +297,10 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS ,p_rolecode IN VARCHAR2 ,p_description IN VARCHAR2) RETURN BOOLEAN AS BEGIN - pl('set_enquiry_role:entry:'||p_enquiryid||':'||p_partyid||':'||p_rolecode||':'||p_description,$$plsql_line); - + pl('set_enquiry_role:entry:' || p_enquiryid || ':' || p_partyid || ':' || + p_rolecode || ':' || p_description + ,$$PLSQL_LINE); + INSERT INTO enquiry_roles (enqu_id ,prty_id @@ -293,13 +314,15 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS ,p_rolecode ,p_description); - pl('set_enquiry_role:exit',$$plsql_line); - + pl('set_enquiry_role:exit' + ,$$PLSQL_LINE); + RETURN TRUE; -- - EXCEPTION - WHEN OTHERS THEN - pl('set_enquiry_role:EXCEPTION:'||SQLERRM,$$plsql_line); + EXCEPTION + WHEN OTHERS THEN + pl('set_enquiry_role:EXCEPTION:' || SQLERRM + ,$$PLSQL_LINE); RAISE; END set_enquiry_role; -- @@ -584,8 +607,10 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS l_dummy NUMBER; BEGIN - pl('show_qmax:entry:'||p_enty_code||':'||p_existing_metr_code||':'||p_existing_mesc_code||':'||p_required_mesc_code,$$PLSQL_LINE); - + pl('show_qmax:entry:' || p_enty_code || ':' || p_existing_metr_code || ':' || + p_existing_mesc_code || ':' || p_required_mesc_code + ,$$PLSQL_LINE); + BEGIN SELECT NULL INTO l_dummy @@ -599,7 +624,8 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS l_return := TRUE; EXCEPTION WHEN no_data_found THEN - pl('show_qmax:QMAX IS HIDDEN',$$PLSQL_LINE); + pl('show_qmax:QMAX IS HIDDEN' + ,$$PLSQL_LINE); l_return := FALSE; END; @@ -617,14 +643,16 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS l_required_mesc_enquiry := TRUE; EXCEPTION WHEN no_data_found THEN - pl('show_qmax:NOT A REQUIRED MESC ENQUIRY',$$PLSQL_LINE); + pl('show_qmax:NOT A REQUIRED MESC ENQUIRY' + ,$$PLSQL_LINE); l_required_mesc_enquiry := FALSE; END; IF l_required_mesc_enquiry AND (nvl(p_required_mesc_code ,'OTHER') <> 'OTHER') THEN - pl('show_qmax:REQUIRED MESC NOT OTHER',$$PLSQL_LINE); + pl('show_qmax:REQUIRED MESC NOT OTHER' + ,$$PLSQL_LINE); l_return := FALSE; ELSE BEGIN @@ -639,7 +667,8 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS l_existing_mesc_enquiry := TRUE; EXCEPTION WHEN no_data_found THEN - pl('show_qmax:NOT EXISTING MESC ENQUIRY',$$PLSQL_LINE); + pl('show_qmax:NOT EXISTING MESC ENQUIRY' + ,$$PLSQL_LINE); l_existing_mesc_enquiry := FALSE; END; @@ -650,13 +679,16 @@ CREATE OR REPLACE PACKAGE BODY mip_enquiry IS ,'OTHER') = 'OTHER' AND nvl(p_existing_mesc_code ,'OTHER') <> 'OTHER')) THEN - pl('show_qmax:EXISTING METR OR MESC NOT OTHER',$$PLSQL_LINE); + pl('show_qmax:EXISTING METR OR MESC NOT OTHER' + ,$$PLSQL_LINE); l_return := FALSE; END IF; END IF; END IF; - -pl('show_qmax:exit:'||CASE l_return WHEN TRUE THEN 'TRUE' ELSE 'FALSE' END,$$PLSQL_LINE); + + pl('show_qmax:exit:' || CASE l_return WHEN TRUE THEN 'TRUE' ELSE + 'FALSE' END + ,$$PLSQL_LINE); RETURN l_return; END show_qmax; diff --git a/Modules/mip_quotation.pck b/Modules/mip_quotation.pck index a86d859..16b6a5f 100644 --- a/Modules/mip_quotation.pck +++ b/Modules/mip_quotation.pck @@ -4,6 +4,8 @@ CREATE OR REPLACE PACKAGE mip_quotation IS -- Created : 15/11/2007 11:27:58 -- Purpose : Handle life-cycle of quotations + TYPE t_tab_messages IS TABLE OF VARCHAR2(240); + /** Determines whether the given enquiry is ready to quote for i.e. have all the mandatory fields been completed @@ -116,6 +118,32 @@ CREATE OR REPLACE PACKAGE mip_quotation IS PROCEDURE lapse_quotes_job; + /** Delete a quote + %param p_qute_id id of the quote to be deleted + %param p_message reason for not deleting quote + %return boolean + {*} TRUE - quote has been deleted + {*} FALSE or UNKNOWN - quote has not been deleted + */ + FUNCTION delete_quote(p_qute_id IN quotes.id%TYPE + ,p_message OUT VARCHAR2) RETURN BOOLEAN; + + /** Delete a quote + %param p_qute_id id of the quote to be deleted + %return reason for not deleting quote + */ + FUNCTION delete_quote(p_qute_id IN quotes.id%TYPE) RETURN VARCHAR2; + + /** Delete all quotes associated with an enquiry + %param p_enqu_id id of the quote to be deleted + %param p_message reason for not deleting quote + %return boolean + {*} TRUE - all quotes have been deleted + {*} FALSE or UNKNOWN - quotes have not been deleted + */ + FUNCTION delete_quotes_for_enquiry(p_enqu_id IN enquiries.id%TYPE + ,p_message OUT VARCHAR2) RETURN BOOLEAN; + /** Return a message if the Tripartite agreement is broached %param p_rec record containing enquiry details to be checked %return message is the agreement was broached @@ -194,6 +222,33 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS /* $END*/ END pl; + PROCEDURE add_quote_reason(p_enqu_id IN enquiries.id%TYPE + ,p_reason IN VARCHAR2 --quote_reasoning.reason%TYPE + ,p_internal_or_external IN quote_reasoning.internal_or_external%TYPE) IS + BEGIN + pl('add_quote_reason:' || p_enqu_id || ':' || p_reason + ,$$PLSQL_LINE); + BEGIN + INSERT INTO quote_reasoning + (enqu_id + ,reason + ,internal_or_external + ,id) + VALUES + (p_enqu_id + ,substr(p_reason + ,1 + ,239) + ,p_internal_or_external + ,qure_seq.NEXTVAL); + EXCEPTION + WHEN OTHERS THEN + pl('add_quote_reason:' || SQLERRM + ,$$PLSQL_LINE); + RAISE; + END; + END add_quote_reason; + PROCEDURE add_quote_event(p_qute_id IN quotes.id%TYPE ,p_qust_code quote_statuses.code%TYPE ,p_description quote_events.description%TYPE DEFAULT NULL @@ -380,6 +435,150 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation IS END select_quote; + FUNCTION delete_quote(p_qute_id IN quotes.id%TYPE + ,p_message OUT VARCHAR2) RETURN BOOLEAN IS + l_qust_code quote_statuses.code%TYPE; + l_quote_deleted BOOLEAN; + l_enqu_id enquiries.id%TYPE; + TYPE t_rowid IS TABLE OF ROWID; + l_rowid t_rowid := t_rowid(); + BEGIN + pl('delete_quote:entry:' || p_qute_id + ,$$PLSQL_LINE); + + BEGIN + SELECT enqu_id + INTO l_enqu_id + FROM quotes + WHERE id = p_qute_id; + EXCEPTION + WHEN no_data_found THEN + NULL; + END; + + cout_assert.isnotnull(p_value => l_enqu_id + ,p_message => 'Unable to find quote ' || p_qute_id); + + SELECT qust_code + INTO l_qust_code + FROM v_current_quote_status + WHERE qute_id = p_qute_id; + + IF l_qust_code IN ('SELECTED', 'ACCEPTED') THEN + l_quote_deleted := FALSE; + p_message := 'Unable to delete quote ' || p_qute_id || + ' as it has a status of ' || initcap(l_qust_code); + ELSE + -- + -- delete all associations with this quote + -- + + DELETE FROM quote_events + WHERE qute_id = p_qute_id; + + DELETE FROM apex_application_files aaf + WHERE aaf.NAME IN (SELECT uri + FROM documents docu + ,document_roles doro + WHERE doro.qute_id = p_qute_id + AND doro.docu_id = docu.id + AND docu.docu_type = 'INDO'); + + DELETE FROM document_events doev + WHERE doev.docu_id IN + (SELECT docu_id + FROM document_roles doro + WHERE doro.qute_id = p_qute_id); + + -- document roles knows which files should be deleted + -- through a FK + -- 1. Gather the rowids of the documents first, + -- 2. Remove the document role + -- 3. Remove the associated document + SELECT ROWID BULK COLLECT + INTO l_rowid + FROM documents + WHERE id IN (SELECT docu_id + FROM document_roles + WHERE qute_id = p_qute_id); + + DELETE FROM document_roles doro + WHERE doro.qute_id = p_qute_id; + + FORALL l_idx IN INDICES OF l_rowid + DELETE FROM documents + WHERE ROWID = l_rowid(l_idx); + + DELETE FROM quote_items + WHERE qute_id = p_qute_id; + + DELETE FROM quote_roles + WHERE qute_id = p_qute_id; + + -- + -- record that the quote was deleted + -- + add_quote_reason(p_enqu_id => l_enqu_id + ,p_reason => 'QUOTE ' || p_qute_id || + ' DELETED BY REQUEST' + ,p_internal_or_external => gc_internal_reason); + + -- + -- delete the quote itself + -- + DELETE FROM quotes + WHERE id = p_qute_id; + l_quote_deleted := TRUE; + END IF; + + pl('delete_quote:exit:' || p_qute_id || ':' || CASE l_quote_deleted WHEN TRUE THEN + 'TRUE' ELSE 'FALSE' END + ,$$PLSQL_LINE); + + RETURN(l_quote_deleted = TRUE); + EXCEPTION + WHEN OTHERS THEN + cout_err.report_and_stop; + END delete_quote; + + FUNCTION delete_quote(p_qute_id IN quotes.id%TYPE) RETURN VARCHAR2 IS + l_dummy BOOLEAN; + l_message VARCHAR2(240); + BEGIN + pl('delete_quote(msg):entry:' || p_qute_id); + + l_dummy := delete_quote(p_qute_id => p_qute_id + ,p_message => l_message); + + pl('delete_quote(msg):exit:' || l_message); + RETURN(l_message); + + END delete_quote; + + FUNCTION delete_quotes_for_enquiry(p_enqu_id IN enquiries.id%TYPE + ,p_message OUT VARCHAR2) RETURN BOOLEAN IS + l_quotes_deleted BOOLEAN := TRUE; + BEGIN + pl('delete_quotes_for_enquiry:entry:' || p_enqu_id + ,$$PLSQL_LINE); + + FOR l_quote IN (SELECT id + FROM quotes + WHERE enqu_id = p_enqu_id) LOOP + IF NOT delete_quote(p_qute_id => l_quote.id + ,p_message => p_message) THEN + l_quotes_deleted := FALSE; + EXIT; + END IF; + END LOOP; + + pl('delete_quotes_for_enquiry:' || CASE l_quotes_deleted WHEN TRUE THEN + 'TRUE' ELSE 'FALSE' END + ,$$PLSQL_LINE); + + RETURN(l_quotes_deleted = TRUE); + END delete_quotes_for_enquiry; + PROCEDURE lapse_quotes_job IS l_current_date DATE := trunc(SYSDATE); BEGIN @@ -1335,33 +1534,6 @@ RECEIVED AT THIS ADDRESS CANNOT BE RESPONDED TO.'); END return_mandatory_messages; - PROCEDURE add_quote_reason(p_enqu_id IN enquiries.id%TYPE - ,p_reason IN VARCHAR2 --quote_reasoning.reason%TYPE - ,p_internal_or_external IN quote_reasoning.internal_or_external%TYPE) IS - BEGIN - pl('add_quote_reason:' || p_enqu_id || ':' || p_reason - ,$$PLSQL_LINE); - BEGIN - INSERT INTO quote_reasoning - (enqu_id - ,reason - ,internal_or_external - ,id) - VALUES - (p_enqu_id - ,substr(p_reason - ,1 - ,239) - ,p_internal_or_external - ,qure_seq.NEXTVAL); - EXCEPTION - WHEN OTHERS THEN - pl('add_quote_reason:' || SQLERRM - ,$$PLSQL_LINE); - RAISE; - END; - END add_quote_reason; - FUNCTION get_u_meter_size(p_qmax IN NUMBER) RETURN meter_size_codes.code%TYPE IS l_meter_size_code meter_size_codes.code%TYPE; diff --git a/Modules/mip_quotation_document.pck b/Modules/mip_quotation_document.pck index 7a34ac2..2bfb2cc 100644 --- a/Modules/mip_quotation_document.pck +++ b/Modules/mip_quotation_document.pck @@ -1447,7 +1447,7 @@ CREATE OR REPLACE PACKAGE BODY mip_quotation_document IS plpdf.SendDoc(l_blob); --punt the created pdf into the APEX files table insert into wwv_flow_files( name, title, mime_type, flow_id, doc_size ,description, blob_content ) - values ( sys_guid()||'/quote_'||p_quote_data.quote_ref||'.pdf', 'Quotation - '||p_quote_data.quote_ref, 'application/pdf', 190, DBMS_LOB.GETLENGTH(l_blob),'this is an auto generated quotation from mip_quotation_document.generate_detailed_quote for quotation '||p_quote_data.quote_ref, l_blob) + values ( sys_guid()||'/quote_'||p_quote_data.quote_ref||'.pdf', 'Quotation - '||p_quote_data.quote_ref, 'application/pdf', apex_application.g_flow_id, DBMS_LOB.GETLENGTH(l_blob),'this is an auto generated quotation from mip_quotation_document.generate_detailed_quote for quotation '||p_quote_data.quote_ref, l_blob) returning name into l_pdf_name; --set up the file associations within our documents tables l_success:= mip_files.set_file_association(l_pdf_name, diff --git a/Modules/mip_security.pck b/Modules/mip_security.pck index d09332c..268caad 100644 --- a/Modules/mip_security.pck +++ b/Modules/mip_security.pck @@ -16,11 +16,11 @@ CREATE OR REPLACE PACKAGE mip_security AS ,p_session_id IN VARCHAR2 ,p_flow_page IN VARCHAR2); -/** Generate a hash from the given username and password - -The system does not record users passwords 'in the plain', instead we -recordThe resultant hash is recorded as the username 'password hash' -*/ + /** Generate a hash from the given username and password + + The system does not record users passwords 'in the plain', instead we + recordThe resultant hash is recorded as the username 'password hash' + */ FUNCTION get_hash(p_username IN VARCHAR2 ,p_password IN VARCHAR2) RETURN VARCHAR2; @@ -54,15 +54,16 @@ recordThe resultant hash is recorded as the username 'password hash' /* creates a new password for another user */ - PROCEDURE other_user_password(p_prty_id IN number, - p_username IN VARCHAR2, - p_password IN VARCHAR2); + PROCEDURE other_user_password(p_prty_id IN NUMBER + ,p_username IN VARCHAR2 + ,p_password IN VARCHAR2); -- - + FUNCTION get_user_status(p_username IN VARCHAR2) RETURN VARCHAR2; /** Updates the user status - */ - PROCEDURE set_user_status(p_username IN VARCHAR2, p_status IN VARCHAR2); + */ + PROCEDURE set_user_status(p_username IN VARCHAR2 + ,p_status IN VARCHAR2); -- /** Authorize access to the given page @@ -97,12 +98,22 @@ recordThe resultant hash is recorded as the username 'password hash' ,p_component_name IN apex_authorization.component_name%TYPE ,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A') RETURN BOOLEAN; - END mip_security; / CREATE OR REPLACE PACKAGE BODY mip_security AS + PROCEDURE pl(p_in VARCHAR2 + ,p_line IN NUMBER DEFAULT NULL) IS + BEGIN + NULL; + /* $IF mip_debug_constants.debugging OR mip_debug_constants.security + $THEN*/ + mip_debug.pl(p_unit => $$PLSQL_UNIT + ,p_line => p_line + ,p_in => p_in); + /* $END*/ + END pl; /* returns the current status of the user */ @@ -124,44 +135,52 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS -- /** Updates the user status - */ - PROCEDURE set_user_status(p_username IN VARCHAR2, p_status IN VARCHAR2) IS + */ + PROCEDURE set_user_status(p_username IN VARCHAR2 + ,p_status IN VARCHAR2) IS BEGIN UPDATE parties prty SET prty.status = upper(p_status) WHERE upper(prty.username) = upper(p_username); - - END; - PROCEDURE update_status_on_login(p_uname IN VARCHAR2, p_password IN VARCHAR2) IS - l_password_days NUMBER; + END; + + PROCEDURE update_status_on_login(p_uname IN VARCHAR2 + ,p_password IN VARCHAR2) IS + l_password_days NUMBER; l_password_created_on DATE; BEGIN -- check that the account is still valid (password etc.). - l_password_created_on := mip_parties.get_user_password_created(p_uname, p_password); + l_password_created_on := mip_parties.get_user_password_created(p_uname + ,p_password); -- - l_password_days := to_date(SYSDATE,'dd/mm/rrrr') - to_date(l_password_created_on,'dd/mm/rrrr'); + l_password_days := to_date(SYSDATE + ,'dd/mm/rrrr') - + to_date(l_password_created_on + ,'dd/mm/rrrr'); -- check the user's password/account has not expired - IF NOT l_password_days - < to_number(cout_system_configuration.get_configuration_item(p_parameter => 'USER_ACCOUNT_LOCK')) THEN - -- user account has expired, set the user account to locked and continue on our journey - set_user_status(p_username => p_uname - ,p_status => 'LOCKED'); - - ELSIF NOT l_password_days - < to_number(cout_system_configuration.get_configuration_item(p_parameter => 'PASSWORD_EXPIRY_LIMIT')) THEN - -- user password has expired, set the user account to expired and continue on our journey - set_user_status(p_username => p_uname - ,p_status => 'EXPIRED'); - - END IF; - -- - EXCEPTION - WHEN no_data_found THEN - NULL; -- no password/user exists to update the status of. - END update_status_on_login; - -- - + IF NOT + l_password_days < + to_number(cout_system_configuration.get_configuration_item(p_parameter => 'USER_ACCOUNT_LOCK')) THEN + -- user account has expired, set the user account to locked and continue on our journey + set_user_status(p_username => p_uname + ,p_status => 'LOCKED'); + + ELSIF NOT + l_password_days < + to_number(cout_system_configuration.get_configuration_item(p_parameter => 'PASSWORD_EXPIRY_LIMIT')) THEN + -- user password has expired, set the user account to expired and continue on our journey + set_user_status(p_username => p_uname + ,p_status => 'EXPIRED'); + + END IF; + -- + EXCEPTION + WHEN no_data_found THEN + NULL; -- no password/user exists to update the status of. + END update_status_on_login; + -- + /** Logs the user into the system and registers with APEX. @@ -173,31 +192,103 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS ,p_password IN VARCHAR2 ,p_session_id IN VARCHAR2 ,p_flow_page IN VARCHAR2) IS - + BEGIN + pl('login:entry:' || p_uname || ':' || p_session_id || ':' || + p_flow_page + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('PLSQL_GATEWAY') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('GATEWAY_IVERSION') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('SERVER_SOFTWARE') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('GATEWAY_INTERFACE') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('SERVER_PORT') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('SERVER_NAME') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('REQUEST_METHOD') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('PATH_INFO') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('SCRIPT_NAME') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('REMOTE_ADDR') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('SERVER_PROTOCOL') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('REQUEST_PROTOCOL') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('REMOTE_USER') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_USER_AGENT') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_HOST') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_ACCEPT') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_ACCEPT_ENCODING') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_ACCEPT_LANGUAGE') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_ACCEPT_CHARSET') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_ORACLE_ECID') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_AUTHORIZATION') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('WEB_AUTHENT_PREFIX') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('DAD_NAME') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('DOC_ACCESS_PATH') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('DOCUMENT_TABLE') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('PATH_ALIAS') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('REQUEST_CHARSET') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('REQUEST_IANA_CHARSET') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('SCRIPT_PREFIX') + ,$$PLSQL_LINE); + pl(owa_util.get_cgi_env('HTTP_COOKIE') + ,$$PLSQL_LINE); + -- check that the account is still valid (password etc.). - update_status_on_login(p_uname, p_password); - + update_status_on_login(p_uname + ,p_password); + -- IF get_user_status(p_uname) = 'OPEN' THEN + pl('login:exit:OPEN' + ,$$PLSQL_LINE); -- log in and flow to the requested page 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 + pl('login:exit:EXPIRED' + ,$$PLSQL_LINE); -- 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 + pl('login:exit:LOGOUT' + ,$$PLSQL_LINE); -- user password has been locked. Log them off and tell them wwv_flow_custom_auth_std.logout(p_this_flow => v('APP_ID') ,p_next_flow_page_sess => v('APP_ID') || ':501'); END IF; + pl('login:exit:UNEXPECTED'); END login; /** Produce a 'password hash' from the given username and password @@ -234,8 +325,6 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS AND pwd.password_hash = get_hash(p_username ,p_password); - - RETURN TRUE; EXCEPTION WHEN no_data_found THEN @@ -337,44 +426,44 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS END IF; -- added block around this to catch no data. BEGIN - SELECT access_allowed - INTO l_access_allowed - FROM (SELECT auth.component_name - ,auth.rt_code - ,parl.rt_code - ,CASE - WHEN auth.rt_code IS NULL THEN - 'YES' - WHEN auth.rt_code = parl.rt_code THEN - 'YES' - ELSE - 'NO' - END access_allowed - FROM (SELECT prty.username - ,rt_code - FROM parties prty - ,party_roles parl - WHERE parl.prty_id = prty.id - AND upper(prty.username) = upper(p_app_user)) parl - ,apex_authorization auth - WHERE (auth.privilege = p_privilege OR - auth.privilege IS NULL AND p_privilege IS NULL) - AND auth.rt_code = parl.rt_code(+) - AND auth.component_name = p_component_name - AND auth.component_type = p_component_type - ORDER BY parl.rt_code) - WHERE rownum < 2; - - IF nvl(l_access_allowed - ,'NO') = 'YES' THEN - RETURN TRUE; - ELSE - RETURN FALSE; - END IF; - EXCEPTION - WHEN no_data_found THEN - RETURN FALSE; - END; + SELECT access_allowed + INTO l_access_allowed + FROM (SELECT auth.component_name + ,auth.rt_code + ,parl.rt_code + ,CASE + WHEN auth.rt_code IS NULL THEN + 'YES' + WHEN auth.rt_code = parl.rt_code THEN + 'YES' + ELSE + 'NO' + END access_allowed + FROM (SELECT prty.username + ,rt_code + FROM parties prty + ,party_roles parl + WHERE parl.prty_id = prty.id + AND upper(prty.username) = upper(p_app_user)) parl + ,apex_authorization auth + WHERE (auth.privilege = p_privilege OR + auth.privilege IS NULL AND p_privilege IS NULL) + AND auth.rt_code = parl.rt_code(+) + AND auth.component_name = p_component_name + AND auth.component_type = p_component_type + ORDER BY parl.rt_code) + WHERE rownum < 2; + + IF nvl(l_access_allowed + ,'NO') = 'YES' THEN + RETURN TRUE; + ELSE + RETURN FALSE; + END IF; + EXCEPTION + WHEN no_data_found THEN + RETURN FALSE; + END; END authorization; /** Checks for authorization to access the given page @@ -507,13 +596,13 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS ,SQLERRM); END new_password; -- - + /* creates a new password for another user */ - PROCEDURE other_user_password(p_prty_id IN number, - p_username IN VARCHAR2, - p_password IN VARCHAR2) IS + PROCEDURE other_user_password(p_prty_id IN NUMBER + ,p_username IN VARCHAR2 + ,p_password IN VARCHAR2) IS BEGIN INSERT INTO passwords (prty_id @@ -526,14 +615,14 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS ,p_password) ,SYSDATE ,NULL); - + EXCEPTION WHEN OTHERS THEN raise_application_error(-20002 ,SQLERRM); END other_user_password; -- - + -- PROCEDURE redirect_on_expired_account(p_username IN VARCHAR2) IS BEGIN