CREATE OR REPLACE PACKAGE mip_parties AS /* PROCEDURE add_party - allows an admin user to create new parties for use in the system %param p_username - the name of the user to create %param p_password - the password of the party %p_role - the party's role in the system */ FUNCTION get_user_id(p_username IN VARCHAR2) RETURN NUMBER; FUNCTION get_user_role(p_username IN VARCHAR2) return varchar2; PROCEDURE add_address(p_address addresses%ROWTYPE); PROCEDURE add_partyaddress(p_addr_code IN VARCHAR2, p_prty_id IN INTEGER); PROCEDURE add_partyrole(p_role_code IN VARCHAR2, p_prty_id IN NUMBER); PROCEDURE add_partycontactmech(p_contact_mech IN VARCHAR2, p_prty_id IN NUMBER); PROCEDURE add_party(p_role IN VARCHAR2, p_username IN VARCHAR2, p_created_by IN VARCHAR2, p_name IN VARCHAR2, p_mkpt_ref IN VARCHAR2, p_shortcode IN VARCHAR2, p_lt_7b_contract_ref IN VARCHAR2, p_gt_7b_contract_ref IN VARCHAR2, p_adversarial_contract_ref IN VARCHAR2, p_manu_ref IN VARCHAR2, p_description IN VARCHAR2, p_status IN VARCHAR2, p_first_name IN VARCHAR2, p_last_name IN VARCHAR2, p_personal_title IN VARCHAR2, p_comments IN VARCHAR2, p_addresscode IN VARCHAR2, p_partyrole IN VARCHAR2, p_partycontactmech IN VARCHAR2); END mip_parties; / CREATE OR REPLACE PACKAGE BODY mip_parties AS /* FUNCTION get_user_id - gets the primary key for a supplied username. This function searches the parties - table for a matching username, if the name is found the users id is returned. %param p_username - the name of the user you want to get the id for. UPDATES 20-Nov-2007 - MM- Upper ing the username check as APEX passes an uppered :APP_USER */ FUNCTION get_user_id(p_username IN VARCHAR2) return NUMBER as userid NUMBER; cursor c_userid is select id from parties where upper(USERNAME) = upper(p_username); begin open c_userid; fetch c_userid into userid; close c_userid; return userid; exception when others then return null; end get_user_id; /* FUNCTION get_user_role - gets the role keycode for a supplied username. This function searches the parties - table for a matching username, if the name is found the users id is returned. - That id is used to search the party_roles table to get the role keycode. %param p_username - the name of the user you want to get the id for. */ FUNCTION get_user_role(p_username IN VARCHAR2) return varchar2 as rolecode varchar2(80); cursor c_userrole is select rt_code from party_roles where PRTY_ID = get_user_id(p_username); begin open c_userrole; fetch c_userrole into rolecode; close c_userrole; return rolecode; exception when others then return null; end get_user_role; PROCEDURE add_address(p_address addresses%ROWTYPE) AS -- BEGIN -- --not implemented yet - will allow us to check the password is valid based on rule in the functional spec -- check_password(p_password); INSERT INTO addresses (code, sub_building, building, street, city, postcode) VALUES (to_char(prty_seq.NEXTVAL), p_address.sub_building, p_address.building, p_address.street, p_address.city, p_address.postcode); COMMIT; -- EXCEPTION WHEN OTHERS THEN ROLLBACK; RAISE; END add_address; /* PROCEDURE add_party - allows an admin user to create new parties for use in the system %param p_username - the name of the user to create %param p_password - the password of the party %p_role - the party's role in the system */ -- PROCEDURE add_party(p_role IN VARCHAR2, p_username IN VARCHAR2, p_created_by IN VARCHAR2, p_name IN VARCHAR2, p_mkpt_ref IN VARCHAR2, p_shortcode IN VARCHAR2, p_lt_7b_contract_ref IN VARCHAR2, p_gt_7b_contract_ref IN VARCHAR2, p_adversarial_contract_ref IN VARCHAR2, p_manu_ref IN VARCHAR2, p_description IN VARCHAR2, p_status IN VARCHAR2, p_first_name IN VARCHAR2, p_last_name IN VARCHAR2, p_personal_title IN VARCHAR2, p_comments IN VARCHAR2, p_addresscode IN VARCHAR2, p_partyrole IN VARCHAR2, p_partycontactmech IN VARCHAR2) AS -- partyid NUMBER; BEGIN -- --not implemented yet - will allow us to check the password is valid based on rule in the functional spec -- check_password(p_password); INSERT INTO parties (id, username, prty_type, created_on, created_by, name, mktp_ref, shortcode, lt_7b_contract_ref, gt_7b_contract_ref, adversarial_contract_ref, manu_ref, description, status, first_name, last_name, personal_title, comments) VALUES (prty_seq.NEXTVAL, upper(p_username), --get_hash(TRIM(p_username), p_password), --will need to call matts get_hash routine once he's added --it into the new schema upper(p_role), SYSDATE, p_created_by, p_name, p_mkpt_ref, p_shortcode, p_lt_7b_contract_ref, p_gt_7b_contract_ref, p_adversarial_contract_ref, p_manu_ref, p_description, p_status, p_first_name, p_last_name, p_personal_title, p_comments ) RETURNING parties.id INTO partyid; --COMMIT; --call the partyaddress to fill in the link between the party and the address if p_addresscode IS NOT NULL then add_partyaddress(p_addresscode, partyid); end if; -- call the party role to fill in the link between party and the role if p_partyrole IS NOT NULL then add_partyrole(p_partyrole, partyid); end if; -- call the party contact mechanism to link the party to a contact mech if p_partycontactmech IS NOT NULL then add_partycontactmech(p_partycontactmech, partyid); end if; -- END add_party; /* PROCEDURE add_partyaddress - allows the association of a party to a number of addresses %param p_username - the name of the user to create %param p_password - the password of the party %p_role - the party's role in the system */ -- PROCEDURE add_partyaddress(p_addr_code IN VARCHAR2, p_prty_id IN INTEGER) AS -- l_addr_code addresses.code%TYPE; l_working_code addresses.code%TYPE; -- BEGIN l_addr_code := p_addr_code || ':'; --not implemented yet - will allow us to check the password is valid based on rule in the functional spec -- check_password(p_password); LOOP -- l_working_code := SUBSTR(l_addr_code, 1, INSTR(l_addr_code, ':')-1); -- IF l_working_code IS NULL THEN EXIT; END IF; -- INSERT INTO party_addresses (addr_code, prty_id, start_date, end_date, comments) VALUES (l_working_code, p_prty_id, SYSDATE, SYSDATE, 'The comments field'); -- l_addr_code := SUBSTR(l_addr_code, INSTR(l_addr_code, ':')+1); -- END LOOP; -- END add_partyaddress; PROCEDURE add_partyrole(p_role_code IN VARCHAR2, p_prty_id IN NUMBER) AS -- BEGIN -- INSERT INTO party_roles (id, rt_code, prty_id, start_date, end_date, description) VALUES (prty_seq.NEXTVAL, p_role_code, p_prty_id, SYSDATE, SYSDATE, 'createwd via plsql procedure add_partyrole'); COMMIT; -- EXCEPTION WHEN OTHERS THEN ROLLBACK; RAISE; END add_partyrole; /* PROCEDURE add_partycontactmech - allows the association of a party to a number of addresses %param p_contact_mech - the name of the contact mechanism code %param p_prty_id - the party's id */ -- PROCEDURE add_partycontactmech(p_contact_mech IN VARCHAR2, p_prty_id IN NUMBER) AS -- l_contact_mech contact_mechanisms.comt_code%TYPE; l_working_code contact_mechanisms.comt_code%TYPE; comeid contact_mechanisms.id%TYPE; --l_contact_mech_role contact_mechanisms.comt_code%TYPE; --l_working_role contact_mechanisms.comt_code%TYPE; --pcmr_id party_contact_mechanism_roles.id%TYPE -- -- get the contact mech type -- create a new contact mech using the type code -- create a new party contact mech from the partyid and the newly created contact mech BEGIN l_contact_mech := p_contact_mech || ':'; LOOP -- l_working_code := SUBSTR(l_contact_mech, 1, INSTR(l_contact_mech, ':')-1); -- IF l_working_code IS NULL THEN EXIT; END IF; -- -- Create the Contact mechanism INSERT INTO contact_mechanisms -- (comt_code, contact_value, id) VALUES (l_working_code, 'dunno what this field is for', come_seq.nextval) RETURNING contact_mechanisms.id INTO comeid; /*-- Create the Party contact mechanism role --Think this needs to be sorted out much like the contact mechanism listed --above, however not sure about the model and what AH intended INSERT INTO party_contact_mechanism_roles -- (pcmrt_code, pcm_prty_id, start_date, id) VALUES (l_working_role, p_prty_id, sysdate, MADEUPSEQPROBABLY CALLED-PCMR_seq.nextval) RETURNING party_contact_mechanism_roles.id INTO pcmr_id;*/ INSERT INTO party_contact_mechanisms --should be the come_id i think! (come_id, prty_id, start_date, end_date, comments) VALUES (comeid, p_prty_id, SYSDATE, SYSDATE, 'The comments field'); -- l_contact_mech := SUBSTR(l_contact_mech, INSTR(l_contact_mech, ':')+1); -- END LOOP; -- END add_partycontactmech; -- -- END mip_parties; /