RE: Data Pump over NETWORK_LINK

From: Goulet, Richard <Richard.Goulet_at_parexel.com>
Date: Tue, 21 Apr 2009 11:45:04 -0400
Message-ID: <23C4836D8E9C5F4280A66C0C247BC16F272E2B83_at_US-BOS-MX011.na.pxl.int>



Oh Ian, it's not that long. Here is a stored procedure that I like:

   procedure schema_refresh(schema in varchar2, link in varchar2) as    h1 NUMBER := 0;
   h2 varchar2(1000);
   dmy number := 0;
   ex boolean := TRUE;
   fl number := 0;
   stmt varchar2(1000);
   schema_exp varchar2(100);
   blksz number := 0;
   bad_purge exception;
   bad_link exception;
   begin

      schema_exp := 'in('''||upper(schema)||''')';
      utl_file.fgetattr('DATA_PUMP_DIR', schema||'.log', ex, fl, blksz);
      if(ex = TRUE) then
utl_file.fremove('DATA_PUMP_DIR',schema||'.log');
      end if;
      h1 := purge_schema(schema);
      if(h1 != 0) then raise bad_purge;
      end if;
      select count(*) into dmy from user_db_links
      where db_link = upper(link);
      if(dmy = 0) then raise bad_link;
      end if;
      h1 := dbms_datapump.open (operation => 'IMPORT', job_mode =>
'SCHEMA', remote_link => link, job_name => upper(schema)||'_EXP', version => 'COMPATIBLE');
     dbms_datapump.set_parallel(handle => h1, degree => 2);
     dbms_datapump.add_file(handle => h1, filename => schema||'.log',
directory => 'DATA_PUMP_DIR', filetype => 3);
     dbms_datapump.set_parameter(handle => h1, name => 'KEEP_MASTER',
value => 0);
     dbms_datapump.set_parameter(handle => h1, name => 'ESTIMATE', value

=> 'STATISTICS');
dbms_datapump.set_parameter(handle => h1, name => 'INCLUDE_METADATA', value => 1); dbms_datapump.metadata_filter(handle => h1, name=> 'SCHEMA_EXPR',value => schema_exp); dbms_datapump.start_job(handle => h1, skip_current => 0, abort_step
=> 0);
dbms_datapump.wait_for_job(h1, h2); mail_log('DATA_PUMP_DIR', schema||'.log', initcap(schema)||'.log'); /*

utl_mail.send(sender=>'richard.goulet_at_parexel.com',recipients=>'richard. goulet_at_parexel.com', subject=>'CoreTST Dump',message=>h2);

      */
   exception

      when bad_purge then
         send_mail('richard.goulet_at_parexel.com','Failed Refresh','Schems
'||schema||' did not flush out properly. ORA-'||h1);
      when bad_link then
         send_mail('richard.goulet_at_parexel.com','Failed
Refresh','Database link '||link||' does not exist');
      when others then
         h2 := sqlerrm;
         if(h1 != 0) then dbms_datapump.stop_job(h1,1,0,0);
         end if;
         mail_log('DATA_PUMP_DIR', schema||'.log',
initcap(schema)||'.log');  

utl_mail.send(sender=>'richard.goulet_at_parexel.com',recipients=>'richard. goulet_at_parexel.com', subject=>schema||'Dump',message=>h2);

   end;

Dick Goulet
Senior Oracle DBA
PAREXEL International

-----Original Message-----
From: oracle-l-bounce_at_freelists.org
[mailto:oracle-l-bounce_at_freelists.org] On Behalf Of Ian Cary Sent: Tuesday, April 21, 2009 10:40 AM
To: Roger.Xu_at_dpsg.com
Cc: oracle-l_at_freelists.org; oracle-l-bounce_at_freelists.org Subject: Re: Data Pump over NETWORK_LINK

Hi Roger,

You can actually do this directly using the datapump API without the need
for an intermediary dmp file.

All you need to do is create a dblink (called e.g. mydblink) on the test database that points to the production one and run the following PL/SQL (again from the test database)

declare
  h1 number;
begin
  h1 := dbms_datapump.open(operation=>'IMPORT',

                           job_mode=>'SCHEMA',
                           remote_link=>'MYDBLINK');
  dbms_datapump.metadata_filter(handle=>h1,
                                name=>'SCHEMA_LIST',
                                value=>'''HR''');
  dbms_datapump.metadata_remap(h1,'REMAP_SCHEMA','HR','TESTHR'); end;
/

I've deliberately kept the example short but this can be expanded on to produce log information if needed.

Cheers,

Ian

|---------+----------------------------->
|         |           Roger.Xu_at_dpsg.com |
|         |           Sent by:          |
|         |           oracle-l-bounce_at_fr|
|         |           eelists.org       |
|         |                             |
|         |                             |
|         |           20/04/2009 21:05  |
|         |           Please respond to |
|         |           Roger.Xu          |
|         |                             |
|---------+----------------------------->
 
>-----------------------------------------------------------------------
---------------------------------------|
  |
|
  | To: oracle-l_at_freelists.org |
  | cc: oracle-l_at_freelists.org |
  | Subject: Data Pump over NETWORK_LINK |  
>-----------------------------------------------------------------------
---------------------------------------|




Here is how I currently copy a schema from production to dev in 10gR2 -

  1. expdp system/password1 schemas=HR directory=pump_dir1 dumpfile=hr.dmp
  2. FTP the dump file (hr.dmp) to the dev box
  3. drop user TESTHR in the dev box
  4. impdp system/password2 schemas=TESTHR directory=pump_dir2 dumpfile=hr.dmp remap_schema=HR:TESTHR
  5. reset password for TESTHR (alter user TESTHR identified by ??????)

Now my question is: how do I do this over the NETWORK_LINK? What kind of DB
link I need?

Would the command looks like this?

impdp system/password2 schemas=TESTHR directory=pump_dir2 network_link=mydblink remap_schema=HR:TESTHR

Thanks

Roger

Click here to learn more about Dr Pepper Snapple Group's commitment to corporate social responsibility.

Please be conscious of the environment and print this email only if absolutely necessary.
This e-mail (including any attachments) is confidential and may contain privileged information of Dr Pepper Snapple Group, Inc. and/or its subsidiaries ("Dr Pepper Snapple Group"). If you are not the intended recipient or receive it in error, you may not use, distribute, disclose or
copy any of the information contained within it and it may be unlawful to
do so. If you are not the intended recipient, please notify us immediately
by returning this e-mail to us at mailerror_at_dpsg.com and destroy all copies. Any views expressed by individuals within this e-mail do not necessarily reflect the views of Dr Pepper Snapple Group. This e-mail does
not constitute a binding offer, acceptance, amendment, waiver or other agreement, unless the intent that an e-mail will constitute such is clearly
stated in the body of the email. Recipients are advised to subject this e-mail and attachments to their own virus checking, in keeping with good computing practice. Please note that e-mail received by Dr Pepper Snapple
Group may be monitored in accordance with applicable law.

This email was received from the INTERNET and scanned by the Government Secure Intranet anti-virus service supplied by Cable&Wireless in partnership with MessageLabs. (CCTM Certificate Number 2007/11/0032.) In case of problems, please call your organisation?s IT Helpdesk. Communications via the GSi may be automatically logged, monitored and/or recorded for legal purposes.(See attached file: att4c4ek.dat)

For the latest data on the economy and society consult National Statistics at http://www.statistics.gov.uk



Please Note: Incoming and outgoing email messages are routinely monitored for compliance with our policy on the use of electronic communications



Legal Disclaimer : Any views expressed by the sender of this message are not necessarily those of the Office for National Statistics



The original of this email was scanned for viruses by the Government Secure Intranet virus scanning service supplied by Cable&Wireless in partnership with MessageLabs. (CCTM Certificate Number 2007/11/0032.) On leaving the GSi this email was certified virus free. Communications via the GSi may be automatically logged, monitored and/or recorded for legal purposes.

--
http://www.freelists.org/webpage/oracle-l
Received on Tue Apr 21 2009 - 10:45:04 CDT

Original text of this message