Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

Copying Oracle Users

Oracle Tips by Steve Karam, OCM, Oracle ACE

This procedure 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';

Note:  As of 12c, this create user xxx identified by values clause will throw a ORA-02153 error

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;


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) || '/' DDLFROM 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.

 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.