Skip to content

Datapump Scheduler for Schema level

 

My previous post about How to schedule and  take full database export using dbms scheduler job .Now i’m here go to show How to schedule schema level export using datapump.But I just added some comments in package body 🙂

Conn Sys user

SQL> grant execute on dbms_lock to system;

Conn system user

Step 1:

SQL> CREATE DIRECTORY NEW_DIR AS ‘D:\ORACLE\DUMP’;

Directory created.

Step 2:

CREATE OR REPLACE PACKAGE testexport
IS
PROCEDURE exptrial;
END testexport;
/

Step 3:

SQL> CREATE OR REPLACE PACKAGE BODY testexport
  2  IS
  3  h1 NUMBER;
  4  PROCEDURE exptrial IS
  5  BEGIN
  6  BEGIN
  7  UTL_FILE.FREMOVE(‘NEW_DIR’,’SCHEMATEST.DMP’);
  8  END;
  9  BEGIN
 10  DBMS_LOCK.sleep(30);
 11  END;
 12  BEGIN
 13  h1 := DBMS_DATAPUMP.open(
 14  operation => ‘EXPORT’,
 15  job_mode => ‘SCHEMA’,
 16  job_name => ‘TESTIT’,
 17  version => ‘COMPATIBLE’);
 18  END;
 19  BEGIN
 20  DBMS_DATAPUMP.add_file(
 21  handle => h1,
 22  filename => ‘TRIAL01.LOG’,
 23  directory => ‘NEW_DIR’,
 24  filetype => 3);
 25  END;
 26  BEGIN
 27  DBMS_DATAPUMP.add_file(
 28  handle => h1,
 29  filename => ‘SCHEMATEST.DMP’,
 30  directory => ‘NEW_DIR’,
 31  filetype => 1);
 32  END;
 33  BEGIN
 34  DBMS_DATAPUMP.metadata_filter(
 35  handle => h1,
 36  name => ‘SCHEMA_EXPR’,
 37  value => ‘IN(”FIN_ACE_DAM_AGNT”)’);
 38  END;
 39  BEGIN
 40  dbms_datapump.set_parameter(
 41  handle => h1, name => ‘ESTIMATE’, value => ‘BLOCKS’);
 42  END;
 43  BEGIN
 44  DBMS_DATAPUMP.START_JOB(h1);
 45  END;
 46  END exptrial;
 47  END testexport;
 48  /

Package body created.

Step 4:

SQL> exec testexport.exptrial;

PL/SQL procedure successfully completed.

Step 5:

SQL> BEGIN
  2  DBMS_SCHEDULER.CREATE_JOB_CLASS(
  3  job_class_name => ‘BACKUPME’,
  4  resource_consumer_group => ‘DEFAULT_CONSUMER_GROUP’,
  5  comments => ‘BACKUP, EXPORT ETC’);
  6  END;
  7  /

PL/SQL procedure successfully completed.

Step 6:

SQL> BEGIN
  2  DBMS_SCHEDULER.CREATE_JOB(
  3  job_name => ‘TRIALME’,
  4  job_type => ‘STORED_PROCEDURE’,
  5  job_action => ‘TESTEXPORT.EXPTRIAL’,
  6  start_date => ‘18-APR-10 10:00:00 PM’,
  7  repeat_interval => ‘FREQ=DAILY;BYHOUR=22′,
  8  job_class => ‘BACKUPME’,
  9  comments => ‘SCHEMA EXPORT’);
 10  END;
 11  /

Step 7:

SQL> BEGIN
  2  DBMS_SCHEDULER.ENABLE(‘TRIALME’);
  3  END;
  4  /

PL/SQL procedure successfully completed.

No comments yet

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

%d bloggers like this: