Tag Archives: privileges

Recreate Oracle RDBMS User accounts

With the advent of Oracle 10g Import and Export data pump utility, the need to recreate a user account from scratch has been greatly reduced. However, there are still situation when you may need the SQL to recreate a specific user within another Oracle environment or just desire to see the creation statements. The script below will generate the statements to create the user defined in the CURR variable from the current Oracle RDBMS environment.

1. First we will create a user named LJCATT with various roles and privileges.

SQL> create user LJCATT identified by LJCATT;
User created.
SQL> alter user LJCATT default tablespace USERS;
User altered.
SQL> alter user LJCATT temporary tablespace TEMP;
User altered.
SQL> alter user LJCATT profile DEFAULT;
User altered.
SQL> grant DBA to LJCATT;
Grant succeeded.
SQL> grant CREATE TABLE to LJCATT with admin option;
Grant succeeded.
SQL> grant UNLIMITED TABLESPACE to LJCATT;
Grant succeeded.
SQL> grant EXECUTE on SYS.UTL_FILE to LJCATT with grant option;
Grant succeeded.
SQL>

2. Now we will execute the following PL/SQL block to regenerate the statements to recreate the user from the data dictionary.

set serveroutput on
spool ./create_user_account.sql

declare

curr varchar2(30):= ‘LJCATT’;
v_ext varchar2(3);

begin

— Create original user definition
for user in(select * from dba_users where username = curr)
loop
dbms_output.put_line(‘create user ‘||user.username||’ identified by
‘||user.username||’;’);
dbms_output.put_line(‘alter user ‘||user.username||’ default tablespace
‘||user.default_tablespace||’;’);
dbms_output.put_line(‘alter user ‘||user.username||’ temporary tablespace
‘||user.temporary_tablespace||’;’);
dbms_output.put_line(‘alter user ‘||user.username||’ profile
‘||user.profile||’;’);
if user.account_status<>‘OPEN’
then
dbms_output.put_line(‘alter user ‘||user.username||’ account lock;’);
end if;
end loop;

— Grant all roles defined for the user.

for role in(select * from dba_role_privs where grantee=curr)
loop
if role.admin_option = ‘YES’
then
dbms_output.put_line(‘grant ‘||role.granted_role||’ to ‘||role.grantee||’ with
admin option’||’;’);
else
dbms_output.put_line(‘grant ‘||role.granted_role||’ to ‘||role.grantee||’;’);
end if;
end loop;

— Grant all system privileges for the user.

for sys_priv in(select * from dba_sys_privs where grantee=curr)
loop
if sys_priv.admin_option = ‘YES’
then
dbms_output.put_line(‘grant ‘||sys_priv.privilege||’ to ‘||sys_priv.grantee||’
with admin option’||’;’);
else
dbms_output.put_line(‘grant ‘||sys_priv.privilege||’ to
‘||sys_priv.grantee||’;’);
end if;
end loop;

— Grant all object privileges for the user.

for tab_priv in(select * from dba_tab_privs where grantee=curr)
loop
if tab_priv.grantable = ‘YES’
then
dbms_output.put_line(‘grant ‘||tab_priv.privilege||’ on
‘||tab_priv.owner||’.’||tab_priv.table_name||’ to ‘||tab_priv.grantee||’ with
grant option;’);
else
dbms_output.put_line(‘grant ‘||tab_priv.privilege||’ on
‘||tab_priv.owner||’.’||tab_priv.table_name||’ to ‘||tab_priv.grantee||’;’);
end if;
end loop;
end;
/

spool off

Sample Output results:

47 48 49 50 51 52 53 54 55 56 57 58 59 60 61
create user LJCATT identified by LJCATT;
alter user LJCATT default tablespace USERS;
alter user LJCATT temporary tablespace TEMP;
alter user LJCATT profile DEFAULT;
grant DBA to LJCATT;
grant CREATE TABLE to LJCATT with admin option;
grant UNLIMITED TABLESPACE to LJCATT;
grant EXECUTE on SYS.UTL_FILE to LJCATT with grant option;

PL/SQL procedure successfully completed.

SQL>

3. The above SQL statements can now be used against any other Oracle database to recreate the user account with the same rights which exist in this database. NOTE: There exist several dependencies in the above statements, such as: tablespaces, profiles, roles, and object privileges. For example, we need to take care that a default tablespace defined in the alter user statement truly exist in the destination database.

Larry J Catt, OCP 9i, 10g
oracle@allcompute.com
www.allcompute.com

Oracle RESOURCE role

