Files
mip/Modules/mip_security.pck
hardya b736bb6136 Modules:
Added cout_assert.pck - provides assertion utilities.
Added cout_err.pck - 'standard' error logging utilities.
Added gen_mandatory.prc - generates packages to provided mandatory field checks.

Schema:
Changed primary key of ENQUIRIES to an ID (also made sequence ENQU_SEQ available).
Changes ENQUIRIES.CONSUMER_NAME to FIRST_CONTACT_NAME.
Added tables DATA_ITEMS and DATA_ITEM_ROLES to support Modules/gen_mandatory.prc.

git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2865 248e525c-4dfb-0310-94bc-949c084e9493
2007-11-16 16:43:58 +00:00

247 lines
8.1 KiB
Plaintext

CREATE OR REPLACE PACKAGE mip_security AS
--PROCEDURE add_user(p_username IN VARCHAR2, p_password IN VARCHAR2);
FUNCTION get_user_status(p_username IN VARCHAR2) RETURN VARCHAR2;
PROCEDURE login(p_uname IN VARCHAR2,
p_password IN VARCHAR2,
p_session_id IN VARCHAR2,
p_flow_page IN VARCHAR2);
FUNCTION get_hash(p_username IN VARCHAR2, p_password IN VARCHAR2)
RETURN VARCHAR2;
PROCEDURE valid_user2(p_username IN VARCHAR2, p_password IN VARCHAR2);
FUNCTION valid_user(p_username IN VARCHAR2, p_password IN VARCHAR2)
RETURN BOOLEAN;
FUNCTION user_screen(p_username IN VARCHAR2) RETURN BOOLEAN;
FUNCTION admin_screen(p_username IN VARCHAR2) RETURN BOOLEAN;
-- check to see whether the username has a role that allows
-- access to the given page and, optionally, the given item
--
-- absence of the page or item from the access controls table
-- infers that access to the page and item is always allowed
FUNCTION access_allowed(p_username IN VARCHAR2,
p_page_number IN NUMBER,
p_item_name IN VARCHAR2 DEFAULT NULL)
RETURN BOOLEAN;
PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2);
END mip_security;
/
CREATE OR REPLACE PACKAGE BODY mip_security AS
/*
returns the current status of the user
*/
FUNCTION get_user_status(p_username IN VARCHAR2) RETURN VARCHAR2 AS
l_status VARCHAR2(10);
BEGIN
SELECT p.status
INTO l_status
FROM parties p
WHERE upper(p.username) = upper(p_username);
RETURN l_status;
EXCEPTION
WHEN no_data_found THEN
raise_application_error(-20000, 'User not found in the system');
--
END get_user_status;
--
/*
logs the user into the system and registers with APEX.
*/
PROCEDURE login(p_uname IN VARCHAR2,
p_password IN VARCHAR2,
p_session_id IN VARCHAR2,
p_flow_page IN VARCHAR2) IS
BEGIN
IF get_user_status(p_uname) = 'OPEN' THEN
wwv_flow_custom_auth_std.login(p_uname => p_uname,
p_password => p_password,
p_session_id => p_session_id,
p_flow_page => p_flow_page);
ELSIF get_user_status(p_uname) = 'EXPIRED' THEN
-- we need to update the password
wwv_flow_custom_auth_std.login(p_uname => p_uname,
p_password => p_password,
p_session_id => p_session_id,
p_flow_page => v('APP_ID') || ':102');
ELSE -- user password has been locked. Log them off and tell them
wwv_flow_custom_auth_std.login(p_uname => p_uname,
p_password => p_password,
p_session_id => p_session_id,
p_flow_page => v('APP_ID') || ':500:&NOTIFICATION_MESSAGE=User account has expired, please contact the system administrator.');
END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE;
END login;
/*
gets the has value of the password for storing in the database.
--*/
FUNCTION get_hash(p_username IN VARCHAR2, p_password IN VARCHAR2)
RETURN VARCHAR2 AS
BEGIN
RETURN dbms_obfuscation_toolkit.md5(input_string => upper(p_username) || '/' ||
p_password);
END get_hash;
/*
updates
MM - 22-Oct-2007
changed the table to use to be the MIP parties table
*/
PROCEDURE valid_user2(p_username IN VARCHAR2, p_password IN VARCHAR2) 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
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 = get_hash(p_username
,p_password);
EXCEPTION
WHEN no_data_found THEN
raise_application_error(-20000, 'Invalid username / password.');
END valid_user2;
FUNCTION valid_user(p_username IN VARCHAR2, p_password IN VARCHAR2)
RETURN BOOLEAN AS
BEGIN
valid_user2(p_username, p_password);
RETURN TRUE;
EXCEPTION
WHEN OTHERS THEN
RETURN FALSE;
END valid_user;
FUNCTION access_allowed(p_username IN VARCHAR2,
p_page_number IN NUMBER,
p_item_name IN VARCHAR2 DEFAULT NULL)
RETURN BOOLEAN IS
l_access_allowed VARCHAR2(3);
BEGIN
-- check to see whether the username has a role that allows
-- access to the given page and, optionally, the given item
--
-- if null is returned from the query, it implies that there
-- is no access control against the given page and item
IF p_page_number IN (101, 102, 500) THEN
RETURN TRUE;
END IF;
SELECT access_allowed
INTO l_access_allowed
FROM (SELECT accl.page_number,
accl.rt_code,
parl.rt_code,
CASE
WHEN accl.rt_code IS NULL THEN
'YES'
WHEN accl.rt_code = parl.rt_code THEN
'YES'
ELSE
'NO'
END access_allowed
FROM (SELECT prty.username, rt_code
FROM parties prty, party_roles parl
WHERE parl.prty_id = prty.id
AND upper(prty.username) = upper(p_username)) parl,
access_controls accl
WHERE accl.rt_code = parl.rt_code(+)
AND accl.page_number = p_page_number
AND (upper(nvl(accl.item, 'NOCONTROL')) =
upper(nvl(p_item_name, nvl(accl.item, 'NOCONTROL'))))
ORDER BY parl.rt_code)
WHERE rownum < 2;
IF nvl(l_access_allowed, 'YES') = 'YES' THEN
RETURN TRUE;
ELSE
RETURN FALSE;
END IF;
EXCEPTION
WHEN no_data_found THEN
raise_application_error(-20000,
'Application Error: Item Name ' ||
p_item_name || ' for page ' || p_page_number ||
' is missing from the ACCESS_CONTROLS table');
END access_allowed;
FUNCTION user_screen(p_username IN VARCHAR2) RETURN BOOLEAN AS
v_dummy VARCHAR2(1);
BEGIN
SELECT '1'
INTO v_dummy
FROM parties au
WHERE upper(username) = upper(p_username);
--AND upper(au.role) IN ('ADMIN', 'USER');
RETURN TRUE;
EXCEPTION
WHEN OTHERS THEN
RETURN FALSE;
END user_screen;
FUNCTION admin_screen(p_username IN VARCHAR2) RETURN BOOLEAN AS
v_dummy VARCHAR2(1);
BEGIN
SELECT '1'
INTO v_dummy
FROM parties au
WHERE upper(username) = upper(p_username);
--AND upper(au.role) = 'ADMIN';
RETURN TRUE;
EXCEPTION
WHEN OTHERS THEN
RETURN FALSE;
END admin_screen;
--
/*
creates a new password
*/
PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2) IS
l_prty_id NUMBER;
--sql_str VARCHAR2(250) := '';
BEGIN
SELECT id
INTO l_prty_id
FROM parties
WHERE upper(username) = upper(p_username);
INSERT INTO passwords(prty_id, password_hash, created_on, created_by)
VALUES (l_prty_id, get_hash(p_username, p_password), SYSDATE, NULL);
-- now we ned to update the user's status to OPEN
UPDATE parties
SET status = 'OPEN'
WHERE id = l_prty_id;
EXCEPTION
WHEN OTHERS THEN
raise_application_error(-20002, SQLERRM);
END new_password;
END mip_security;
/