Adding Tablespaces/Datafiles with Logical Standby DB present

Being in Norway this week, I have again the pleasure to teach an 11g Data Guard course. I always try to get a hotel close to the education center to be able to walk over there, but I didn’t get the right direction on the first day and had to use a taxi instead. Fortunately, the Norwegians are friendly and helpful and like to explain to a stranger where to find the next taxi stand 🙂

oracle_norway

One of the student asked how we can handle the situation, if we have a Logical Standby Database and want to add datafiles to the primary, while the Logical Standby DB uses an other directory structure than the Primary. Putting the parameter standby_file_management to auto and also setting db_file_name_convert appropriately is not sufficient in this case, as it is for a Physical Standby Database. Well, I searched through the documentation and found the following remedy:

Connect to the Logical Standby DB as sys and then

create or replace procedure sys.handle_tbs_ddl
(
  old_stmt  in  varchar2,
  stmt_typ  in  varchar2,
  schema    in  varchar2,
  name      in  varchar2,
  xidusn    in  number,
  xidslt    in  number,
  xidsqn    in  number,
  action    out number,
  new_stmt  out varchar2
) as
begin
  new_stmt := replace(old_stmt,
                     '/home/oracle/prima',
                     '/home/oracle/logst');

  action := dbms_logstdby.skip_action_replace;

exception
  when others then
    action := dbms_logstdby.skip_action_error;
    new_stmt := null;
end;
/
--------------------------------------------------------------------
-- LSP has to be stopped before we can do the next step
--------------------------------------------------------------------
alter database stop logical standby apply;
begin
dbms_logstdby.skip (stmt=>'tablespace',proc_name=>'sys.handle_tbs_ddl');
end;
/
alter database start logical standby apply immediate;

You can now create Tablespaces and/or add Datafiles on the Primary and they are automatically created on the Logical Standby as well.

You could also take an reactive approach and let the create tablespace action on the Primary crash the SQl Apply on the Logical Standby and then skip that DDL and create the tablespace manually on the Logical SB. But this approach above seems to be more elegant and leaves you with less administrative tasks to do. Thanks to Cecilie Sander for asking that question!

  1. #1 von audreyj am Februar 27, 2013 - 20:12

    Thanks, this worked for me. I have a physical and a logical instance on the same box and it would never create both in the desired directory until this.

  2. #2 von oraclenerd am September 18, 2017 - 17:25

    What if I define onle db_create_file_dest and work with datafiles, with their file_ids? Shouldnt it be sufficient for log mining and the creation of the datafile?

    I dont like when somebody converts files.. I let them create by the mentioned parameter

Kommentar verfassen

Trage deine Daten unten ein oder klicke ein Icon um dich einzuloggen:

WordPress.com-Logo

Du kommentierst mit Deinem WordPress.com-Konto. Abmelden /  Ändern )

Twitter-Bild

Du kommentierst mit Deinem Twitter-Konto. Abmelden /  Ändern )

Facebook-Foto

Du kommentierst mit Deinem Facebook-Konto. Abmelden /  Ändern )

Verbinde mit %s

Diese Seite verwendet Akismet, um Spam zu reduzieren. Erfahre, wie deine Kommentardaten verarbeitet werden..