HOW TO

Perform schema restores of an Oracle enterprise geodatabase

Last Published: April 25, 2020

Summary

This article describes a series of steps to perform when importing an Oracle Data Pump file by schema using the Data Pump import utility - impdp. These steps are meant to be run one at a time.

Versions Supported:
  • EGDB: All
  • DBMS: Oracle
  • DBMS Version: 11g and above

Procedure

  1. Create a new Oracle database.
  2. Connect as SYS via SQL*Plus.
sqlplus sys/syspassword@server/sid as sysdba
  1. Grant public permissions for Oracle geodatabase.
GRANT EXECUTE ON dbms_pipe TO public;
GRANT EXECUTE ON dbms_lock TO public;
GRANT EXECUTE ON dbms_lob TO public;
GRANT EXECUTE ON dbms_utility TO public;
GRANT EXECUTE ON dbms_sql TO public;
GRANT EXECUTE ON utl_raw TO public;
  1. Obtain list of owners that own data in the old enterprise geodatabase.
select distinct owner from sde.layers
union
select distinct owner from sde.st_geometry_columns
union
select distinct owner from sde.table_registry
order by 1;
  1. Create all required tablespaces.
Note:
This is a default tablespace to auto-extend.
CREATE TABLESPACE SDETBS DATAFILE '/home/oracle/orcl/oradata/banner/sde.dbf'
SIZE 100M AUTOEXTEND ON NEXT 51200K MAXSIZE UNLIMITED EXTENT MANAGEMENT
LOCAL UNIFORM SIZE 320K LOGGING ONLINE SEGMENT SPACE MANAGEMENT MANUAL;
  1. Create all required users/schema.
create user sde identified by sdepassword default tablespace sdetbs;
  1. Grant all necessary permissions to the new user.
grant CREATE SESSION to sde;
grant CREATE TABLE to sde;
grant CREATE TRIGGER to sde;
grant CREATE SEQUENCE to sde;
grant CREATE PROCEDURE to sde;

grant EXECUTE ON DBMS_CRYPTO to sde;
grant CREATE INDEXTYPE to sde;
grant CREATE LIBRARY to sde;
grant CREATE OPERATOR to sde;
grant CREATE PUBLIC SYNONYM to sde;
grant CREATE TYPE to sde;
grant CREATE VIEW to sde;
grant DROP PUBLIC SYNONYM to sde;
grant ADMINISTER DATABASE TRIGGER to sde;

grant ALTER ANY INDEX to sde;
grant ALTER ANY TABLE to sde;
grant CREATE ANY INDEX to sde;
grant CREATE ANY TRIGGER to sde;
grant CREATE ANY VIEW to sde;
grant DROP ANY INDEX to sde;
grant DROP ANY VIEW to sde;
grant SELECT ANY TABLE to sde;

grant ALTER SESSION to sde;
grant ANALYZE ANY to sde;
grant SELECT ANY DICTIONARY to sde;
grant CREATE DATABASE LINK to sde;
grant CREATE MATERIALIZED VIEW to sde;
grant RESTRICTED SESSION to sde;
grant UNLIMITED TABLESPACE to sde;
grant ALTER SYSTEM to sde;
grant SELECT_CATALOG_ROLE to sde;
  1. Create a directory for the SYSTEM user to access.
create directory DPUMP1 as '/home/oracle/dpump';
  1. Grant R/W to SYSTEM user to read the files in the directory.
GRANT READ, WRITE ON DIRECTORY DPUMP1 to system;
exit
  1. Run the impdp utility from the CMD window for each user schema.
  • Example 1: SDE Schema
impdp system/sys directory=dpump1 logfile=sde_imp.log dumpfile=backup.DMP schemas=sde
  • Example 2: GIS Schema
impdp system/sys directory=dpump1 logfile=GIS_imp.log dumpfile=backup.DMP schemas=GIS
  1. Log into SQL*Plus and check for invalid objects.
sqlplus sys/sys@server/sid as sysdba
Select count(*) from dba_objects where owner='SDE' and status='INVALID';
  1. Compile any invalid schema objects.
exec dbms_utility.compile_schema(schema => 'SDE');

Article ID:000018063

Receive notifications and find solutions for new or common issues

Get summarized answers and video solutions from our new AI chatbot.

Download the Esri Support App

Related Information

Discover more on this topic

Get help from ArcGIS experts

Contact technical support

Download the Esri Support App

Go to download options