Whenever you change the email address of a HR Employee record you will notice that this change in the email address is not reflected within the user account. For example for the below employee I changed the email address through a correction update in HR.
On the account of this user to which the HR Employee record is assigned this change is not reflected.
In other words the email address assigned to the user and to the related employee do not match. This will generate problems with workflow notifications if they are being sent through the Workflow Notification Mailer.
Currently there is no direct update functionality from HR to the FND_USER table. Oracle will only execute an update to the WF_LOCAL_ROLES table from the APPLSYS schema (for future assignments of the employee to a user). Also after running concurrent program Workflow Directory Services User/Role Validation only the WF_LOCAL_ROLES table is updated and not FND_USER.
SELECT
*
FROM
APPLSYS.WF_LOCAL_ROLES
WHERE
ORIG_SYSTEM = 'PER'
AND PARENT_ORIG_SYSTEM_ID = <person_id_hr>
Enhancement requests are logged to have this feature as it is crucial for correct Workflow behaviour.
Only remedy for now is to schedule a SQL update to keep the email addresses between HR and the user in sync. Find below the procedure needed to keep things in sync and to avoid Workflow notification problems. Incorporate this in your custom package.
PROCEDURE p_update_email (p_success OUT BOOLEAN)
IS
CURSOR c_user_email IS
SELECT fu.email_address user_email
,pap.email_address emp_email
,pap.person_id emp_person_id
FROM fnd_user fu
,per_all_people_f pap
WHERE fu.employee_id = pap.person_id
AND fu.email_address <> pap.email_address;
r_user_email c_user_email%ROWTYPE;
BEGIN
p_success := FALSE;
IF c_user_email%ISOPEN
THEN
CLOSE c_user_email;
END IF;
OPEN c_user_email;
FETCH c_user_email INTO r_user_email;
IF r_user_email.user_email <> r_user_email.emp_email THEN
UPDATE fnd_user SET email_address = r_user_email.emp_email
WHERE employee_id = r_user_email.emp_person_id;
COMMIT;
p_success := TRUE;
ELSE
p_success := FALSE;
END IF;
CLOSE c_user_email;
EXCEPTION
WHEN OTHERS
THEN
p_success := FALSE;
END p_update_email;
Also a direct update can be done on table FND_USER for user records where email addresses are not synced. Fire below update against your instance for an immediate synchronization between APPLSYS.FND_USER and HR.PER_ALL_PEOPLE_F.
UPDATE APPLSYS.FND_USER FUSER
SET FUSER.EMAIL_ADDRESS = (
SELECT
PAP.EMAIL_ADDRESS
FROM
HR.PER_ALL_PEOPLE_F PAP
WHERE
FUSER.EMPLOYEE_ID = PAP.PERSON_ID
)
WHERE EXISTS
(
SELECT
PAP.EMAIL_ADDRESS
FROM
HR.PER_ALL_PEOPLE_F PAP
WHERE
FUSER.EMPLOYEE_ID = PAP.PERSON_ID
AND FUSER.EMAIL_ADDRESS <> PAP.EMAIL_ADDRESS
);
The solution that I use is more functional and tedious , after updating user email addy in HR I go to Sysadmin , remove the HR user from account and then re-assign
Its a wok arround
Hey Richard, long time no see! Yes what you’re telling is a workaround. After removing the HR record from the user and re-adding it again EBS will derive the record from WF_LOCAL_ROLES and HR resulting in the new email to be assigned to the user record. The updates mentioned are usefull when doing mass updates in HR or, like I did for a client, when building an interface from an external HR system and creating and updating HR records through API’s. In that case it happened email adresses were updated which was also needed on the assigned user record. Nice to see you’re reading my blog 😀
1. per_all_people_f is a date tracked table so there can be multiple records for each employee, with effective start/end dates. the cursor should be modified to get only the latest.
Add to WHERE clause: AND pap.effective_end_date > SYSDATE
2. The procedure needs a FOR…LOOP; the current OPEN…FETCH will update one USER record only.
Hi Venkat, you’re right about that. For my interface date tracking the email address was not relevant as we were updating email addresses for all records despite the fact they are date tracked or not. When not doing this the changes you propose are a great addition. Thanks for that!