DBA Tips Archive for Oracle

  


[an error occurred while processing this directive]

No Title

[an error occurred while processing this directive]

by Michael New, MichaelNew@earthlink.net, Gradation LLC

This note explains how to use product and user level security by disabling and re-enabling commands such as SPOOL or ALTER using the table PRODUCT_USER_PROFILE.

PRODUCT_USER_PROFILE is table that resides in the SYSTEM account. It provides product level security that supplements the user level security provided by SQL commands GRANT and REVOKE, and can be used with your own applications as well as with other Oracle products. The table is created by running the command file ORACLE_HOME\sqlplus\admin\pupbld.sql under the schema SYSTEM.

To disable a SQL or SQL*Plus commands for a given user, insert a row in the PRODUCT_USER_PROFILE table. User names can be appended to with the wild card '%'. For example 'SC%', which will then disable the relevant command for all users whose name starts with 'SC'.

 

The userid, attribute and char_value must be in uppercase.

For example:


CONNECT system/manager Connected. INSERT INTO product_user_profile (product, userid, attribute, char_value, date_value) VALUES('SQL*Plus', 'SCOTT', 'HOST', 'DISABLED', NULL); 1 row created. INSERT INTO product_user_profile (product, userid, attribute, char_value, date_value) VALUES('SQL*Plus', 'JHUNTER', 'SPOOL', 'DISABLED', NULL); 1 row created. COMMIT; Commit complete. SELECT product, userid, attribute, char_value FROM product_user_profile; PRODUCT USERID ATTRIBUTE CHAR_VALUE ------------ ---------- ------------ ------------ SQL*Plus SCOTT HOST DISABLED SQL*Plus JHUNTER SPOOL DISABLED

If user SCOTT tried to run a HOST command or if JHUNTER attempts a SPOOL, they would receive the following errors:


SQL> connect scott/tiger Connected. SQL> host ls SP2-0544: Command "host" disabled in Product User Profile SQL> !ls -l SP2-0544: Command "! (HOST)" disabled in Product User Profile -------------------------------------------------------------- SQL> connect jhunter/xxxxxx Connected. SQL> spool report.txt SP2-0544: Command "spool" disabled in Product User Profile

To re-enable commands, delete the row containing the restriction from the PRODUCT_USER_PROFILE table.


CONNECT system/manager Connected. DELETE FROM product_user_profile WHERE product='SQL*Plus' AND userid='SCOTT' and attribute='HOST'; 1 row deleted. DELETE FROM product_user_profile WHERE product='SQL*Plus' AND userid='JHUNTER' and attribute='SPOOL'; 1 row deleted. COMMIT; Commit complete.

The following are SQL and SQL*Plus commands that one can disable through the PRODUCT_USER_PROFILE table. For a full list, review the SQL*Plus User's Guide.



Copyright (c) 1998-2017 Jeffrey M. Hunter. All rights reserved.

All articles, scripts and material located at the Internet address of http://www.idevelopment.info is the copyright of Jeffrey M. Hunter and is protected under copyright laws of the United States. This document may not be hosted on any other site without my express, prior, written permission. Application to host any of the material elsewhere can be made by contacting me at jhunter@idevelopment.info.

I have made every effort and taken great care in making sure that the material included on my web site is technically accurate, but I disclaim any and all responsibility for any loss, damage or destruction of data or any other property which may arise from relying on it. I will in no case be liable for any monetary damages arising from such loss, damage or destruction.

Last modified on
Tuesday, 04-Sep-2012 00:25:11 EDT
Page Count: 19068