<-----Google Analytics Code Start----> <-----Google Analytics Code Close---->
Skip to content

Green

color

Default screen resolution  Wide screen resolution  Increase font size  Decrease font size  Default font size  Skip to content Default color Pink color Green color Green color

Related Items

Home arrow Technical Articles arrow Oracle Scripts arrow Read Only Schema in Oracle APPS 11i
This website has now moved to http://apps2fusion.com





Read Only Schema in Oracle APPS 11i | Print |  E-mail
Written by Anil Passi   
Saturday, 02 September 2006
In this article I have discussed how to create and maintain a read only schema for APPS in Oracle eBusiness Suite.

Whilst in the past I have known clients to implement this using synonyms. However the approach discussed below is designed without the need of having to create a single synonym in APPS_QUERYschema.

Step 1 
Create the read-only schema, in this case lets call it APPS_QUERY.

Step 2.
Surely, the schema created in above Step 1 will be given read only grants to objects in apps. There will be cases where the grant command might fail. To monitor such failures  create a table as below
conn xx_g4g/&2 ;
--For APPS_QUERY. This table will capture the exceptions during Grants
PROMPT create table XX_GRANTS_FAIL_APPS_QUERY
create table XX_GRANTS_FAIL_APPS_QUERY (
        object_name VARCHAR2(100)
       ,sqlerrm varchar2(2000)
       ,creation_date DATE
        );


grant all on XX_GRANTS_FAIL_APPS_QUERY to apps with grant option;

grant select on XX_GRANTS_FAIL_APPS_QUERY to apps_query ;

Step 3
In this step we grant select on all the existing views and synonyms in apps schema to apps_query.

conn apps/&1 ;

PROMPT This can take upto 15-30 minutes
PROMPT Granting SELECT on All synonyms and views to apps_query
DECLARE
--One off script to execute grants to apps_query
  v_error VARCHAR2(2000);
BEGIN

  FOR p_rec IN (SELECT *
                FROM   all_objects
                WHERE  owner = 'APPS'
                AND    object_type IN ('SYNONYM', 'VIEW')
                AND    object_name NOT LIKE '%_S')
  LOOP
    BEGIN
      EXECUTE IMMEDIATE 'grant select on ' || p_rec.object_name ||
                        ' to apps_query';
    EXCEPTION
      WHEN OTHERS THEN
        v_error := substr(SQLERRM, 1, 2000);
        INSERT INTO bes.XX_GRANTS_FAIL_apps_query
          (object_name
          ,SQLERRM
          ,creation_date
          )
        VALUES
          (p_rec.object_name
          ,v_error
          ,sysdate
          );
    END;
  END LOOP;
  COMMIT;
END;
/


Step 4
Write a after logon trigger on apps_query schema. The main purpose of this trigger is to alter the session to apps schema, such that the CurrentSchema will be set to apps for the session(whilst retaining apps_query restrictions).In doing so your logon will retain the permissions of apps_query schema(read_only). Howerver it will be able to reference the apps objects with exactly the same name as does a direct connection to apps schema.


conn apps/&1 ;
PROMPT CREATE OR REPLACE TRIGGER xx_apps_query_logon_trg
CREATE OR REPLACE TRIGGER xx_apps_query_logon_trg
--16Jun2006 By Anil Passi
--Trigger to toggle schema to apps, but yet retaining apps_query resitrictions
--Also sets the org_id
  AFTER logon ON apps_query.SCHEMA
DECLARE
BEGIN
  EXECUTE IMMEDIATE
          'declare begin ' ||
          'dbms_application_info.set_client_info ( 101 ); end;';
  EXECUTE IMMEDIATE 'ALTER SESSION SET CURRENT_SCHEMA =APPS';
END;
/


