This work is licensed under a Creative Commons Attribution-NonCommercial 2.5 License.








Saturday, September 02, 2006

Oracle Read Only APPS Database Schema

In this article I have detailed how to create a read only schema for APPS in Oracle eBusiness Suite, without the overhead of creating thousands of synonyms. 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 synonyms.

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;
/



OK, now for sme notes:-
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 on ""

 

Anonymous Anonymous said ... (1:32 AM) : 

Hi Anil
Searching over google I landed here.Nice tech tips.
I am having a peculiar problem , hope you have solution for this.
I am on process of comsolidating pur multiple oracle instances to one instance and multiple schemas.Created a test instance, now we have thousands of forms for this multiple schema. So we created a common form with different buttons to connect to individual schemas.
1.When you press the button for schema emp , it will alter the session to set the current_schema to emp and then open the main menu for emp .It works fine but when it comes to the reports it doesn't work, it says the table name doesn't exist.

I am looking for a solution which is bit easy then changing the thosands of reports.

I appreiate your help and your time.

with best
CT

 

Blogger Anil Passi said ... (1:47 AM) : 

Hi CT,

It appears that you are successfully able to switch current_schema to Emp in form, and it works.

However for the report, it does'nt work. My question for you is "which trigger in the report are you issuing alter session(via SRW)?
Are you doing so in Before Parameter Trigger? If so it should work, provided you have granted the appropriate permissions.

Thanks,
Anil Passi

 

Anonymous Anonymous said ... (11:30 AM) : 

Hi Anil
Thank you for the response. I am on my way to office(its an hour drive).
From the form we are calling the reports or some times from form menu directly by pressing a button, so I guess its going to be the same session.So we didn't add any triggers inside the reports.

As you said I have tried before , it was working but the thing is we have thousands of reports and we don't want to do by going to each report, which is time expensive.

Please help me out.

with best regards
CT

 

Blogger Anil Passi said ... (4:42 PM) : 

Hi CT/Soumya

Are you using RUN_PRODUCT to kick off the report from Form?

If so, the RUN_PRODUCT could be kicking off a new session, hence causing you to loose the effect of "alter the session to set the current_schema". Is there a common peice of initialization/(pll/Library ) code that is being executed by all the reports in BeforeParam/AfterParam trigger?

 

Blogger Anil Passi said ... (5:47 PM) : 

Hello CT/Soumya,

Will imlpementing something similar to "Step 4" of this article help?
Surely, if you write a "after logon", you will need to devise a mechanism to work out which session to switch to.

CREATE OR REPLACE TRIGGER xx_switch_logon_trg
AFTER logon ON [your_schema_name].SCHEMA
DECLARE
BEGIN
EXECUTE IMMEDIATE
'declare begin ' ||
EXECUTE IMMEDIATE 'ALTER SESSION SET CURRENT_SCHEMA =[new session]';
END;
/

Thanks,
Anil Passi

 

post a comment