Yesterday I announced that I would be doing a five day series entitled “The 5 Oracle Tricks You Never Knew.” Today’s trick is pretty simple, and it allows you to copy user accounts from one instance to another with the same password, grants, roles, etc, without using the exp/imp tools.
Everyone knows that you can use “create user username identified by password” to create a new user. What most people don’t know is that you can actually copy the password of a user from one database to another as well.
You wont be able to see the password (sorry hackers), but you can copy it in its encoded form.
Instead of using:
create user test identified by password;
You will use:
create user test identified by values 'encoded password';
The encoded password will actually be the encrypted password stored in the database that is visible to the DBA eye. This is a 16 character password you will find in the DBA_USERS view in the PASSWORD column.
You can also use:
alter user test identified by values 'encoded password';
If you have already created the user and need to change the password to what it might have been on another system.
This is extremely useful for DBAs that are copying their production database to development, or migrating a database from one instance to another. Too often, DBAs are forced to remember the details they have, copy them from the DBA_USERS view, and try to create the new users as close as possible to the original.
But we’re more sophisticated! Instead, we will use the DBMS_METADATA package to pull the user information.
set head off set pages 0 set long 9999999 select dbms_metadata.get_ddl('USER', username) || '/' usercreate from dba_users; USERCREATE -------------------------------------------------------------- CREATE USER "SYS" IDENTIFIED BY VALUES 'F894844C34402B67' DEFAULT TABLESPACE "SYSTEM" TEMPORARY TABLESPACE "TEMP" / ...
Do you want to get all their roles and grants as well? Nothing easier! Look at the following:
SELECT DBMS_METADATA.GET_GRANTED_DDL('ROLE_GRANT','SYS') FROM DUAL; SELECT DBMS_METADATA.GET_GRANTED_DDL('SYSTEM_GRANT','SYS') FROM DUAL; SELECT DBMS_METADATA.GET_GRANTED_DDL('OBJECT_GRANT','SYS') FROM DUAL;
From this, we can form our Unified User Copy-o-matic with the following query:
set head off set pages 0 set long 9999999 spool user_script.sql SELECT DBMS_METADATA.GET_DDL('USER', USERNAME) || '/' DDL FROM DBA_USERS UNION ALL SELECT DBMS_METADATA.GET_GRANTED_DDL('ROLE_GRANT', USERNAME) || '/' DDL FROM DBA_USERS UNION ALL SELECT DBMS_METADATA.GET_GRANTED_DDL('SYSTEM_GRANT', USERNAME) || '/' DDL FROM DBA_USERS UNION ALL SELECT DBMS_METADATA.GET_GRANTED_DDL('OBJECT_GRANT', USERNAME) || '/' DDL FROM DBA_USERS; spool off;
And voila! All of our users and grants all in one simple script.
If you would like simple alter commands instead, we can always skip using DBMS_METADATA. Instead, use this query:
select 'alter user ' || username || ' identified by values ''' || password || ''';' from dba_users;
Note that in the case above, there are three single quotes to the left and right of password. Don’t use double quotes.
That’s it for today; a rather easy trick that you can use many times during your DBA career. If you already knew this trick, don’t worry! There’s more to come, the rest a bit more advanced and a bit more obscure. Join me tomorrow and we’ll talk about how to transform any query into any other on the back-end, sometimes with very amusing results!
Hello ,
It is helpful to others to add one more proc.
GET_DEPENDENT_DDL to get the space quota in tablespaces.
Hope this helps.
Ravinder
You’re absolutely right, it helps very much. Quota information is vital to copy a user verbatim.
I had to add some qualifiers on the statements so that if a user has not bee issued a grant the procedure does not fail. Here is my additions: Note the ‘exists’ statements.
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘ROLE_GRANT’, USERNAME) || ‘/’ DDL
FROM DBA_USERS where exists (select ‘x’ from dba_role_privs drp where
drp.grantee = dba_users.username)
UNION ALL
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘SYSTEM_GRANT’, USERNAME) || ‘/’ DDL FROM D
BA_USERS where exists (select ‘x’ from dba_role_privs drp where
drp.grantee = dba_users.username)
UNION ALL
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘OBJECT_GRANT’, USERNAME) || ‘/’ DDL FROM D
BA_USERS where exists (select ‘x’ from dba_tab_privs dtp where
dtp.grantee = dba_users.username);
Good call Bob, without this is can make for a painful output script.
This will help Bob’s code out and stop the package from issuing errors, where users have no system privlidges.
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘SYSTEM_GRANT’, USERNAME) || ‘/’ DDL
FROM DBA_USERS
where exists (select ‘x’ from dba_role_privs drp, dba_sys_privs dsp
where drp.grantee = dba_users.username
and drp.granted_role = dsp.privilege)
Still one hangup, setting default role(s) for the users. If there are multiple roles to be set as default for a user they must all be declared in the same ALTER USER statement. The statment can be generated with the function below:
create or replace
FUNCTION f_default_roles(p_usr varchar2) RETURN VARCHAR2 IS
v_list VARCHAR2(2000);
v_first boolean;
CURSOR c_def_roles(v_userid varchar2) IS
SELECT granted_role
FROM dba_role_privs
WHERE grantee = v_userid
AND default_role = ‘YES’
ORDER BY granted_role;
BEGIN
v_first := true;
FOR c_rec IN c_def_roles(p_usr)
LOOP
if v_first then
v_list := c_rec.granted_role ;
v_first := false ;
else
v_list := v_list || ‘, ‘ || c_rec.granted_role;
end if;
END LOOP;
if v_first then
v_list := ‘– no default role for ‘ || p_usr ;
else
v_list := ‘alter user ‘ || p_usr || ‘ default role ‘ || v_list || ‘ ;’;
end if;
RETURN v_list;
END f_default_roles;
# Ravinder Says:
#It is helpful to others to add one more proc.
#GET_DEPENDENT_DDL to get the space quota in tablespaces.
Thanks for this tidbit — I am currently trying to extract it through the GET_DEPENDENT_DDL proc but I couldn’t figure out the correct syntax. Do you specify the user or the tablespace? Either way, I couldn’t get it to run:
SQL> select DBMS_METADATA.GET_DEPENDENT_DDL(‘TABLESPACE_QUOTA’,’SYSTEM’) FROM DUAL;
ERROR:
ORA-31604: invalid NAME parameter “BASE_OBJECT_NAME” for object type TABLESPACE_QUOTA in function
SET_FILTER
ORA-06512: at “SYS.DBMS_SYS_ERROR”, line 116
ORA-06512: at “SYS.DBMS_METADATA_INT”, line 4676
ORA-06512: at “SYS.DBMS_METADATA_INT”, line 8552
ORA-06512: at “SYS.DBMS_METADATA”, line 2881
ORA-06512: at “SYS.DBMS_METADATA”, line 2757
ORA-06512: at “SYS.DBMS_METADATA”, line 4394
ORA-06512: at line 1
Any thoughts?
You probably have this by now, but anyhow….
SELECT DBMS_METADATA.GET_granted_DDL(‘TABLESPACE_QUOTA’, ‘SYSTEM’) || ‘/’ DDL
FROM dual;
As observed earlier, you’ll want to wrap this to avoid the instance where there is no quota for that user. If you find you can’t get this to work, try using a ‘real’ user rather than SYS or SYSTEM in the function call.
Not to come across as picky but are you sure the sql above works on all versions?
I had to do this for an Oracle 9i database and the code I came up with was.
set head off
set pages 0
set long 9999999
spool user_script.sql
SELECT DBMS_METADATA.GET_DDL(‘USER’, USERNAME) || ‘;’ DDL
FROM DBA_USERS;
SELECT DBMS_METADATA.GET_DDL(‘ROLE’, role)||’;’ DDL
FROM dba_roles;
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘ROLE_GRANT’, role) || ‘;’ DDL
FROM role_role_privs;
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘SYSTEM_GRANT’, role) || ‘;’ DDL
FROM role_sys_privs;
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘OBJECT_GRANT’, role) || ‘;’ DDL
FROM role_tab_privs;
spool off;
like the ‘exist’ subquery idea.
Can one rename a database user (schema)?
i am getting the below error.
please let me know what i am doing wrong and moreover i want to get a DDL of user created role for ex: my_custom_role. please help
ops1@OESH111:SQL> SELECT DBMS_METADATA.GET_GRANTED_DDL(‘ROLE_GRANT’, USERNAME) || ‘/’ DDL
FROM DBA_USERS where exists (select ‘x’ from dba_role_privs drp where drp.grantee = dba_users.username) 2 ;
ERROR:
ORA-31608: specified object of type ROLE_GRANT not found
ORA-06512: at “SYS.DBMS_SYS_ERROR”, line 86
ORA-06512: at “SYS.DBMS_METADATA”, line 2809
ORA-06512: at “SYS.DBMS_METADATA”, line 4450
ORA-06512: at line 1
I figured out the above error. it was because i did not have the select_catalog_role. i tried on the database in which i had this role and worked like wonder.
But in case i have created 3 roles role_A role_B and role_C. then can you please tell me how to get the DDL for these roles. i tried the below
select DBMS_METADATA.GET_GRANTED_DDL(‘ROLE’,roleA) from dual;
but did not work. please provide me with the solution at the earliest
Found a nice way of getting the termination character (;) appended to each row
exec dbms_metadata.set_transform_param(dbms_metadata.SESSION_TRANSFORM,’SQLTERMINATOR’,TRUE);
Cheers
There are problems with at least Oracle 9.2:
I am missing 28 role to role grants when issuning this in Oracle 9.2:
SELECT DBMS_METADATA.GET_GRANTED_DDL(‘ROLE_GRANT’, role) DDL
FROM role_role_privs
…
17 Zeilen ausgewählt.
But for this:
select ‘GRANT “‘ || GRANTED_ROLE || ‘” TO “‘ || GRANTEE || ‘”;’
FROM DBA_ROLE_PRIVS
WHERE GRANTEE NOT IN (select username from dba_users) ;
I get:
45 Zeilen ausgewählt.
When I use the SELECT … ROLE_ROLE_PRIVS vs. DBA_ROLE_PRIVS in 11.2 I get the correct result 53 lines for each select), so there seems to be something like a bug in DBMS_METADATA from 9.2. that there are not all role to role grants returned from role_role_privs?
Here is my take on the script, it is the one I have been using for a while, though it doesn’t avoid the ORA-31608, it does give a nice clean output for a clean spool
set long 10000000
set pagesize 0
set trimspool on
set linesize 2000
execute dbms_metadata.set_transform_param (DBMS_METADATA.SESSION_TRANSFORM,’SQLTERMINATOR’,TRUE);
column x format a200 WORD_WRAPPED
select dbms_metadata.get_ddl (‘USER’, username) x
from dba_users
where username in (‘&&USERNAME’);
select dbms_metadata.get_granted_ddl (‘DEFAULT_ROLE’, grantee) x
from (select distinct grantee
from dba_role_privs
where default_role = ‘YES’
intersect
select username
from dba_users
where username in (‘&&USERNAME’));
select dbms_metadata.get_granted_ddl (‘ROLE_GRANT’, grantee) x
from (select distinct grantee
from dba_role_privs
intersect
select username
from dba_users
where username in (‘&&USERNAME’));
select dbms_metadata.get_granted_ddl (‘SYSTEM_GRANT’, grantee) x
from (select distinct grantee
from dba_sys_privs
intersect
select username
from dba_users
where username in (‘&&USERNAME’));
select dbms_metadata.get_granted_ddl (‘OBJECT_GRANT’, grantee, ‘COMPATIBLE’,’ORACLE’,’DDL’,100000) x
from (select distinct grantee
from dba_tab_privs
intersect
select username
from dba_users
where username in (‘&&USERNAME’));
wish I would have read about:
exec dbms_metadata.set_transform_param(dbms_metadata.SESSION_TRANSFORM,’SQLTERMINATOR’,TRUE)
At the start of my migration, but never the less this post was SUPER helpful!
OTOH, Oracle should be ashamed, that they didn’t provide a procedure to do this stuff for us until today, it could be as simple as: exec dbms_metadata.clone_user(‘SCOTT’)