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:
hardya
2007-11-21 17:03:01 +00:00
parent c4f1d2027d
commit ef78cea95d
3 changed files with 500 additions and 130 deletions

View File

@@ -7,6 +7,7 @@ set define off
@@mip_parties.pck @@mip_parties.pck
@@mip_mandatory.pck @@mip_mandatory.pck
@@mip_enquiry.pck @@mip_enquiry.pck
@@mip_regions.pck
@@cout_assert.pck @@cout_assert.pck
@@cout_err.pck @@cout_err.pck

173
Modules/mip_regions.pck Normal file
View File

@@ -0,0 +1,173 @@
CREATE OR REPLACE PACKAGE mip_regions IS
-- Author : HARDYA
-- Created : 20/11/2007 14:18:26
-- Purpose :
/** Attempts to validate that the format of the given string matches a standard postcode format
This includes the general format of the string, plus any restrictions on character values within
the overall format.
%param p_string the string whose format is to be checked
%return TRUE if the given string matches a known postcode format
*/
FUNCTION valid_postcode_format(p_postcode IN VARCHAR2) RETURN BOOLEAN;
END mip_regions;
/
CREATE OR REPLACE PACKAGE BODY mip_regions IS
/** Attempts to determine whether general the format the given string to match a standard postcode format
%param p_string the string whose format is to be checked
%return a known postcode format or NULL if the string did not match a known postcode format
{*} ANbNAA e.g. M1 1AA
{*} ANNbNAA e.g. M60 1NW
{*} AANbNAA e.g. CR2 6XH
{*} AANNbNAA e.g. DN55 1PT
{*} ANAbNAA e.g. W1A 1HP
{*} AANAbNAA e.g. EC1A 1BB
*/
FUNCTION reformat_postcode_string(p_string IN VARCHAR2) RETURN VARCHAR2 IS
l_return VARCHAR2(8);
BEGIN
IF regexp_like(srcstr => p_string
,pattern => '^[[:upper:]][[:digit:]]} [[:digit:]][[:upper:]]{2}$') THEN
l_return := 'AN NAA';
ELSIF regexp_like(srcstr => p_string
,pattern => '^[[:upper:]][[:digit:]]{2} [[:digit:]][[:upper:]]{2}$') THEN
l_return := 'ANN NAA';
ELSIF regexp_like(srcstr => p_string
,pattern => '^[[:upper:]]{2}[[:digit:]] [[:digit:]][[:upper:]]{2}$') THEN
l_return := 'AAN NAA';
ELSIF regexp_like(srcstr => p_string
,pattern => '^[[:upper:]]{2}[[:digit:]]{2} [[:digit:]][[:upper:]]{2}$') THEN
l_return := 'AANN NAA';
ELSIF regexp_like(srcstr => p_string
,pattern => '^[[:upper:]][[:digit:]][[:upper:]] [[:digit:]][[:upper:]]{2}$') THEN
l_return := 'ANA NAA';
ELSIF regexp_like(srcstr => p_string
,pattern => '^[[:upper:]]{2}[[:digit:]][[:upper:]] [[:digit:]][[:upper:]]{2}$') THEN
l_return := 'AANA NAA';
END IF;
RETURN l_return;
END reformat_postcode_string;
/** Attempts to validate that the format of the given string matches a standard postcode format
This includes the general format of the string, plus any restrictions on character values within
the overall format.
%param p_string the string whose format is to be checked
%return TRUE if the given string matches a known postcode format
*/
FUNCTION valid_postcode_format(p_postcode IN VARCHAR2) RETURN BOOLEAN IS
l_return BOOLEAN := TRUE;
l_postcode_format VARCHAR2(8);
BEGIN
IF p_postcode = 'GIR 0AA' THEN
l_return := TRUE;
ELSIF length(p_postcode) NOT IN (6
,7
,8) THEN
l_return := FALSE;
ELSE
l_postcode_format := reformat_postcode_string(p_postcode);
IF l_postcode_format IS NULL THEN
l_return := FALSE;
ELSE
IF instr('QVX'
,substr(p_postcode
,1
,1)) > 0 THEN
l_return := FALSE;
ELSIF substr(l_postcode_format
,2
,1) = 'A'
AND instr('IJZ'
,substr(p_postcode
,2
,1)) > 0 THEN
l_return := FALSE;
ELSIF substr(l_postcode_format
,3
,1) = 'A'
AND instr('ABCDEFGHJKSTUW'
,substr(p_postcode
,3
,1)) = 0 THEN
l_return := FALSE;
ELSIF substr(l_postcode_format
,4
,1) = 'A'
AND instr('ABCDEFGHJKSTUW'
,substr(p_postcode
,4
,1)) = 0 THEN
l_return := FALSE;
ELSE
-- letters CIKMOV are not used in the second part of the postcode
FOR l_idx IN instr(l_postcode_format
,' ') .. length(l_postcode_format) LOOP
IF substr(l_postcode_format
,l_idx
,1) = 'A'
AND instr('CIKMOV'
,substr(p_postcode
,l_idx
,1)) > 0 THEN
l_return := FALSE;
END IF;
END LOOP;
END IF;
END IF;
END IF;
RETURN l_return;
END valid_postcode_format;
/** Find the region with which the given postcode is associated
%param p_postcode correctly formatted postcode
%return region code
*/
FUNCTION get_region_for_postcode(p_postcode IN VARCHAR2)
RETURN postcodes.regi_code%TYPE IS
l_regi_code postcodes.regi_code%TYPE;
BEGIN
SELECT regi_code
INTO l_regi_code
FROM (SELECT regi_code
,outcode
,incode
,decode(outcode || ' ' || incode
,p_postcode
,1
,999) AS accuracy
FROM postcodes t
WHERE (outcode || ' ' || incode = p_postcode)
OR (outcode = substr(p_postcode
,1
,instr(p_postcode
,' ') - 1) AND incode IS NULL)
ORDER BY 4)
WHERE rownum < 2;
RETURN l_regi_code;
EXCEPTION
WHEN no_data_found THEN
RETURN NULL;
END get_region_for_postcode;
BEGIN
-- Initialization
NULL;
END mip_regions;
/