Oracle provides several predefined roles for various functions within the database. Roles are defined as a grouping of system and object privileges which can be granted to a user instead of assigning individual privileges. This functionality can be extremely helpful when you have to assign hundreds of privileges to a large number of users, which is a typical function in most systems. Additionally, changes to privileges for groups of users can easily be accomplished by altering the definition of the role instead of changing each individual user account. In this article we will discuss the use of the Oracle defined role RESOURCE.

The RESOURCE role is used to give an individual the right to create any object within his/her own schema. This role is normally used to define a developer’s privilege within a test and development system. It allows a developer to build objects necessary to create a system without impacting other developers on the same system. The following instructions define how to create a user account, assign the RESOURCE role to that user and lists the privileges granted by RESOURCE role.

1. Logon to you Oracle database as sysdba.

mylinux:>sqlplus ‘/ as sysdba’

SQL*Plus: Release 10.2.0.4.0 – Production on Wed May 20 17:16:49 2009

Copyright (c) 1982, 2007, Oracle. All Rights Reserved.

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 – 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL>

2. Create a permanent tablespace for your new user.

SQL> create tablespace devl datafile ‘/U01/ORACLE/PRODUCT/10.2.0/ORADATA/ORCL10G/d
evl01.dbf’ size 5000m;

Tablespace created.

SQL>

3. Create a temporary tablespace for you new user.

SQL> create temporary tablespace devl_temp tempfile ‘/U01/ORACLE/PRODUCT/10.2.0/OR
ADATA/ORCL10G/devl_temp01.dbf’ size 2500m;

Tablespace created.

SQL>

4. Create you development user.

SQL> Create user developer01 identified by developer
2 Default tablespace devl
3 Quota unlimited on devl
4 Temporary tablespace devl_temp;

User created.

SQL>

5. You have to grant create session directly to the user developer01. NOTE: “create session” is not part of the RESOURCE role.

SQL> grant create session to developer01;

Grant succeeded.

SQL>

6. Grant the role RESOURCE to the user developer01.

SQL> grant resource to developer01;

Grant succeeded.

SQL>

7. Now you can logon and test the new user account by creating an object.

SQL> connect developer01/developer
Connected.
SQL> create table test1(testing varchar2(30));

Table created.

SQL> select tablespace_name from user_tables where table_name=’TEST1′;

TABLESPACE_NAME
——————————
DEVL

SQL>

8. The following PL/SQL block gives you all of the privileges granted to a specific role where the variable V_USER defines the role.

set serveroutput on

declare

v_ct number;
v_user varchar2(30):=’RESOURCE’;

begin

for role in(select * from dba_role_privs where grantee=v_user)
loop

if role.admin_option = ‘YES’
then
dbms_output.put_line(‘grant ‘||role.granted_role||’ to ‘||role.grantee||’ with
admin option’||’;’);
else
dbms_output.put_line(‘grant ‘||role.granted_role||’ to ‘||role.grantee||’;’);
end if;
end loop;

for sys_priv in(select * from dba_sys_privs where grantee=v_user)
loop

if sys_priv.admin_option = ‘YES’
then
dbms_output.put_line(‘grant ‘||sys_priv.privilege||’ to ‘||sys_priv.grantee||’
with admin option’||’;’);
else
dbms_output.put_line(‘grant ‘||sys_priv.privilege||’ to
‘||sys_priv.grantee||’;’);
end if;
end loop;

for tab_priv in(select * from dba_tab_privs where grantee=v_user)
loop

if tab_priv.grantable = ‘YES’
then
dbms_output.put_line(‘grant ‘||tab_priv.privilege||’ on
‘||tab_priv.owner||’.’||tab_priv.table_name||’ to ‘||tab_priv.grantee||’ with
grant option;’);
else
dbms_output.put_line(‘grant ‘||tab_priv.privilege||’ on
‘||tab_priv.owner||’.’||tab_priv.table_name||’ to ‘||tab_priv.grantee||’;’);
end if;
end loop;
end;
/

SQL> set serveroutput on

declare

v_ct number;
v_user varchar2(30):=’RESOURCE’;

begin

for role in(select * from dba_role_privs where grantee=v_user)
loop

if role.admin_option = ‘YES’
then
dbms_output.put_line(‘grant ‘||role.granted_role||’ to ‘||role.grantee||’ with
admin option’||’;’);
else
dbms_output.put_line(‘grant ‘||role.granted_role||’ to ‘||role.grantee||’;’);
end if;
end loop;

for sys_priv in(select * from dba_sys_privs where grantee=v_user)
loop

if sys_priv.admin_option = ‘YES’
then
dbms_output.put_line(‘grant ‘||sys_priv.privilege||’ to ‘||sys_priv.grantee||’
with admin option’||’;’);
else
dbms_output.put_line(‘grant ‘||sys_priv.privilege||’ to
‘||sys_priv.grantee||’;’);
end if;
end loop;

