PL/SQL Apps init and development

PL/SQL Apps init and development

While developing, once in a while, you want to execute some SQL or PL/SQL within the context of an EBS session. To be able to do that, I created a script to easily generate some initialization code for handling this issue. Beware, the script below assumes that it is run for the NL language. If you don't have that language installed, the script will definitely not work. Adjust the script to your liking and situation. For example, change the language codes to US or another language. Beware that when you change them, you will also need to enter the responsibility parameter in that language. All three parameters are case-sensitive.

set pages 9999 feedback off verify off heading off lines 20000 long 20000
accept v_user_name             CHAR PROMPT '-- username       : ' DEFAULT 'SYSADMIN'
accept v_responsibility_name   CHAR PROMPT '-- responsibility : ' DEFAULT 'Systeembeheerder'
accept v_session_language_code CHAR PROMPT '-- language (NL)  : ' DEFAULT 'NL'
COL scriptje FOR A100

select scriptje
  from (select 'begin' scriptje, 0 volgorde                                                             from dual union
        select '  INSERT INTO fnd_sessions SELECT USERENV(''sessionid''),TRUNC( SYSDATE )', 11          from dual union
        select '    FROM DUAL WHERE NOT EXISTS (SELECT NULL FROM fnd_sessions ', 12                     from dual union
        select '    WHERE session_id = USERENV(''sessionid''));', 13                                    from dual union
        select '  fnd_global.apps_initialize' || chr(13) || chr(10) || '    ( user_id           => ' || user_id ||
               chr(13) || chr(10) || '    , resp_id           => ' || responsibility_id || chr(13) || chr(10) ||
               '    , resp_appl_id      => ' || application_id || chr(13) || chr(10) || '    , security_group_id => 0);',
               14
          from fnd_responsibility_tl, fnd_user
         where responsibility_name = '&v_responsibility_name'
           and language = 'NL'
           and user_name = '&v_user_name'
        union
        select '  fnd_client_info.setup_client_info' || chr(13) || chr(10) || '    ( application_id    => ' ||
               application_id || chr(13) || chr(10) || '    , responsibility_id => ' || responsibility_id || chr(13) ||
               chr(10) || '    , user_id           => ' || user_id || chr(13) || chr(10) ||
               '    , security_group_id => 0);',
               15
          from fnd_responsibility_tl, fnd_user
         where responsibility_name = '&&v_responsibility_name'
           and language = 'NL'
           and user_name = '&&v_user_name'
        union
        select '  mo_global.init' || '(p_appl_short_name => ''' || application_short_name || '''' || ');', 16
          from fnd_responsibility_tl resp, fnd_user, fnd_application app
         where responsibility_name = '&&v_responsibility_name'
           and language = 'NL'
           and user_name = '&&v_user_name'
           and app.application_id = resp.application_id
           and exists (select 1 from fnd_mo_product_init where application_short_name = app.application_short_name)
        union
        select '  fnd_global.set_nls_context(p_nls_language => ''' || nls_language || ''');', 1005
          from fnd_languages
         where installed_flag != 'D'
           and language_code = nvl('&v_session_language_code', 'NL')
        union
        select 'end;', 1010                                                                             from dual union
        select '/', 1011          from dual)
 order by volgorde
/
set feedback on verify on heading on

When you run that script you generate a new script that sets the session to the context chosen.

It generates something like:

-- username       :
-- responsibility :
-- language (NL)  :

begin
  INSERT INTO fnd_sessions SELECT USERENV('sessionid'),TRUNC( SYSDATE )
    FROM DUAL WHERE NOT EXISTS (SELECT NULL FROM fnd_sessions
    WHERE session_id = USERENV('sessionid'));
  fnd_global.apps_initialize
    ( user_id           => 0
    , resp_id           => 20420
    , resp_appl_id      => 1
    , security_group_id => 0);

  fnd_client_info.setup_client_info
    ( application_id    => 1
    , responsibility_id => 20420
    , user_id           => 0
    , security_group_id => 0);

  fnd_global.set_nls_context(p_nls_language => 'DUTCH');
end;
/

Once the generated script is run, you can check the basics of the EBS context with below query.

select fnd_global.user_name, fnd_global.resp_name
from dual
/

Did you find this article valuable?

Support Oracle EBS R12 by becoming a sponsor. Any amount is appreciated!