From 9cb6d4539e73d3e18ffa356ef83d0460a050c250 Mon Sep 17 00:00:00 2001 From: mullenm Date: Tue, 11 Dec 2007 18:46:49 +0000 Subject: [PATCH] New procedures created for the user management screens. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2973 248e525c-4dfb-0310-94bc-949c084e9493 --- Modules/mip_parties.pck | 564 ++++++++++++++++++++++++++++----------- Modules/mip_security.pck | 40 +++ 2 files changed, 442 insertions(+), 162 deletions(-) diff --git a/Modules/mip_parties.pck b/Modules/mip_parties.pck index 2640ea3..ad2ff6e 100644 --- a/Modules/mip_parties.pck +++ b/Modules/mip_parties.pck @@ -1,6 +1,5 @@ CREATE OR REPLACE PACKAGE mip_parties AS - /* PROCEDURE add_party - allows an admin user to create new parties for use in the system @@ -8,44 +7,97 @@ CREATE OR REPLACE PACKAGE mip_parties AS %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; + FUNCTION get_user_id(p_username IN VARCHAR2) RETURN NUMBER; + FUNCTION get_user_role(p_username IN VARCHAR2) RETURN VARCHAR2; -- /** get the password created date for the given username and password %return DATE the date the password was created for authenticated username and password combination - + */ - FUNCTION get_user_password_created(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) RETURN DATE; + FUNCTION get_user_password_created(p_username IN VARCHAR2, + p_password IN VARCHAR2) RETURN DATE; -- - FUNCTION has_supplier(p_username IN VARCHAR2, p_supplierid IN VARCHAR) return boolean; + FUNCTION has_supplier(p_username IN VARCHAR2, p_supplierid IN VARCHAR) + RETURN BOOLEAN; 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, + 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); + 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); + -- + /** allows new parties to be created in the system. + + %param p_manu_ref the manufacturer's unique reference + %param p_created_by the user that created the party + %param p_shortcode the mktp short code + %param p_name the organization's name + %param p_description description of the manufacturer + %param p_created_on when the party was created + %param p_mktp_ref the mktp's unique reference + %param p_lt_7b_contract_ref + %param p_gt_7b_contract_ref + %param p_adversarial_contract_ref + %param p_username the username + %param p_status the status of the user + %param p_first_name the user's first name + %param p_last_name the user's last name + %param p_personal_title the user's title + %param p_comments any comments on the user + %param p_id the unique party id + %param p_prty_type the prty type + + */ + PROCEDURE create_party(p_manu_ref IN VARCHAR2, + p_created_by IN VARCHAR2, + p_shortcode IN VARCHAR2, + p_name IN VARCHAR2, + p_description IN VARCHAR2, + p_mktp_ref IN VARCHAR2, + p_lt_7b_contract_ref IN VARCHAR2, + p_gt_7b_contract_ref IN VARCHAR2, + p_adversarial_contract_ref IN VARCHAR2, + p_username IN VARCHAR2, + p_first_name IN VARCHAR2, + p_last_name IN VARCHAR2, + p_personal_title IN VARCHAR2, + p_comments IN VARCHAR2, + p_id IN INTEGER, + p_prty_type IN VARCHAR2, + p_password IN VARCHAR2, + p_expire_pword IN NUMBER); + -- + PROCEDURE create_party_address(p_addr_code IN addresses.code%TYPE, + p_prty_id IN parties.id%TYPE, + p_addr_type IN VARCHAR2); + -- + /** + create party contact details + */ + PROCEDURE create_party_contact_details(p_prty_id IN parties.id%TYPE, + p_contact_mech_type IN VARCHAR2, + p_contact_value IN VARCHAR2); + -- END mip_parties; / CREATE OR REPLACE PACKAGE BODY mip_parties AS @@ -54,20 +106,24 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS - 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_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 @@ -76,63 +132,87 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS - 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; + 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; -- /** get the password created date for the given username and password %return DATE the date the password was created for authenticated username and password combination - + */ - FUNCTION get_user_password_created(p_username IN VARCHAR2 - ,p_password IN VARCHAR2) RETURN DATE AS + FUNCTION get_user_password_created(p_username IN VARCHAR2, + p_password IN VARCHAR2) RETURN DATE AS l_password_created_on DATE; BEGIN SELECT created_on INTO l_password_created_on - FROM (SELECT pwd.prty_id - ,pwd.password_hash - ,MAX(pwd.created_on) over(PARTITION BY pwd.prty_id) AS latest_pwd_date - ,pwd.created_on - FROM passwords pwd - ,parties prty + FROM (SELECT pwd.prty_id, + pwd.password_hash, + MAX(pwd.created_on) over(PARTITION BY pwd.prty_id) AS latest_pwd_date, + pwd.created_on + FROM passwords pwd, parties prty WHERE upper(prty.username) = upper(p_username) AND pwd.prty_id = prty.id) pwd WHERE pwd.created_on = pwd.latest_pwd_date - AND pwd.password_hash = mip_security.get_hash(p_username - ,p_password); - - RETURN l_password_created_on; - END get_user_password_created; + AND pwd.password_hash = + mip_security.get_hash(p_username, p_password); + + RETURN l_password_created_on; + END get_user_password_created; -- - + + -- + -- adds a new party address if required. -- 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; + -- check all columns are identical + -- if they match do nothing, we are reusing an existing address + -- otherwsie INSERT a new record. + -- + MERGE INTO addresses addr + USING (SELECT p_address.code AS code, + p_address.sub_building AS sub_building, + p_address.building AS building, + p_address.street AS street, + p_address.city AS city, + p_address.postcode AS postcode + FROM dual) l_addr + ON (addr.code = l_addr.code AND + addr.sub_building = l_addr.sub_building AND + addr.building = l_addr.building AND + addr.street = l_addr.street AND + addr.city = l_addr.city AND + addr.postcode = p_address.postcode) + WHEN NOT MATCHED THEN + INSERT + (code, sub_building, building, street, city, postcode) + VALUES + (l_addr.code, + l_addr.sub_building, + l_addr.building, + l_addr.street, + l_addr.city, + l_addr.postcode); + + --COMMIT; -- EXCEPTION WHEN OTHERS THEN @@ -140,36 +220,35 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS 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, + 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 + 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 @@ -182,7 +261,7 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS prty_type, created_on, created_by, - name, + NAME, mktp_ref, shortcode, lt_7b_contract_ref, @@ -216,47 +295,46 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS p_first_name, p_last_name, p_personal_title, - p_comments - ) + 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 + IF p_addresscode IS NOT NULL THEN add_partyaddress(p_addresscode, partyid); - end if; + END IF; -- call the party role to fill in the link between party and the role - if p_partyrole IS NOT NULL then + IF p_partyrole IS NOT NULL THEN add_partyrole(p_partyrole, partyid); - end if; + END IF; -- call the party contact mechanism to link the party to a contact mech - if p_partycontactmech IS NOT NULL then + IF p_partycontactmech IS NOT NULL THEN add_partycontactmech(p_partycontactmech, partyid); - end if; + 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; - -- + 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 || ':'; + 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); + l_working_code := substr(l_addr_code, 1, instr(l_addr_code, ':') - 1); -- IF l_working_code IS NULL THEN EXIT; @@ -267,22 +345,27 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS VALUES (l_working_code, p_prty_id, SYSDATE, SYSDATE, 'The comments field'); -- - l_addr_code := SUBSTR(l_addr_code, INSTR(l_addr_code, ':')+1); + 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 + 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'); - + (prty_seq.NEXTVAL, + p_role_code, + p_prty_id, + SYSDATE, + SYSDATE, + 'createwd via plsql procedure add_partyrole'); + COMMIT; -- EXCEPTION @@ -290,33 +373,36 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS 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 + 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 || ':'; - + l_contact_mech := p_contact_mech || ':'; + LOOP -- - l_working_code := SUBSTR(l_contact_mech, 1, INSTR(l_contact_mech, ':')-1); + l_working_code := substr(l_contact_mech, + 1, + instr(l_contact_mech, ':') - 1); -- IF l_working_code IS NULL THEN EXIT; @@ -327,14 +413,13 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS -- (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 + (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) @@ -343,14 +428,15 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS 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); + l_contact_mech := substr(l_contact_mech, + instr(l_contact_mech, ':') + 1); -- END LOOP; -- @@ -366,21 +452,175 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS %param p_username - the name of the user you want to find the supplier for. %param p_supplierid - the id of the supplier you want to check the user against. */ - FUNCTION has_supplier(p_username IN VARCHAR2, p_supplierid IN VARCHAR) return boolean as - cursor c_userrole is select ID - from PARTIES p, PARTY_RELATIONSHIPS pr - where p.ID = pr.TO_PARL_PRTY_ID - and pr.FROM_PARL_PRTY_ID = get_user_id(p_username) - and pr.TO_PARL_RT_CODE = 'SUPP' - and pr.FROM_PARL_RT_CODE = 'AGENT'; - begin - for userrole_rec in c_userrole loop - if p_supplierid = userrole_rec.id then - return true; - end if; - end loop; - return false; - end has_supplier; + FUNCTION has_supplier(p_username IN VARCHAR2, p_supplierid IN VARCHAR) + RETURN BOOLEAN AS + CURSOR c_userrole IS + SELECT id + FROM parties p, party_relationships pr + WHERE p.id = pr.to_parl_prty_id + AND pr.from_parl_prty_id = get_user_id(p_username) + AND pr.to_parl_rt_code = 'SUPP' + AND pr.from_parl_rt_code = 'AGENT'; + BEGIN + FOR userrole_rec IN c_userrole LOOP + IF p_supplierid = userrole_rec.id THEN + RETURN TRUE; + END IF; + END LOOP; + RETURN FALSE; + END has_supplier; + /** allows new parties to be created in the system. + + %param p_manu_ref the manufacturer's unique reference + %param p_created_by the user that created the party + %param p_shortcode the mktp short code + %param p_name the organization's name + %param p_description description of the manufacturer + %param p_created_on when the party was created + %param p_mktp_ref the mktp's unique reference + %param p_lt_7b_contract_ref + %param p_gt_7b_contract_ref + %param p_adversarial_contract_ref + %param p_username the username + %param p_status the status of the user + %param p_first_name the user's first name + %param p_last_name the user's last name + %param p_personal_title the user's title + %param p_comments any comments on the user + %param p_id the unique party id + %param p_prty_type the prty type + + */ + PROCEDURE create_party(p_manu_ref IN VARCHAR2, + p_created_by IN VARCHAR2, + p_shortcode IN VARCHAR2, + p_name IN VARCHAR2, + p_description IN VARCHAR2, + p_mktp_ref IN VARCHAR2, + p_lt_7b_contract_ref IN VARCHAR2, + p_gt_7b_contract_ref IN VARCHAR2, + p_adversarial_contract_ref IN VARCHAR2, + p_username IN VARCHAR2, + p_first_name IN VARCHAR2, + p_last_name IN VARCHAR2, + p_personal_title IN VARCHAR2, + p_comments IN VARCHAR2, + p_id IN INTEGER, + p_prty_type IN VARCHAR2, + p_password IN VARCHAR2, + p_expire_pword IN NUMBER) IS + -- + BEGIN + -- + INSERT INTO parties + (id, + manu_ref, + created_by, + shortcode, + NAME, + description, + created_on, + mktp_ref, + lt_7b_contract_ref, + gt_7b_contract_ref, + adversarial_contract_ref, + username, + first_name, + last_name, + personal_title, + comments, + prty_type) + VALUES + (p_id, + p_manu_ref, + p_created_by, + p_shortcode, + p_name, + p_description, + SYSDATE, + p_mktp_ref, + p_lt_7b_contract_ref, + p_gt_7b_contract_ref, + p_adversarial_contract_ref, + upper(p_username), + p_first_name, + p_last_name, + p_personal_title, + p_comments, + p_prty_type); + + -- if we created a user they need a password creating + IF upper(p_prty_type) = 'PERS' THEN + mip_security.other_user_password(p_prty_id => p_id, + p_username => p_username, + p_password => p_password); + + -- set the user's status + IF p_expire_pword IS NOT NULL THEN + mip_security.set_user_status(p_username => p_username, + p_status => 'EXPIRED'); + ELSE + -- just open the user + mip_security.set_user_status(p_username => p_username, + p_status => 'OPEN'); + END IF; + END IF; + -- + END create_party; + -- + + /** + associate an address with a party + + %param p_addr_code the code of the address + %param p_prty_id the party's unique ID + %param p_addr_type the type of address, either HOME or OFFICE + */ + PROCEDURE create_party_address(p_addr_code IN addresses.code%TYPE, + p_prty_id IN parties.id%TYPE, + p_addr_type IN VARCHAR2) IS + BEGIN + INSERT INTO party_addresses + (addr_code, prty_id, start_date, end_date, comments) + VALUES + (p_addr_code, + p_prty_id, + SYSDATE, + NULL, + 'Party address created by ' || v('APP_USER')); + + INSERT INTO party_address_roles + (start_date, + paddr_addr_code, + paddr_prty_id, + paddr_start_date, + rt_code, + end_date) + VALUES + (SYSDATE, p_addr_code, p_prty_id, SYSDATE, p_addr_type, NULL); + + END create_party_address; + -- + + /** + create party contact details + */ + PROCEDURE create_party_contact_details(p_prty_id IN parties.id%TYPE, + p_contact_mech_type IN VARCHAR2, + p_contact_value IN VARCHAR2) IS + l_come_id NUMBER; + BEGIN + SELECT come_seq.NEXTVAL INTO l_come_id FROM dual; + + -- insert the contact mechanism value + INSERT INTO contact_mechanisms(comt_code, contact_value, id) + VALUES(p_contact_mech_type, p_contact_value, l_come_id); + + -- associate the contact mechanism with the party. + INSERT INTO party_contact_mechanisms(come_id, prty_id, start_date) + VALUES(l_come_id, p_prty_id, SYSDATE); + + END create_party_contact_details; END mip_parties; / diff --git a/Modules/mip_security.pck b/Modules/mip_security.pck index 0ba0a3f..4e1f23f 100644 --- a/Modules/mip_security.pck +++ b/Modules/mip_security.pck @@ -51,6 +51,19 @@ recordThe resultant hash is recorded as the username 'password hash' PROCEDURE new_password(p_username IN VARCHAR2 ,p_password IN VARCHAR2); + /* + creates a new password for another user + */ + PROCEDURE other_user_password(p_prty_id IN number, + p_username IN VARCHAR2, + p_password IN VARCHAR2); + -- + + /** Updates the user status + */ + PROCEDURE set_user_status(p_username IN VARCHAR2, p_status IN VARCHAR2); + -- + /** Authorize access to the given page %param p_app_user The name of the application user %param p_page_id The page to be accessed @@ -483,6 +496,33 @@ 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 + BEGIN + INSERT INTO passwords + (prty_id + ,password_hash + ,created_on + ,created_by) + VALUES + (p_prty_id + ,get_hash(p_username + ,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