for tab_priv in(select * from dba_tab_privs where grantee=v_user)
loop

if tab_priv.grantable = ‘YES’
then
dbms_output.put_line(‘grant ‘||tab_priv.privilege||’ on
‘||tab_priv.owner||’.’||tab_priv.table_name||’ to ‘||tab_priv.grantee||’ with
grant option;’);
else
dbms_output.put_line(‘grant ‘||tab_priv.privilege||’ on
‘||tab_priv.owner||’.’||tab_priv.table_name||’ to ‘||tab_priv.grantee||’;’);
end if;
end loop;
end;
/
SQL> SQL> SQL> 2 3 4 5 6 7 8 9 10 11 12 13 14
15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30
31 32 33 34 35 36 37 38 39 40 41 42 grant CREATE TYPE to
RESOURCE;
grant CREATE TABLE to RESOURCE;
grant CREATE CLUSTER to RESOURCE;
grant CREATE TRIGGER to RESOURCE;
grant CREATE OPERATOR to RESOURCE;
grant CREATE SEQUENCE to RESOURCE;
grant CREATE INDEXTYPE to RESOURCE;
grant CREATE PROCEDURE to RESOURCE;
grant CREATE TYPE to RESOURCE;
grant CREATE TABLE to RESOURCE;
grant CREATE CLUSTER to RESOURCE;
grant CREATE TRIGGER to RESOURCE;
grant CREATE OPERATOR to RESOURCE;
grant CREATE SEQUENCE to RESOURCE;
grant CREATE INDEXTYPE to RESOURCE;
grant CREATE PROCEDURE to RESOURCE;

PL/SQL procedure successfully completed.

SQL>

Larry J. Catt, OCP 9i, 10g
oracle@allcompute.com
www.allcompute.com

Oracle – ORA-00604: error occurred at recursive SQL level 1 and revoking a user privileges.

A schema is considered all of the objects owned by a single user within the Oracle database. When a user has a privilege revoked in the database, but owns a particular object which requires that privilege, errors will result. This article will recover an error which will result from a user having a privilege revoked which is require by one of the objects he owns.

1. Logon to your Oracle database server as the Oracle software owner.

2. Logon to SQLPLUS with SYSDBA privileges.

mylinux:> sqlplus ‘/ as sysdba’

SQL*Plus: Release 10.2.0.4.0 – Production on Sat Jan 17 11:00:09 2009

Copyright (c) 1982, 2007, Oracle. All Rights Reserved.

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 – 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL>

3. Create the user LJCATT and grant him the DBA role and create procedure privileges.

SQL> create user ljcatt identified by password10;

User created.

SQL> grant dba to ljcatt;

Grant succeeded.

SQL> grant execute on utl_file to ljcatt;

Grant succeeded.

4. Connect as the user ljcatt and create a procedure named test_file.

SQL> connect ljcatt
Enter password:
Connected.

SQL> create or replace procedure test_file
is
2 3 v_record varchar2(50) := ‘Testing file creation’;
4 v_file varchar2(30) := ‘testfile’;
5 v_dir varchar2(100) := ‘/home/lcatt’;
6 v_write utl_file.file_type;
7 begin
8
9 v_write := utl_file.fopen(v_dir, v_file, ‘w’, 4000);

10 11 –utl_file.fopen(v_dir, v_file, ‘w’, 100);
12
13 utl_file.put_line(v_write, v_record);

14 15 utl_file.fclose(v_write);
16
17 end test_file;
/ 18

Procedure created.

5. Reconnect to the database with SYSDBA privileges and revoke the DBA from ljcatt and grant the create session privilege. Then attempt to reconnect as the user LJCATT.

SQL> connect / as sysdba
Connected.
SQL> revoke dba from ljcatt;

Revoke succeeded.

SQL> grant create session to ljcatt;

Grant succeeded.

SQL> connect ljcatt
Enter password:
ERROR:
ORA-00604: error occurred at recursive SQL level 1
ORA-00900: invalid SQL statement
ORA-06512: at line 8

Warning: You are no longer connected to ORACLE.

6. NOTE: The error is received due to this user owning objects which he does not have privileges to create or access. This is shown below by reconnecting as SYSDBA and displaying objects owned by the user LJCATT.

SQL> connect / as sysdba
Connected.

SQL> select owner, object_name from dba_objects where object_name like ‘TEST_F%’
and owner=’LJCATT’

OWNER OBJECT_NAME
————————- ————————–
LJCATT TEST_FILE

7. As SYSDBA, re-grant the DBA role to LJCATT and attempt to reconnect.

SQL> grant dba to ljcatt;

Grant succeeded.

SQL> connect ljcatt
Enter password:
Connected.
SQL>