View File

@@ -1,34 +1,78 @@
CREATE OR REPLACE PACKAGE mip_security AS 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; Handle authentication and authorization processes for the MIP project
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) /** Perform user authentication and login
RETURN VARCHAR2; 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) PROCEDURE valid_user2(p_username IN VARCHAR2
RETURN BOOLEAN; ,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 user_screen(p_username IN VARCHAR2) RETURN BOOLEAN;
FUNCTION admin_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 PROCEDURE new_password(p_username IN VARCHAR2
-- access to the given page and, optionally, the given item ,p_password IN VARCHAR2);
--
-- absence of the page or item from the access controls table /** Authorize access to the given page
-- infers that access to the page and item is always allowed %param p_app_user The name of the application user
FUNCTION access_allowed(p_username IN VARCHAR2, %param p_page_id The page to be accessed
p_page_number IN NUMBER, %param p_privilege The access privilege requested
p_item_name IN VARCHAR2 DEFAULT NULL) %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; RETURN BOOLEAN;
PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2);
END mip_security; END mip_security;
/ /
CREATE OR REPLACE PACKAGE BODY mip_security AS CREATE OR REPLACE PACKAGE BODY mip_security AS
@@ -47,144 +91,276 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS
RETURN l_status; RETURN l_status;
EXCEPTION EXCEPTION
WHEN no_data_found THEN 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; END get_user_status;
-- --
/* /**
logs the user into the system and registers with APEX. Logs the user into the system and registers with APEX.
*/
PROCEDURE login(p_uname IN VARCHAR2, if the user account is 'OPEN', log them in and flow to the requested page
p_password IN VARCHAR2, if the user account is 'EXPIRED', log them in and flow to the 'Change Password' page
p_session_id IN VARCHAR2, if the user account is 'LOCKED', log the user out and flow to the 'Locked' page
p_flow_page IN VARCHAR2) IS */
PROCEDURE login(p_uname IN VARCHAR2
,p_password IN VARCHAR2
,p_session_id IN VARCHAR2
,p_flow_page IN VARCHAR2) IS
BEGIN BEGIN
IF get_user_status(p_uname) = 'OPEN' THEN IF get_user_status(p_uname) = 'OPEN' THEN
wwv_flow_custom_auth_std.login(p_uname => p_uname, -- log in and flow to the requested page
p_password => p_password, wwv_flow_custom_auth_std.login(p_uname => p_uname
p_session_id => p_session_id, ,p_password => p_password
p_flow_page => p_flow_page); ,p_session_id => p_session_id
,p_flow_page => p_flow_page);
ELSIF get_user_status(p_uname) = 'EXPIRED' THEN ELSIF get_user_status(p_uname) = 'EXPIRED' THEN
-- we need to update the password -- we need to update the password
wwv_flow_custom_auth_std.login(p_uname => p_uname, wwv_flow_custom_auth_std.login(p_uname => p_uname
p_password => p_password, ,p_password => p_password
p_session_id => p_session_id, ,p_session_id => p_session_id
p_flow_page => v('APP_ID') || ':102'); ,p_flow_page => v('APP_ID') || ':102');
ELSE -- user password has been locked. Log them off and tell them ELSE
wwv_flow_custom_auth_std.login(p_uname => p_uname, -- user password has been locked. Log them off and tell them
p_password => p_password, wwv_flow_custom_auth_std.logout(p_this_flow => v('APP_ID')
p_session_id => p_session_id, ,p_next_flow_page_sess => v('APP_ID') ||
p_flow_page => v('APP_ID') || ':500:&NOTIFICATION_MESSAGE=User account has expired, please contact the system administrator.'); ':501');
END IF; END IF;
EXCEPTION
WHEN OTHERS THEN
RAISE;
END login; END login;
/* /** Produce a 'password hash' from the given username and password
gets the has value of the password for storing in the database.
--*/ Uses the dbms_obfuscation_toolkit to produce the hash.
FUNCTION get_hash(p_username IN VARCHAR2, p_password IN VARCHAR2) */
RETURN VARCHAR2 AS FUNCTION get_hash(p_username IN VARCHAR2
,p_password IN VARCHAR2) RETURN VARCHAR2 AS
BEGIN BEGIN
RETURN dbms_obfuscation_toolkit.md5(input_string => upper(p_username) || '/' || RETURN dbms_obfuscation_toolkit.md5(input_string => upper(p_username) || '/' ||
p_password); p_password);
END get_hash; END get_hash;
/* /** Authenticates the given username and password
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 %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; l_password_created_on DATE;
BEGIN BEGIN
SELECT created_on SELECT created_on
INTO l_password_created_on INTO l_password_created_on
FROM (SELECT pwd.prty_id FROM (SELECT pwd.prty_id
,pwd.password_hash ,pwd.password_hash
,MAX(pwd.created_on) over(PARTITION BY pwd.prty_id) AS latest_pwd_date ,MAX(pwd.created_on) over(PARTITION BY pwd.prty_id) AS latest_pwd_date
,pwd.created_on ,pwd.created_on
FROM passwords pwd FROM passwords pwd
,parties prty ,parties prty
WHERE upper(prty.username) = upper(p_username) WHERE upper(prty.username) = upper(p_username)
AND pwd.prty_id = prty.id) pwd AND pwd.prty_id = prty.id) pwd
WHERE pwd.created_on = pwd.latest_pwd_date WHERE pwd.created_on = pwd.latest_pwd_date
AND pwd.password_hash = get_hash(p_username AND pwd.password_hash = get_hash(p_username
,p_password); ,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 EXCEPTION
WHEN no_data_found THEN WHEN no_data_found THEN
raise_application_error(-20000, 'Invalid username / password.'); raise_application_error(-20000
,'Invalid username / password.');
END valid_user2; END valid_user2;
FUNCTION valid_user(p_username IN VARCHAR2, p_password IN VARCHAR2) /** Authenticates the given username and password
RETURN BOOLEAN AS
%obs Replaced by authenticate_user
*/
FUNCTION valid_user(p_username IN VARCHAR2
,p_password IN VARCHAR2) RETURN BOOLEAN AS
BEGIN BEGIN
valid_user2(p_username, p_password); valid_user2(p_username
,p_password);
RETURN TRUE; RETURN TRUE;
EXCEPTION EXCEPTION
WHEN OTHERS THEN WHEN OTHERS THEN
RETURN FALSE; RETURN FALSE;
END valid_user; END valid_user;
FUNCTION access_allowed(p_username IN VARCHAR2, /** Checks for authorization to access the given component
p_page_number IN NUMBER,
p_item_name IN VARCHAR2 DEFAULT NULL) %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 RETURN BOOLEAN IS
l_access_allowed VARCHAR2(3); l_access_allowed VARCHAR2(3);
BEGIN 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; END IF;
SELECT access_allowed SELECT access_allowed
INTO l_access_allowed INTO l_access_allowed
FROM (SELECT accl.page_number, FROM (SELECT auth.component_name
accl.rt_code, ,auth.rt_code
parl.rt_code, ,parl.rt_code
CASE ,CASE
WHEN accl.rt_code IS NULL THEN WHEN auth.rt_code IS NULL THEN
'YES' 'YES'
WHEN accl.rt_code = parl.rt_code THEN WHEN auth.rt_code = parl.rt_code THEN
'YES' 'YES'
ELSE ELSE
'NO' 'NO'
END access_allowed END access_allowed
FROM (SELECT prty.username, rt_code FROM (SELECT prty.username
FROM parties prty, party_roles parl ,rt_code
FROM parties prty
,party_roles parl
WHERE parl.prty_id = prty.id WHERE parl.prty_id = prty.id
AND upper(prty.username) = upper(p_username)) parl, AND upper(prty.username) = upper(p_app_user)) parl
access_controls accl ,apex_authorization auth
WHERE accl.rt_code = parl.rt_code(+) WHERE (auth.privilege = p_privilege OR
AND accl.page_number = p_page_number auth.privilege IS NULL AND p_privilege IS NULL)
AND (upper(nvl(accl.item, 'NOCONTROL')) = AND auth.rt_code = parl.rt_code(+)
upper(nvl(p_item_name, nvl(accl.item, 'NOCONTROL')))) AND auth.component_name = p_component_name
AND auth.component_type = p_component_type
ORDER BY parl.rt_code) ORDER BY parl.rt_code)
WHERE rownum < 2; WHERE rownum < 2;
IF nvl(l_access_allowed, 'YES') = 'YES' THEN IF nvl(l_access_allowed
,'NO') = 'YES' THEN
RETURN TRUE; RETURN TRUE;
ELSE ELSE
RETURN FALSE; RETURN FALSE;
END IF; END IF;
END authorization;
EXCEPTION /** Checks for authorization to access the given page
WHEN no_data_found THEN
raise_application_error(-20000, Calls the authorization function to perform the check
'Application Error: Item Name ' ||
p_item_name || ' for page ' || p_page_number || %param p_app_user username
' is missing from the ACCESS_CONTROLS table'); %param p_page_id page number to be accessed
END access_allowed; %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 FUNCTION user_screen(p_username IN VARCHAR2) RETURN BOOLEAN AS
v_dummy VARCHAR2(1); v_dummy VARCHAR2(1);
@@ -218,29 +394,49 @@ CREATE OR REPLACE PACKAGE BODY mip_security AS
-- --
/* /*
creates a new password creates a new password
*/ */
PROCEDURE new_password(p_username IN VARCHAR2, p_password IN VARCHAR2) IS PROCEDURE new_password(p_username IN VARCHAR2
l_prty_id NUMBER; ,p_password IN VARCHAR2) IS
--sql_str VARCHAR2(250) := ''; l_prty_id NUMBER;
BEGIN --sql_str VARCHAR2(250) := '';
SELECT id BEGIN
INTO l_prty_id SELECT id
FROM parties INTO l_prty_id
FROM parties
WHERE upper(username) = upper(p_username); WHERE upper(username) = upper(p_username);
INSERT INTO passwords(prty_id, password_hash, created_on, created_by) INSERT INTO passwords
VALUES (l_prty_id, get_hash(p_username, p_password), SYSDATE, NULL); (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 -- now we ned to update the user's status to OPEN
UPDATE parties UPDATE parties
SET status = 'OPEN' SET status = 'OPEN'
WHERE id = l_prty_id; WHERE id = l_prty_id;
EXCEPTION EXCEPTION
WHEN OTHERS THEN WHEN OTHERS THEN
raise_application_error(-20002, SQLERRM); raise_application_error(-20002
END new_password; ,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; END mip_security;
/ /