CREATE OR REPLACE PACKAGE mip_security AS /** Handle authentication and authorization processes for the MIP project */ /** 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); /** Generate a hash from the given username and password The system does not record users passwords 'in the plain', instead we recordThe resultant hash is recorded as the username 'password hash' */ FUNCTION get_hash(p_username IN VARCHAR2 ,p_password IN VARCHAR2) RETURN VARCHAR2; /** %obs private function */ PROCEDURE valid_user2(p_username IN VARCHAR2 ,p_password IN VARCHAR2); /** %obs replaced by authenticate_user */ 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; 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); -- FUNCTION get_user_status(p_username IN VARCHAR2) RETURN 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 %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; END mip_security; / CREATE OR REPLACE PACKAGE BODY mip_security AS PROCEDURE pl(p_in VARCHAR2 ,p_line IN NUMBER DEFAULT NULL) IS BEGIN $IF mip_debug_constants.debugging OR mip_debug_constants.security $THEN mip_debug.pl(p_unit => $$PLSQL_UNIT ,p_line => p_line ,p_in => p_in); $END NULL; END pl; /* 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; -- /** Updates the user status */ PROCEDURE set_user_status(p_username IN VARCHAR2 ,p_status IN VARCHAR2) IS BEGIN UPDATE parties prty SET prty.status = upper(p_status) WHERE upper(prty.username) = upper(p_username); END; PROCEDURE update_status_on_login(p_uname IN VARCHAR2 ,p_password IN VARCHAR2) IS l_password_days NUMBER; l_password_created_on DATE; BEGIN -- check that the account is still valid (password etc.). l_password_created_on := mip_parties.get_user_password_created(p_uname ,p_password); -- l_password_days := to_date(SYSDATE ,'dd/mm/rrrr') - to_date(l_password_created_on ,'dd/mm/rrrr'); -- check the user's password/account has not expired IF NOT l_password_days < to_number(cout_system_configuration.get_configuration_item(p_parameter => 'USER_ACCOUNT_LOCK')) THEN -- user account has expired, set the user account to locked and continue on our journey set_user_status(p_username => p_uname ,p_status => 'LOCKED'); ELSIF NOT l_password_days < to_number(cout_system_configuration.get_configuration_item(p_parameter => 'PASSWORD_EXPIRY_LIMIT')) THEN -- user password has expired, set the user account to expired and continue on our journey set_user_status(p_username => p_uname ,p_status => 'EXPIRED'); END IF; -- EXCEPTION WHEN no_data_found THEN NULL; -- no password/user exists to update the status of. END update_status_on_login; -- /** 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 pl('login:entry:' || p_uname || ':' || p_session_id || ':' || p_flow_page ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('PLSQL_GATEWAY') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('GATEWAY_IVERSION') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('SERVER_SOFTWARE') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('GATEWAY_INTERFACE') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('SERVER_PORT') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('SERVER_NAME') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('REQUEST_METHOD') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('PATH_INFO') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('SCRIPT_NAME') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('REMOTE_ADDR') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('SERVER_PROTOCOL') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('REQUEST_PROTOCOL') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('REMOTE_USER') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_USER_AGENT') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_HOST') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_ACCEPT') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_ACCEPT_ENCODING') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_ACCEPT_LANGUAGE') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_ACCEPT_CHARSET') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_ORACLE_ECID') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_AUTHORIZATION') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('WEB_AUTHENT_PREFIX') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('DAD_NAME') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('DOC_ACCESS_PATH') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('DOCUMENT_TABLE') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('PATH_ALIAS') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('REQUEST_CHARSET') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('REQUEST_IANA_CHARSET') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('SCRIPT_PREFIX') ,$$PLSQL_LINE); pl(owa_util.get_cgi_env('HTTP_COOKIE') ,$$PLSQL_LINE); -- check that the account is still valid (password etc.). update_status_on_login(p_uname ,p_password); -- IF get_user_status(p_uname) = 'OPEN' THEN pl('login:exit:OPEN' ,$$PLSQL_LINE); -- 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 pl('login:exit:EXPIRED' ,$$PLSQL_LINE); -- 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 pl('login:exit:LOGOUT' ,$$PLSQL_LINE); -- 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; pl('login:exit:UNEXPECTED'); END login; /** 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; /** 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 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); RETURN TRUE; EXCEPTION WHEN no_data_found THEN 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; /** 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 htp.bold('YOU SENT ME :' || p_username || ':' || p_password); valid_user2(p_username ,p_password); RETURN TRUE; EXCEPTION WHEN OTHERS THEN RETURN FALSE; END valid_user; /** 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 -- -- 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; -- added block around this to catch no data. BEGIN SELECT access_allowed INTO l_access_allowed FROM (SELECT auth.component_name ,auth.rt_code ,parl.rt_code ,CASE WHEN auth.rt_code IS NULL THEN 'YES' 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 WHERE parl.prty_id = prty.id 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 ,'NO') = 'YES' THEN RETURN TRUE; ELSE RETURN FALSE; END IF; EXCEPTION WHEN no_data_found THEN RETURN FALSE; END; END authorization; /** Checks for authorization to access the given page 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); 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 need 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 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 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; /