Now that the user LJCATT has the specific privileges required by the objects he owns, he is able to connect without error.

Larry J. Catt, OCP 9i, 10g
oracle@allcompute.com
www.allcompute.com

Oracle – User does not have permissions on Oracle package UTL_FILE.

Oracle provides the package UTL_FILE to produce OS layer files from within the Oracle RDBMS. Due to this procedures ability to create OS layer files from within the database, its access must be controlled through system privileges. This article will show a common PLS-00201 error, which indicates a lack of access permissions and how to resolve it.

1. Logon to your Oracle database server as the Oracle software owner.

2. Create a file called create_file.sql with the following SQL.

create or replace procedure test_file
is

v_record varchar2(50) := ‘Testing file creation’;
v_file varchar2(30) := ‘test_file.txt’;
v_dir varchar2(512) := ‘/home/lcatt’;
v_write utl_file.file_type;
begin

v_write:=utl_file.fopen(v_dir, v_file, ‘w’, 2000);

utl_file.put_line(v_write, v_record);

utl_file.fclose(v_write);

end test_file;
/

3. Logon to SQL*PLUS as the SYSDBA and create the user account LJCATT with the privileges: connect, create session, and resource to LJCATT.

mylinux:> sqlplus ‘/ as sysdba’

SQL*Plus: Release 10.2.0.4.0 – Production on Tue Jan 13 22:26:07 2009

Copyright (c) 1982, 2007, Oracle. All Rights Reserved.

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 – 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL>

SQL> create user ljcatt identified by ljcatt;

User created.

SQL> grant connect to ljcatt;

Grant succeeded.

SQL> grant create session to ljcatt;

Grant succeeded.

SQL> grant resource to ljcatt;

Grant succeeded.

SQL>

4. Reconnect to SQL*PLUS as LJCATT and execute the file create_file.sql to create your procedure

Mylinux:/home/lcatt:>sqlplus ljcatt

SQL*Plus: Release 10.2.0.4.0 – Production on Tue Jan 13 22:43:17 2009

Copyright (c) 1982, 2007, Oracle. All Rights Reserved.

Enter password:

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 – 64bit Production
With the Partitioning, OLAP, Data Mining and Real Application Testing options

SQL> set feedback on
SQL> set echo on
SQL>@./create_file.sql

SQL> create or replace procedure test_file
is
2 3
4 v_record varchar2(50) := ‘Testing file creation’;
5 v_file varchar2(30) := ‘test_file.txt’;
6 v_dir varchar2(512) := ‘/home/lcatt’;
7 v_write utl_file.file_type;
8 begin
9
10 v_write:=utl_file.fopen(v_dir, v_file, ‘w’, 2000);
11
12 utl_file.put_line(v_write, v_record);
13
utl_file.fclose(v_write);
14 15
16 end test_file;
17 /

Warning: Procedure created with compilation errors.

SQL> show errors
Errors for PROCEDURE TEST_FILE:

LINE/COL ERROR
——– —————————————————————–
7/9 PL/SQL: Item ignored
7/9 PLS-00201: identifier ‘UTL_FILE’ must be declared
10/1 PL/SQL: Statement ignored
10/1 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

12/1 PL/SQL: Statement ignored
12/19 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

14/1 PL/SQL: Statement ignored

LINE/COL ERROR
——– —————————————————————–
14/17 PLS-00320: the declaration of the type of this expression is
incomplete or malformed

SQL>

5. NOTE: The error received indicates that we do not have permissions to use the package UTL_FILE. Now connect to the database as sydba, execute the grant command: grant execute on utl_file to ljcatt;

SQL> connect / as sysdba
Connected.
SQL> grant execute on utl_file to ljcatt;

Grant succeeded.

SQL>

6. Connect back to the database as the user LJCATT, re-execute the SQL file create_file.sql, and execute the procedure test_file.

SQL> connect ljcatt
Enter password:
Connected.
SQL> create or replace procedure test_file
2 is
3
4 v_record varchar2(50) := ‘Testing file creation’;
5 v_file varchar2(30) := ‘test_file.txt’;
6 v_dir varchar2(512) := ‘/home/lcatt’;
7 v_write utl_file.file_type;
8 begin
9
10 v_write:=utl_file.fopen(v_dir, v_file, ‘w’, 2000);
11
12 utl_file.put_line(v_write, v_record);
13
14 utl_file.fclose(v_write);
15
end test_file;
16 17 /

Procedure created.

SQL> execute test_file

PL/SQL procedure successfully completed.

SQL>

The procedure now compiles without error and executes, due to the owner having proper privileges on the package UTL_FILE.

Larry J. Catt, OCP 9i, 10g
oracle@allcompute.com
www.allcompute.com