Step 5
Create a Trigger on the apps schema to issue select only grants for all new views and synonyms. Please note that I am excluding grants for sequences. SELECT grants for views and synonyms will be provided to apps_query as and when such objects are created in APPS. Please note that, all the APPS objects (views and synonyms) that existed in APPS schema prior to the implementation of this design, would have been granted read-only access to apps_query in Step 2.

conn apps/&1 ;
PROMPT CREATE OR REPLACE TRIGGER xx_grant_apps_query
CREATE OR REPLACE TRIGGER xx_grant_apps_query
--16Jun2006 By Anil Passi
--
  AFTER CREATE ON APPS.SCHEMA
DECLARE
  l_str VARCHAR2(255);
  l_job NUMBER;
BEGIN
  IF (ora_dict_obj_type IN ('SYNONYM', 'VIEW'))
     AND (ora_dict_obj_name NOT LIKE '%_S')
  THEN
    l_str := 'execute immediate "grant select on ' || ora_dict_obj_name ||
             ' to apps_query";';
    dbms_job.submit(l_job, REPLACE(l_str, '"', ''''));
  END IF;
END;
/



Some notes for this design

Note1 
You need to ensure that the schema created in Step 1 has very limited permissions. Most importantly it must not be given grant for “EXECUTE/CREATE ANY PROCEDURE”. You will need to agree with your DBAs upfront for the permissions,

Note 2
Only views and synonyms will be granted access. Objects in your xx_g4g(bespoke) schema should have their synonyms in apps already in place.

Note 3
If your site has multi org enabled, you will then have to set the org I'd after loggiong on to apps query schema. In case you have only one single ORG_ID, then would have been set as in Step 4 above.

Note 4
ALTER SESSION SET CURRENT_SCHEMA =APPS
This facilitates users to run their queries as if they were connected to apps schema. However, their previliges will be restricted to those of apps_query

Note 5
It is assumed that ALTER SESSION privilege will exist for APPS_QUERY schema.

Thanks,
Anil Passi

Comments (21)add
...
written by Dnyanesh , February 07, 2007
Hi Anil,
This is a excellent note on creating read only schema for Apps.
Well, I am looking for creating read only responsibility. Will you pls prepare note for this.
Thanks,
Dnyanesh
...
written by Hi Anil, , July 16, 2007
If we give select any table to new user(who needs read only access),can't it be fine ?
...
written by Anil Passi , July 16, 2007
Hi there,

In this case, we are giving select privelege to SYNONYMS and Views in APPS.
The apps schema does not contain tables.
Also, we do not wish to create thousands of synonyms, hence ALTER SESSION SET CURRENT_SCHEMA is needed too.

Thanks
Anil Passi
...
written by Pranay , August 19, 2007
'%_S' in the select statement above will not fetch any synonyms/views ending with 'S'.

The statement has to be like,

SELECT *
FROM all_objects
WHERE owner = 'APPS'
AND object_type IN ('SYNONYM', 'VIEW')
AND object_name NOT LIKE '%_S' ESCAPE '';

This would aviod getting objects ending with '_S' (which I guess would be sequences, and they are not selected in the object_type above).

- Pranay
...
written by Anil Passi , August 19, 2007
Cheers Pranay for enhancing this further.

Thanks,
Anil Passi
...
written by SRINIVAS. M , August 23, 2007
Hi Anil/Dnyanesh,
I am looking for creating read only responsibility. Will you pls prepare note for this.
Thanks,
Srinivas
...
written by Akil , August 24, 2007
Hi Anil , Oracle says that Data Group attached to responsibility helps to connect to username which is defined in Data Group as Application Oracle ID pair. So e.g Application Name => Oracle GL Oracle ID => Apps. This means if user select GL responsibility it will connect with Apps User. So can we achieve Query Only Schema with this functionality like Creating New Data Group which will be paired to Apps_Query schema . Then creating a responsibility and attached this new data group. Just a thought.
...
written by Anil Passi , August 24, 2007
Hi Akil

If you want a read only responsibility, simplest way is to implement one of the two options:-
1. For hrms responsibilities, set profile option HR:Query Only to Yes
2. For non-hrms responsibility, you can set the default value for its form functions to include parameter
QUERY_ONLY=Yes

Thanks,
Anil Passi
Create custom Application
written by ashish dubeby , October 20, 2007
hi
im new to orr-apps .can u elaborate me on.....Create custom Application.....it would be gr8 help for me.....thanx in advance...
regards
Ashish
How to put the oracle apps in query-only mode.
written by Neeladri , October 22, 2007

Hi Anil,

Just adding one thought to the point no. 2, in case of non-hrms responsibility, there would be many form functions, is there a single way to make all the forms query-only access to all users in apps? please give a suggestion on this.

Thanks,
Neeladri
More questions about oracle apps schema
written by Carlos , November 20, 2007
Hi Anil:

your doc is very useful!!! thanks in advance.

But I would like to comment another issue regarding this matter, read_only apps schema...
I working to implementing policies and procedures for SOX audit, and I need to define a specific procedure to established a emergency changes to live environment.. that is, create a mirror apps schema (apps-emer) for implement a emergency changes for a developer user if the person in charge to apply this cannot to do...

do you have any experiences about this issue, mirror apps schema?

thanks for your comments


Regards,

Carlos

ora-600 when executed trigger xx_apps_query_logon_trg
written by Carlos , November 21, 2007
Hi Anil:

I'm trying to apply your process, but when I would like to create trigger xx_apps_query_logon_trg, failed with oracle error ora-600 [17057]. This lookup error is not identified!! do you have any experience about this trouble?

Thanks!
Carlos
Oracle Apps Read Only Responsibility
written by George , November 26, 2007
Appreciate for the details about the APPS_QUERY read-only setup options for creating schema. Is there an answer or somebody ever tried this -> Create an Oracle Apps read-only responsibility with new data groups (this is linked to APPS_QUERY schema); Or what all components - objects and privilegs required to login and access standard oracle forms thru the read-only responsility attached to read-only schema data group. I know about making a readonly resp connecting to APPS schema. Appreciate your feedback.
Read only Responsibility from APPS_QUERY Schema
written by George , December 01, 2007
Has anybody tried creating Read only responsibility connecting to Read only APPS_QUERY schema? Please share your ideas.
...
written by NeoHyd , January 18, 2008
Please be aware....
Apps Read only schema is a serious security violation.
When implementing this make sure you are not violating any Audit procedures. Access from back-end should always be discouraged unless there is a dire need and it is always better to have individual users created in DB and have access to data which they are authorized to see.
...
written by Anil Passi , January 18, 2008
Just wondering what brought you to this webpage !

...
written by NeoHyd , January 18, 2008
Actually I started at oracle forums....went to some blog...then went to another...and then to Atul's blog and from there I came here...was a long journey.... smilies/wink.gif
...
written by Anil Passi , January 18, 2008
Cheers NeoHyd.
I do not disagree with your statement though.
Perhaps you can modify procedure xx_grant_apps_query(), so as to exclude the tables that you fear might cause security concern.
If you end up doing so, then please feel free to paste the modified code for xx_grant_apps_query() on here.

Thanks,
Anil Passi
...
written by Khaleel , January 31, 2008
Hi Anil,

Just adding one thought to the point no. 2, in case of non-hrms responsibility, there would be many form functions, is there a single way to make all the forms query-only access to all users in apps? please give a suggestion on this.

Thanks,
Khaleel S
Mr
written by VenkatJ , March 11, 2008
Hi Anil

Can you please explain in detail about READ-ONLY APPS Schema.

I am not able to find schema "XX_G4G"


Thanks
Venkat.
FND_USR
written by Damir Vadas , March 12, 2008
Granting SELECT on that table is more then security flaw. What about that?
THX
You must be logged in to a comment. Please register if you do not have an account yet.

busy