Added mip_regions.pck to handle postcode and region queries.
Modified mip_security.pck to have new procedures to authorize access to components and pages. Also, new procedures to authenicate users - old procedures marked as obsolete and to be removed at a later date. git-svn-id: http://locode01.ad.dom/svn/WEBMIP/trunk@2875 248e525c-4dfb-0310-94bc-949c084e9493
This commit is contained in:
@@ -1,34 +1,78 @@
|
||||
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);
|
||||
/**
|
||||
Handle authentication and authorization processes for the MIP project
|
||||
*/
|
||||
|
||||
FUNCTION get_hash(p_username IN VARCHAR2, p_password IN VARCHAR2)
|
||||
RETURN VARCHAR2;
|
||||
/** Perform user authentication and login
|
||||
An authenticated login for an expired password will result in flow to the 'Change Password'
|
||||
page.
|
||||
%param p_uname username
|
||||
%param p_password password
|
||||
%param p_session_id APEX session number
|
||||
%param p_flow_page the app:page to which flow should pass on successful authentication
|
||||
*/
|
||||
PROCEDURE login(p_uname IN VARCHAR2
|
||||
,p_password IN VARCHAR2
|
||||
,p_session_id IN VARCHAR2
|
||||
,p_flow_page IN VARCHAR2);
|
||||
|
||||
PROCEDURE valid_user2(p_username IN VARCHAR2, p_password IN VARCHAR2);
|
||||
FUNCTION get_hash(p_username IN VARCHAR2
|
||||
,p_password IN VARCHAR2) RETURN VARCHAR2;
|
||||
|
||||
FUNCTION valid_user(p_username IN VARCHAR2, p_password IN VARCHAR2)
|
||||
RETURN BOOLEAN;
|
||||
PROCEDURE valid_user2(p_username IN VARCHAR2
|
||||
,p_password IN VARCHAR2);
|
||||
|
||||
FUNCTION valid_user(p_username IN VARCHAR2
|
||||
,p_password IN VARCHAR2) RETURN BOOLEAN;
|
||||
|
||||
/** Authenticates the given username and password
|
||||
|
||||
%return TRUE for authenticated username and password combination
|
||||
%rep valid_user, valid_user2
|
||||
*/
|
||||
FUNCTION authenticate_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)
|
||||
PROCEDURE new_password(p_username IN VARCHAR2
|
||||
,p_password 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
|
||||
%param p_privilege The access privilege requested
|
||||
%return Boolean value, true for access allowed
|
||||
*/
|
||||
FUNCTION page_authorization(p_app_user IN VARCHAR2
|
||||
,p_page_id IN NUMBER
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
RETURN BOOLEAN;
|
||||
|
||||
/** Authorize access to the given component
|
||||
%param p_app_user The name of the application user
|
||||
%param p_component_name The name of the component to be accessed
|
||||
%param p_privilege The access privilege requested
|
||||
%return Boolean value, true for access allowed
|
||||
*/
|
||||
FUNCTION component_authorization(p_app_user IN VARCHAR2
|
||||
,p_component_name IN apex_authorization.component_name%TYPE
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
RETURN BOOLEAN;
|
||||
|
||||
/** Authorize access to the given region
|
||||
%param p_app_user The name of the application user
|
||||
%param p_component_name The name of the region to be accessed
|
||||
%param p_privilege The access privilege requested
|
||||
%return Boolean value, true for access allowed
|
||||
*/
|
||||
FUNCTION region_authorization(p_app_user IN VARCHAR2
|
||||
,p_component_name IN apex_authorization.component_name%TYPE
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
RETURN BOOLEAN;
|
||||
|
||||
PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2);
|
||||
END mip_security;
|
||||
/
|
||||
CREATE OR REPLACE PACKAGE BODY mip_security AS
|
||||
@@ -47,144 +91,276 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS
|
||||
RETURN l_status;
|
||||
EXCEPTION
|
||||
WHEN no_data_found THEN
|
||||
raise_application_error(-20000, 'User not found in the system');
|
||||
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
|
||||
/**
|
||||
Logs the user into the system and registers with APEX.
|
||||
|
||||
if the user account is 'OPEN', log them in and flow to the requested page
|
||||
if the user account is 'EXPIRED', log them in and flow to the 'Change Password' page
|
||||
if the user account is 'LOCKED', log the user out and flow to the 'Locked' page
|
||||
*/
|
||||
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);
|
||||
-- log in and flow to the requested page
|
||||
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.');
|
||||
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.logout(p_this_flow => v('APP_ID')
|
||||
,p_next_flow_page_sess => v('APP_ID') ||
|
||||
':501');
|
||||
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
|
||||
/** Produce a 'password hash' from the given username and password
|
||||
|
||||
Uses the dbms_obfuscation_toolkit to produce the hash.
|
||||
*/
|
||||
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
|
||||
/** Authenticates the given username and password
|
||||
|
||||
%return TRUE for authenticated username and password combination
|
||||
%rep valid_user, valid_user2
|
||||
*/
|
||||
|
||||
PROCEDURE valid_user2(p_username IN VARCHAR2, p_password IN VARCHAR2) AS
|
||||
FUNCTION authenticate_user(p_username IN VARCHAR2
|
||||
,p_password IN VARCHAR2) RETURN BOOLEAN AS
|
||||
l_password_created_on DATE;
|
||||
BEGIN
|
||||
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);
|
||||
|
||||
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);
|
||||
|
||||
RETURN TRUE;
|
||||
EXCEPTION
|
||||
WHEN no_data_found THEN
|
||||
raise_application_error(-20000, 'Invalid username / password.');
|
||||
RETURN FALSE;
|
||||
END authenticate_user;
|
||||
|
||||
/** Authenticates the given p_username and p_password
|
||||
|
||||
Checks the {%link passwords} table for a hash value matching that produced from the
|
||||
given p_username and p_password.
|
||||
|
||||
%raises -20000 when unable to authenticate
|
||||
%obs Replaced by authenticate_user
|
||||
*/
|
||||
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
|
||||
/** Authenticates the given username and password
|
||||
|
||||
%obs Replaced by authenticate_user
|
||||
*/
|
||||
FUNCTION valid_user(p_username IN VARCHAR2
|
||||
,p_password IN VARCHAR2) RETURN BOOLEAN AS
|
||||
BEGIN
|
||||
valid_user2(p_username, p_password);
|
||||
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)
|
||||
/** Checks for authorization to access the given component
|
||||
|
||||
%param p_app_user username
|
||||
%param p_component_name name of the component to be accessed
|
||||
%param p_component_type the type of component to be accessed
|
||||
%param p_privilege the access privilege being sought
|
||||
%return TRUE if the given p_app_user is authorized
|
||||
|
||||
Checks the roles assigned to the given p_app_user to see whether they are authorized
|
||||
to access the given component.
|
||||
|
||||
If configuration item APEX_AUTHORIZATION_DEFAULT_MODE = PUBLIC, all components
|
||||
are considered to be accessible to all unless specifically listed in the
|
||||
apex_authorization table. Otherwise, the requested access must be listed in the
|
||||
apex_authorization table.
|
||||
*/
|
||||
FUNCTION authorization(p_app_user IN VARCHAR2
|
||||
,p_component_name IN apex_authorization.component_name%TYPE
|
||||
,p_component_type IN apex_authorization.component_type%TYPE
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
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;
|
||||
--
|
||||
-- for development purposes, assume that all components are unprotected unless they are
|
||||
-- specifically recorded in the authorization table
|
||||
--
|
||||
IF cout_system_configuration.get_configuration_item('APEX_AUTHORIZATION_DEFAULT_MODE') =
|
||||
'PUBLIC' THEN
|
||||
BEGIN
|
||||
SELECT 'NO'
|
||||
INTO l_access_allowed
|
||||
FROM apex_authorization
|
||||
WHERE component_name = p_component_name
|
||||
AND component_type = p_component_type
|
||||
AND (privilege = p_privilege OR
|
||||
privilege IS NULL AND p_privilege IS NULL)
|
||||
AND rownum < 2;
|
||||
EXCEPTION
|
||||
WHEN no_data_found THEN
|
||||
-- unprotected page
|
||||
RETURN TRUE;
|
||||
END;
|
||||
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
|
||||
FROM (SELECT auth.component_name
|
||||
,auth.rt_code
|
||||
,parl.rt_code
|
||||
,CASE
|
||||
WHEN auth.rt_code IS NULL THEN
|
||||
'YES'
|
||||
WHEN accl.rt_code = parl.rt_code THEN
|
||||
WHEN auth.rt_code = parl.rt_code THEN
|
||||
'YES'
|
||||
ELSE
|
||||
'NO'
|
||||
END access_allowed
|
||||
FROM (SELECT prty.username, rt_code
|
||||
FROM parties prty, party_roles parl
|
||||
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'))))
|
||||
AND upper(prty.username) = upper(p_app_user)) parl
|
||||
,apex_authorization auth
|
||||
WHERE (auth.privilege = p_privilege OR
|
||||
auth.privilege IS NULL AND p_privilege IS NULL)
|
||||
AND auth.rt_code = parl.rt_code(+)
|
||||
AND auth.component_name = p_component_name
|
||||
AND auth.component_type = p_component_type
|
||||
ORDER BY parl.rt_code)
|
||||
WHERE rownum < 2;
|
||||
|
||||
IF nvl(l_access_allowed, 'YES') = 'YES' THEN
|
||||
IF nvl(l_access_allowed
|
||||
,'NO') = 'YES' THEN
|
||||
RETURN TRUE;
|
||||
ELSE
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
END authorization;
|
||||
|
||||
/** Checks for authorization to access the given page
|
||||
|
||||
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;
|
||||
Calls the authorization function to perform the check
|
||||
|
||||
%param p_app_user username
|
||||
%param p_page_id page number to be accessed
|
||||
%param p_privilege the access privilege being sought
|
||||
%return TRUE if the given p_app_user is authorized
|
||||
*/
|
||||
|
||||
FUNCTION page_authorization(p_app_user IN VARCHAR2
|
||||
,p_page_id IN NUMBER
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
RETURN BOOLEAN IS
|
||||
BEGIN
|
||||
RETURN authorization(p_app_user => p_app_user
|
||||
,p_component_name => p_page_id
|
||||
,p_component_type => 'P'
|
||||
,p_privilege => p_privilege);
|
||||
END page_authorization;
|
||||
|
||||
/** Checks for authorization to access the given component
|
||||
|
||||
Calls the authorization function to perform the check
|
||||
|
||||
%param p_app_user username
|
||||
%param p_component_name name of the component to be accessed
|
||||
%param p_privilege the access privilege being sought
|
||||
%return TRUE if the given p_app_user is authorized
|
||||
*/
|
||||
FUNCTION component_authorization(p_app_user IN VARCHAR2
|
||||
,p_component_name IN apex_authorization.component_name%TYPE
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
RETURN BOOLEAN IS
|
||||
BEGIN
|
||||
|
||||
RETURN authorization(p_app_user => p_app_user
|
||||
,p_component_name => p_component_name
|
||||
,p_component_type => 'C'
|
||||
,p_privilege => p_privilege);
|
||||
END component_authorization;
|
||||
|
||||
/** Checks for authorization to access the given page
|
||||
|
||||
Calls the authorization function to perform the check
|
||||
|
||||
%param p_app_user username
|
||||
%param p_component_name name of the region to be accessed
|
||||
%param p_privilege the access privilege being sought
|
||||
%return TRUE if the given p_app_user is authorized
|
||||
*/
|
||||
FUNCTION region_authorization(p_app_user IN VARCHAR2
|
||||
,p_component_name IN apex_authorization.component_name%TYPE
|
||||
,p_privilege IN apex_authorization.privilege%TYPE DEFAULT 'A')
|
||||
RETURN BOOLEAN IS
|
||||
BEGIN
|
||||
|
||||
RETURN authorization(p_app_user => p_app_user
|
||||
,p_component_name => p_component_name
|
||||
,p_component_type => 'R'
|
||||
,p_privilege => p_privilege);
|
||||
END region_authorization;
|
||||
|
||||
FUNCTION user_screen(p_username IN VARCHAR2) RETURN BOOLEAN AS
|
||||
v_dummy VARCHAR2(1);
|
||||
@@ -216,31 +392,51 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS
|
||||
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;
|
||||
/*
|
||||
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;
|
||||
|
||||
PROCEDURE redirect_on_expired_account(p_username IN VARCHAR2) IS
|
||||
BEGIN
|
||||
IF get_user_status(p_username) = 'EXPIRED' THEN
|
||||
-- we need to update the password
|
||||
owa_util.redirect_url(curl => 'f?p=' || v('APP_ID') || ':102:' ||
|
||||
v('SESSION'));
|
||||
END IF;
|
||||
END redirect_on_expired_account;
|
||||
|
||||
END mip_security;
|
||||
/
|
||||
|
||||
Reference in New Issue
Block a user