SELECT po.profile_option_name "NAME",
decode(to_char(pov.level_id),
'10001', 'SITE',
'10002', 'APP',
'10003', 'RESP',
'10005', 'SERVER',
'10006', 'ORG',
'10004', 'USER', '???') "LEV",
decode(to_char(pov.level_id),
'10001','',
'10002', app.application_short_name,
'10003', rsp.responsibility_key,
'10005', svr.node_name,
'10006', org.name,
'10004', usr.user_name,
'???') "CONTEXT",
pov.profile_option_value "VALUE"
FROM FND_PROFILE_OPTIONS po,
FND_PROFILE_OPTION_VALUES pov,
fnd_user usr,
fnd_application app,
fnd_responsibility rsp,
fnd_nodes svr,
hr_operating_units org
WHERE 1 =1
and po.profile_option_name LIKE '&PROFILE%%'
AND pov.application_id = po.application_id
AND pov.profile_option_id = po.profile_option_id
AND usr.user_id (+) = pov.level_value
AND rsp.application_id (+) = pov.level_value_application_id
AND rsp.responsibility_id (+) = pov.level_value
AND app.application_id (+) = pov.level_value
AND svr.node_id (+) = pov.level_value
AND org.organization_id (+) = pov.level_value
/*AND decode(to_char(pov.level_id),
'10001', '',
'10002', app.application_short_name,
'10003', rsp.responsibility_key,
'10005', svr.node_name,
'10006', org.name,
'10004', usr.user_name,
'???') LIKE '&USERNAME%'*/
ORDER BY "NAME", pov.level_id, "VALUE";
----------------------------------------------------------------------------------------------------------
How to check Profile Option Values using SQL Queries
Well, there is no better place to check the Profile Options using the Profile Options Form in System Administrator responsibility. But at times, you either do not have System Administrator responsibility or you need to check and compare profile options for more than one profile or more than one responsibility at the same time. The following queries are very useful in those scenarios…
SQL Queries for checking Profile Option Values
The following queries are useful to get the profile option values of a profile option at site, application, responsibility and user level
1) Obtain Profile Option values for Profile Option name like ‘%Ledger%’ and Responsibility name like ‘%General%Ledger%’
SELECT
substr(pro1.user_profile_option_name,1,35) Profile,
decode(pov.level_id,
10001,'Site',
10002,'Application',
10003,'Resp',
10004,'User') Option_Level,
decode(pov.level_id,
10001,'Site',
10002,appl.application_short_name,
10003,resp.responsibility_name,
10004,u.user_name) Level_Value,
nvl(pov.profile_option_value,'Is Null') Profile_option_Value
FROM
fnd_profile_option_values pov,
fnd_responsibility_tl resp,
fnd_application appl,
fnd_user u,
fnd_profile_options pro,
fnd_profile_options_tl pro1
WHERE
pro1.user_profile_option_name like ('%Ledger%')
and pro.profile_option_name = pro1.profile_option_name
and pro.profile_option_id = pov.profile_option_id
and resp.responsibility_name like '%General%Ledger%' /* comment this line if you need to check profiles for all responsibilities */
and pov.level_value = resp.responsibility_id (+)
and pov.level_value = appl.application_id (+)
and pov.level_value = u.user_id (+)
order by 1,2;
|
2) Obtain all Profile Option values setup for a particular responsibility. Replace the responsibility name as per your requirement.
SELECT
substr(pro1.user_profile_option_name,1,35) Profile,
decode(pov.level_id,
10001,'Site',
10002,'Application',
10003,'Resp',
10004,'User') Option_Level,
decode(pov.level_id,
10001,'Site',
10002,appl.application_short_name,
10003,resp.responsibility_name,
10004,u.user_name) Level_Value,
nvl(pov.profile_option_value,'Is Null') Profile_option_Value
FROM
fnd_profile_option_values pov,
fnd_responsibility_tl resp,
fnd_application appl,
fnd_user u,
fnd_profile_options pro,
fnd_profile_options_tl pro1
WHERE
pro.profile_option_name = pro1.profile_option_name
and pro.profile_option_id = pov.profile_option_id
and resp.responsibility_name like '%General%Ledger%'
and pov.level_value = resp.responsibility_id (+)
and pov.level_value = appl.application_id (+)
and pov.level_value = u.user_id (+)
order by 1,2;
|
SELECT e.profile_option_name Profile,
f.user_profile_option_name User_Profile_Name, c.application_short_name,
decode(a.level_id,10001,'Site',10002,'Application',10003,'Resp',10004,'User') LevelSet_At,
decode(a.level_id,10001,'Site',10002,c.application_short_name,
10003,b.responsibility_name,10004,d.user_name) LValue,
nvl(a.profile_option_value,'Is Null') Value
FROM fnd_profile_option_values a, fnd_responsibility_tl b,
fnd_application c, fnd_user d, fnd_profile_options e, fnd_profile_options_vl f
WHERE f.user_profile_option_name like 'OM%'
AND e.profile_option_id = a.profile_option_id
AND e.profile_option_id = f.profile_option_id
AND a.level_value = b.responsibility_id (+)
AND a.level_value = c.application_id (+)
AND a.level_value = d.user_id (+)
ORDER BY 1,2;
f.user_profile_option_name User_Profile_Name, c.application_short_name,
decode(a.level_id,10001,'Site',10002,'Application',10003,'Resp',10004,'User') LevelSet_At,
decode(a.level_id,10001,'Site',10002,c.application_short_name,
10003,b.responsibility_name,10004,d.user_name) LValue,
nvl(a.profile_option_value,'Is Null') Value
FROM fnd_profile_option_values a, fnd_responsibility_tl b,
fnd_application c, fnd_user d, fnd_profile_options e, fnd_profile_options_vl f
WHERE f.user_profile_option_name like 'OM%'
AND e.profile_option_id = a.profile_option_id
AND e.profile_option_id = f.profile_option_id
AND a.level_value = b.responsibility_id (+)
AND a.level_value = c.application_id (+)
AND a.level_value = d.user_id (+)
ORDER BY 1,2;
Hey Really Thanks for sharing the best information regarding cloud application,hope you will write more great blogs. Erptree.com
ReplyDeleteayam bangkok berkualitas Info selengkapnya hubungi customer service : BBM: BOLAVITA WeChat: BOLAVITA WA: +6281377055002 Line : cs_bolavita Live Chat : www.bolavita,pw
ReplyDelete