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 delete_enquiry(p_enquiryid IN NUMBER) RETURN BOOLEAN; FUNCTION get_enquiry_status(p_enquiryid IN NUMBER) RETURN VARCHAR2; FUNCTION get_enquiry_role(p_enquiryid IN NUMBER ,p_rolecode IN VARCHAR2) RETURN NUMBER; FUNCTION set_enquiry_role(p_enquiryid IN NUMBER ,p_partyid IN NUMBER ,p_rolecode IN VARCHAR2) RETURN BOOLEAN; /* 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 /* 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 get_enquiry_status - This function returns the status of the enquiry provided %param p_enquiryid - the enquiry we want to find the role from. %return varchar2 - the current status of the enquiry */ FUNCTION get_enquiry_status(p_enquiryid IN NUMBER) RETURN VARCHAR2 AS -- cursor to get the current enquiry CURSOR c_get_enquiry_status(cp_enqu_id number) IS SELECT enst_code FROM v_current_enquiry_status WHERE enqu_id=cp_enqu_id; l_enqu_status varchar2(80); BEGIN IF NOT c_get_enquiry_status%ISOPEN THEN OPEN c_get_enquiry_status(p_enquiryid); END IF; FETCH c_get_enquiry_status INTO l_enqu_status; CLOSE c_get_enquiry_status; return nvl(l_enqu_status,''); END get_enquiry_status; /* FUNCTION get_enquiry_role - This function finds the enquiry and the role specified and returns the - latest(current) user id for the specifed role %param p_enquiryid - the enquiry we want to find the role from. %param p_rolecode - the type of role we want to find %return number - the party id of the party that currently assumes the specified role */ FUNCTION get_enquiry_role(p_enquiryid IN NUMBER ,p_rolecode IN VARCHAR2) RETURN NUMBER AS -- cursor to get the current enquiry CURSOR c_get_enquiry_role(cp_enqu_id number, cp_rolecode VARCHAR2) IS SELECT prty_id FROM v_latest_rt_code_for_enro WHERE rt_code=cp_rolecode and enqu_id=cp_enqu_id; l_enqu_role_row number; BEGIN IF NOT c_get_enquiry_role%ISOPEN THEN OPEN c_get_enquiry_role(p_enquiryid, p_rolecode); END IF; FETCH c_get_enquiry_role INTO l_enqu_role_row; CLOSE c_get_enquiry_role; return l_enqu_role_row; END get_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. */ 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 ,start_date ,rt_code) VALUES (p_enquiryid ,p_partyid ,SYSDATE ,p_rolecode); 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 WHEN OTHERS THEN 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; /