added functionality to add party roles and relationships
git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2974 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
@@ -20,8 +20,9 @@ CREATE OR REPLACE PACKAGE mip_parties AS
|
||||
--
|
||||
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);
|
||||
@@ -87,17 +88,61 @@ CREATE OR REPLACE PACKAGE mip_parties AS
|
||||
p_password IN VARCHAR2,
|
||||
p_expire_pword IN NUMBER);
|
||||
--
|
||||
|
||||
/**
|
||||
allows the creation of addresses in the system.
|
||||
|
||||
%param p_address address%ROWTYPE - a record of the address table.
|
||||
*/
|
||||
PROCEDURE add_address(p_address addresses%ROWTYPE);
|
||||
--
|
||||
|
||||
/**
|
||||
allows an address in the system to be associated with a party
|
||||
|
||||
%param p_addr_code - the ID of the address
|
||||
%param p_prty_id - the ID of the party
|
||||
%param p_addr_type - the type of address (HOME/OFFICE)
|
||||
*/
|
||||
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
|
||||
*/
|
||||
allows party contact details to be stored in the system
|
||||
|
||||
%param p_prty_id - the ID of the party
|
||||
%param p_contact_mech_type - the type of contact mechanism being created
|
||||
%param p_contact_value - the value of the contact mechanism
|
||||
|
||||
*/
|
||||
PROCEDURE create_party_contact_details(p_prty_id IN parties.id%TYPE,
|
||||
p_contact_mech_type IN VARCHAR2,
|
||||
p_contact_value IN VARCHAR2);
|
||||
--
|
||||
|
||||
/**
|
||||
allows a role to be assigned to a party
|
||||
|
||||
%param p_role_code the role to assign to the party
|
||||
%param p_prty_id the unique party ID
|
||||
*/
|
||||
PROCEDURE add_party_role(p_role_code IN VARCHAR2,
|
||||
p_prty_id IN NUMBER);
|
||||
--
|
||||
|
||||
/**
|
||||
allows a party relationship to be created e.g. associating a party with a supplier
|
||||
|
||||
*/
|
||||
PROCEDURE create_relationship(p_from_prty_id IN VARCHAR2,
|
||||
p_from_prty_role IN VARCHAR2,
|
||||
p_to_prty_id IN VARCHAR2,
|
||||
p_to_prty_role IN VARCHAR2);
|
||||
--
|
||||
END mip_parties;
|
||||
/
|
||||
CREATE OR REPLACE PACKAGE BODY mip_parties AS
|
||||
@@ -176,49 +221,29 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS
|
||||
END get_user_password_created;
|
||||
--
|
||||
|
||||
PROCEDURE add_partyrole(p_role_code IN VARCHAR2, p_prty_id IN NUMBER) AS
|
||||
--
|
||||
-- adds a new party address if required.
|
||||
--
|
||||
PROCEDURE add_address(p_address addresses%ROWTYPE) AS
|
||||
--
|
||||
BEGIN
|
||||
--
|
||||
-- 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;
|
||||
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,
|
||||
NULL,
|
||||
'added by ' || v('APP_USER'));
|
||||
|
||||
COMMIT;
|
||||
--
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
ROLLBACK;
|
||||
RAISE;
|
||||
END add_address;
|
||||
END add_partyrole;
|
||||
--
|
||||
|
||||
/*
|
||||
PROCEDURE add_party
|
||||
@@ -351,28 +376,7 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS
|
||||
--
|
||||
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
|
||||
@@ -570,6 +574,53 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS
|
||||
END create_party;
|
||||
--
|
||||
|
||||
/**
|
||||
allows the creation of addresses in the system.
|
||||
|
||||
%param p_address address%ROWTYPE - a record of the address table.
|
||||
*/
|
||||
PROCEDURE add_address(p_address addresses%ROWTYPE) AS
|
||||
--
|
||||
BEGIN
|
||||
--
|
||||
-- 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
|
||||
ROLLBACK;
|
||||
RAISE;
|
||||
END add_address;
|
||||
--
|
||||
|
||||
/**
|
||||
associate an address with a party
|
||||
|
||||
@@ -604,8 +655,13 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS
|
||||
--
|
||||
|
||||
/**
|
||||
create party contact details
|
||||
*/
|
||||
allows party contact details to be stored in the system
|
||||
|
||||
%param p_prty_id - the ID of the party
|
||||
%param p_contact_mech_type - the type of contact mechanism being created
|
||||
%param p_contact_value - the value of the contact mechanism
|
||||
|
||||
*/
|
||||
PROCEDURE create_party_contact_details(p_prty_id IN parties.id%TYPE,
|
||||
p_contact_mech_type IN VARCHAR2,
|
||||
p_contact_value IN VARCHAR2) IS
|
||||
@@ -622,5 +678,86 @@ CREATE OR REPLACE PACKAGE BODY mip_parties AS
|
||||
VALUES(l_come_id, p_prty_id, SYSDATE);
|
||||
|
||||
END create_party_contact_details;
|
||||
--
|
||||
|
||||
/**
|
||||
allows a role to be assigned to a party
|
||||
|
||||
%param p_role_code the role to assign to the party
|
||||
%param p_prty_id the unique party ID
|
||||
*/
|
||||
PROCEDURE add_party_role(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,
|
||||
NULL,
|
||||
'added by ' || v('APP_USER'));
|
||||
|
||||
--
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN
|
||||
ROLLBACK;
|
||||
RAISE;
|
||||
END add_party_role;
|
||||
--
|
||||
|
||||
/**
|
||||
allows a party relationship to be created e.g. associating a party with a supplier
|
||||
|
||||
*/
|
||||
PROCEDURE create_relationship(p_from_prty_id IN VARCHAR2,
|
||||
p_from_prty_role IN VARCHAR2,
|
||||
p_to_prty_id IN VARCHAR2,
|
||||
p_to_prty_role IN VARCHAR2) IS
|
||||
l_to_parl_id NUMBER;
|
||||
l_from_parl_id NUMBER;
|
||||
BEGIN
|
||||
-- get the role IDs
|
||||
SELECT parl.id
|
||||
INTO l_to_parl_id
|
||||
FROM party_roles parl
|
||||
WHERE parl.prty_id = p_to_prty_id
|
||||
AND parl.rt_code = p_to_prty_role;
|
||||
|
||||
SELECT parl.id
|
||||
INTO l_from_parl_id
|
||||
FROM party_roles parl
|
||||
WHERE parl.prty_id = p_from_prty_id
|
||||
AND parl.rt_code = p_from_prty_role;
|
||||
|
||||
-- now do the insert
|
||||
INSERT INTO party_relationships
|
||||
(from_parl_id,
|
||||
to_parl_id,
|
||||
from_parl_prty_id,
|
||||
to_parl_prty_id,
|
||||
from_parl_rt_code,
|
||||
to_parl_rt_code,
|
||||
start_date,
|
||||
from_prtp_rt_code,
|
||||
to_prtp_rt_code,
|
||||
end_date)
|
||||
VALUES
|
||||
(l_from_parl_id,
|
||||
l_to_parl_id,
|
||||
p_from_prty_id,
|
||||
p_to_prty_id,
|
||||
p_from_prty_role,
|
||||
p_to_prty_role,
|
||||
SYSDATE,
|
||||
p_from_prty_role,
|
||||
p_to_prty_role,
|
||||
NULL);
|
||||
END create_relationship;
|
||||
--
|
||||
END mip_parties;
|
||||
/
|
||||
|
||||
Reference in New Issue
Block a user