From 2a490afbbc4d2a86fc61bec66f3a1bf936ed110f Mon Sep 17 00:00:00 2001 From: mullenm Date: Mon, 26 Nov 2007 13:34:20 +0000 Subject: [PATCH] Added the copy_enquiry function and other supporting functions. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2886 248e525c-4dfb-0310-94bc-949c084e9493 --- Modules/MIP_ENQUIRY.pck | 248 +++++++++++++++++++++++++++++++++++++--- 1 file changed, 229 insertions(+), 19 deletions(-) diff --git a/Modules/MIP_ENQUIRY.pck b/Modules/MIP_ENQUIRY.pck index 17b372a..cec4da3 100644 --- a/Modules/MIP_ENQUIRY.pck +++ b/Modules/MIP_ENQUIRY.pck @@ -1,16 +1,54 @@ -create or replace package MIP_ENQUIRY is +CREATE OR REPLACE PACKAGE mip_enquiry IS -- Author : PRIESTJ -- Created : 15/11/2007 14:18:24 -- Purpose : Provides useful admin functions/procedures for enquiries + -- Updates : 21 November 2007 - MM - added copy_enquiry function + -- -- Public function and procedure declarations - FUNCTION set_enquiry_role(p_enquiryid in number,p_partyid in number,p_rolecode IN VARCHAR2) - RETURN boolean; + FUNCTION set_enquiry_role(p_enquiryid IN NUMBER, + p_partyid IN NUMBER, + p_rolecode IN VARCHAR2) RETURN BOOLEAN; -end MIP_ENQUIRY; + /* + FUNCTION set_enquiry_role + - gets the enquiry id, party id and the role type and writes a record in the enquiry_roles table + - allowing you to assign agents, suppliers etc. to an enquiry. + %param p_enquiryid - the current enquiry to save the role against. + %param p_partyid - the user or party to assign to this role. + %param p_rolecode - what kind of role this will be. + %param p_description - a description for the enquiry role + */ + FUNCTION set_enquiry_role(p_enquiryid IN NUMBER, + p_partyid IN NUMBER, + p_rolecode IN VARCHAR2, + p_description IN VARCHAR2) RETURN BOOLEAN; + + -- + FUNCTION set_enquiry_event(p_enquiryid IN NUMBER, + p_eventcode IN VARCHAR2) RETURN BOOLEAN; + + /* + FUNCTION copy_enquiry + copies the specified enquiry. + + %param p_enquiry_id - the id of the current enquiry to copy. + %param p_enqu_owner - the ID of the enquiry owner + %param p_enqu_supp - the ID of the enquiry supplier + %return varchar2 - a success or error message. + + -- NOTE: there is no need to copy any quote information. All quotes will be + -- regenerated for the new enquiry when submitted. + */ + FUNCTION copy_enquiry(p_enquiry_id enquiries.id%TYPE, + p_enqu_owner parties.id%TYPE, + p_enqu_supp parties.id%TYPE) RETURN VARCHAR2; + -- + +END mip_enquiry; / -create or replace package body MIP_ENQUIRY is +CREATE OR REPLACE PACKAGE BODY mip_enquiry IS /* FUNCTION set_enquiry_role - gets the enquiry id, party id and the role type and writes a record in the enquiry_roles table @@ -19,25 +57,197 @@ create or replace package body MIP_ENQUIRY is %param p_partyid - the user or party to assign to this role. %param p_rolecode - what kind of role this will be. */ - FUNCTION set_enquiry_role(p_enquiryid in number,p_partyid in number,p_rolecode IN VARCHAR2) - RETURN boolean as - begin + FUNCTION set_enquiry_role(p_enquiryid IN NUMBER, + p_partyid IN NUMBER, + p_rolecode IN VARCHAR2) RETURN BOOLEAN AS + BEGIN INSERT INTO enquiry_roles - (enqu_id, prty_id, rt_code) + (enqu_id, prty_id, start_date, rt_code) VALUES - (p_enquiryid, - p_partyid, - p_rolecode); + (p_enquiryid, p_partyid, SYSDATE, p_rolecode); - return TRUE; + RETURN TRUE; + -- + -- EXCEPTION + -- WHEN OTHERS THEN + -- RETURN FALSE; + -- RAISE; + END set_enquiry_role; + -- + + /* + FUNCTION set_enquiry_role + - gets the enquiry id, party id and the role type and writes a record in the enquiry_roles table + - allowing you to assign agents, suppliers etc. to an enquiry. + %param p_enquiryid - the current enquiry to save the role against. + %param p_partyid - the user or party to assign to this role. + %param p_rolecode - what kind of role this will be. + %param p_description - a description for the enquiry role + */ + FUNCTION set_enquiry_role(p_enquiryid IN NUMBER, + p_partyid IN NUMBER, + p_rolecode IN VARCHAR2, + p_description IN VARCHAR2) RETURN BOOLEAN AS + BEGIN + + INSERT INTO enquiry_roles + (enqu_id, prty_id, start_date, rt_code, description) + VALUES + (p_enquiryid, p_partyid, SYSDATE, p_rolecode, p_description); + + RETURN TRUE; -- EXCEPTION - -- edit this to check for a 'unable to write record' - -- only and just pass on all other exceptions WHEN OTHERS THEN - return FALSE; - RAISE; - end set_enquiry_role; -end MIP_ENQUIRY; + RETURN FALSE; + END set_enquiry_role; + -- + + /* + FUNCTION set_enquiry_event + - gets the enquiry id and the event type and writes a record in the enquiry_roles table + - allowing you to assign in progress, submitted for quotation etc. to an enquiry. + %param p_enquiryid - the current enquiry to save the event role against. + %param p_eventcode - what kind of event role this will be. + */ + FUNCTION set_enquiry_event(p_enquiryid IN NUMBER, + p_eventcode IN VARCHAR2) RETURN BOOLEAN AS + BEGIN + + INSERT INTO enquiry_events + (enqu_id, event_date, enst_code) + VALUES + (p_enquiryid, SYSDATE, p_eventcode); + + RETURN TRUE; + -- + -- EXCEPTION + -- WHEN OTHERS THEN + -- RETURN FALSE; + -- RAISE; + END set_enquiry_event; + -- + + /* + FUNCTION copy_enquiry + copies the specified enquiry. + + %param p_enquiry_id - the id of the current enquiry to copy. + %param p_enqu_owner - the ID of the enquiry owner + %param p_enqu_supp - the ID of the enquiry supplier + %return varchar2 - a success or error message. + + -- NOTE: there is no need to copy any quote information. All quotes will be + -- regenerated for the new enquiry when submitted. + */ + FUNCTION copy_enquiry(p_enquiry_id enquiries.id%TYPE, + p_enqu_owner parties.id%TYPE, + p_enqu_supp parties.id%TYPE) RETURN VARCHAR2 IS + -- + -- cursor to get a new enquiry ID from the sequence + CURSOR c_get_new_id IS + SELECT enqu_seq.NEXTVAL FROM dual; + + -- cursor to get the current enquiry + CURSOR c_get_enquiry IS + SELECT * FROM enquiries WHERE id = p_enquiry_id; + + -- variable to hold the enquiry details returned + l_enqu_row enquiries%ROWTYPE; + + -- the new enquiry ID + l_enqu_id NUMBER; + + -- + l_dummy BOOLEAN; + -- + BEGIN + + -- first thing to do is check the user's role allows them to copy enquiries + -- only agents and I&C users. + IF NOT mip_parties.get_user_role(p_username => v('APP_USER')) IN ('AGENT','ICU', 'MIPADMIN') THEN + raise_application_error(-20100,'User '||v('APP_USER') || ' is not permitted to copy enquiries.'); + END IF; + + + -- + -- try to get the enquiry based on the ID we've been given. + -- + BEGIN + IF NOT c_get_enquiry%ISOPEN THEN + OPEN c_get_enquiry; + END IF; + + FETCH c_get_enquiry + INTO l_enqu_row; + + CLOSE c_get_enquiry; + + EXCEPTION + WHEN no_data_found THEN + CLOSE c_get_enquiry; + -- couldn't find the enquiry, tell someone + raise_application_error(-20100,'Unable to find the specified enquiry. Please try again.'); + END; + -- + + -- get a new enquiry ID. + BEGIN + OPEN c_get_new_id; + FETCH c_get_new_id + INTO l_enqu_id; + CLOSE c_get_new_id; + EXCEPTION + WHEN no_data_found THEN + CLOSE c_get_new_id; + raise_application_error(-20101,'Unable to retrieve a new ID for the enquiry.'); + END; + + l_enqu_row.id := l_enqu_id; + + -- now do the insert (copy) for the enquiry + INSERT INTO enquiries VALUES l_enqu_row; + -- + + -- create an enquiry supplier, add a description of where it was copied from + l_dummy := set_enquiry_role(p_enquiryid => l_enqu_id, + p_partyid => p_enqu_supp, + p_rolecode => 'ENQ SUPP', + p_description => 'Enquiry copied from enquiry ' || + p_enquiry_id || ' by user ' || + v(':APP_USER')); + IF NOT l_dummy THEN + raise_application_error(-20102,'Unable to set enquiry supplier.'); + END IF; + + -- create an enquiry owner + l_dummy := set_enquiry_role(p_enquiryid => l_enqu_id, + p_partyid => p_enqu_owner, + p_rolecode => 'ENQ OWN'); + IF NOT l_dummy THEN + raise_application_error(-20103,'Unable to set enquiry owner.'); + END IF; + -- + + -- set the enquiry event to "In Progress" + l_dummy := set_enquiry_event(p_enquiryid => l_enqu_id, + p_eventcode => 'INP'); + + IF NOT l_dummy THEN + raise_application_error(-20104,'Unable to set enquiry owner.'); + END IF; + -- + + -- + RETURN l_enqu_id; + -- + EXCEPTION + WHEN OTHERS THEN + ROLLBACK; + RETURN SQLERRM; + END copy_enquiry; + -- + +END mip_enquiry; /