Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: Script to overcome ORA-54 during DDL

Re: Script to overcome ORA-54 during DDL

From: Jonathan Lewis <jonathan_at_jlcomp.demon.co.uk>
Date: Fri, 25 Jun 2004 21:36:58 +0100
Message-ID: <011201c45af4$29886060$7102a8c0@Primary>

This looks about right (except for the formatting);

create or replace procedure do_ddl(m_sql varchar2) as
 in_use exception ;
 pragma exception_init(in_use, -54);
begin
 while true loop
  begin
   execute immediate m_sql;
   exit;
  exception
   when in_use then null;
   when others then raise;
  end;
  dbms_lock.sleep(0.01);
 end loop;
end;
/

Regards

Jonathan Lewis

http://www.jlcomp.demon.co.uk

http://www.jlcomp.demon.co.uk/faq/ind_faq.html The Co-operative Oracle Users' FAQ

http://www.jlcomp.demon.co.uk/seminar.html Optimising Oracle Seminar - schedule updated May 1st

Sometimes when trying to perform DDL on really hot objects (heavy read/DML), I get:

ORA-00054: resource busy and acquire with NOWAIT specified.

I guess this is because you need to obtain a library cache lock in order to change the object definition. Since there is no enqueue mechanism for this resource, you can't just 'lock table ... in exclusive mode;' All that gives you is a DML lock.

One way to avoid this is to write a PL/SQL routine that uses DBMS_SQL and spins trying to run the DDL, stopping only when it succeeds. This seems to work most of the time.

Does anyone have a script for doing the above that they would like to share?

Please don't tell me to just use dbms_redefinition. That is unnecessarily complex when the above technique can be used instead.

Thanks

--

Jeremiah Wilton



Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--

Archives are at http://www.freelists.org/archives/oracle-l/ FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
Received on Fri Jun 25 2004 - 15:33:34 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US