27 March, 2020

Using FLASHBACK DATABASE for [destructive] D.R. Testing

Testing your Disaster Recovery strategy with an Oracle Standby Database can be at different "levels" for the database :
1. Graceful Switchover to the D.R. site and reversing roles between the two databases, but only querying* data at the D.R. site
2. Shutdown of the Production site and Failover to the D.R. site and only *querying* data at the D.R. site
3. Shutdown of the Production site and Failover to the D.R. site with *destructive* testing at the D.R. site followed by restore (or flashback) of the D.R. site database to "throwaway" all  changes
4. Either Switchover or Failover with role reversal and *destructive* testing at the D.R. site, validation that data changes flow back to the Production site and, finally, restore (or flashback) of the database at both sites.

Restoring a large database at one or both sites can take time.
You may have taken a Snapshot of the database(s) and just restore the snapshot.
Or you may FLASHBACK the database(s).

{for details on how I created this Standby database configuration in 19c, see my previous posts here and here}

I will try to use FLASHBACK DATABASE here.

I start with the Primary running at the Production site :

oracle19c>sqlplus hemant/hemant@orclpdb1

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:22:26 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.

Last Successful login time: Thu Mar 26 2020 23:22:02 +08:00

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> drop table my_transactions purge;

Table dropped.

SQL> create table my_transactions (txn_id number, txn_data varchar2(50));

Table created.

SQL> insert into my_transactions values (1,'First at ProductionDC:Primary');

1 row created.

SQL> commit;

Commit complete.

SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0
oracle19c>


I then verify the state of both databases (the "oracle19c" prompt is at the Production site, the  "STDBYDB" prompt is at the D.R. site)

oracle19c>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:23:48 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON       CURRENT_SCN
------- ----------- ---------------- ------------------ -----------
CURRENT NOT ALLOWED PRIMARY          NO                     4796230

SQL>



STDBYDB>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:25:02 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
STANDBY REQUIRED    PHYSICAL STANDBY NO
                         0     4796205


SQL>


So, currently, the Standby is slightly behind (SCN#4796205) the Primary (SCN#4796230). Note that FLASHBACK is *not* enabled in the databases.

I first create my RESTORE POINT on the Standby and then on the Primary.

{at the current Standby at the D.R. site}
SQL> alter database recover managed standby database cancel;

Database altered.

SQL> show parameter db_recovery_file_dest

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
db_recovery_file_dest                string      /opt/oracle/FRA/STDBYDB
db_recovery_file_dest_size           big integer 10G
SQL> create restore point dr_before_switch guarantee flashback database;

Restore point created.

SQL> select name, restore_point_time, database_incarnation#, scn, guarantee_flashback_database
  2  from v$restore_point
  3  /

NAME
--------------------------------------------------------------------------------
RESTORE_POINT_TIME
---------------------------------------------------------------------------
DATABASE_INCARNATION#        SCN GUA
--------------------- ---------- ---
DR_BEFORE_SWITCH

                    2    4796590 YES


SQL>
SQL> alter database recover managed standby database disconnect from session;

Database altered.

SQL>




{at the current Primary at the Production site}
SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON       CURRENT_SCN
------- ----------- ---------------- ------------------ -----------
CURRENT NOT ALLOWED PRIMARY          NO                     4796230

SQL> alter system switch logfile;

System altered.

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON       CURRENT_SCN
------- ----------- ---------------- ------------------ -----------
CURRENT NOT ALLOWED PRIMARY          NO                     4796968

SQL> create restore point production_before_switch guarantee flashback database;

Restore point created.

SQL> select name, restore_point_time, database_incarnation#, scn, guarantee_flashback_database
  2  from v$restore_point
  3  /

NAME
--------------------------------------------------------------------------------
RESTORE_POINT_TIME
---------------------------------------------------------------------------
DATABASE_INCARNATION#        SCN GUA
--------------------- ---------- ---
PRODUCTION_BEFORE_SWITCH

                    2    4797182 YES


SQL>


At each site, I have created a Restore Point (with Guarantee Flashback Database). I have ensured that the Restore Point for the current Standby Database at the D.R. site is at a *lower* SCN (4796590) than that for the current Primary (4797182) (at the Production site).  To further ensure this, I did a log swich and verified the CURRENT_SCN at the Primary before creating the Restore Point.

(Note that both sites have a DB_RECOVERY_FILE_DEST configured for the GUARANTEEd Restore Point).

(a small note : I have to disable Recovery at the Standby database before I can create a Restore Point and then re-enable Recovery after that.  A Restore Point cannot be created when a database is in Recovery mode).


I now put in another transaction at the Primary (Production site database) and then Switchover to to the D.R. site.

SQL> connect hemant/hemant@orclpdb1
Connected.
SQL> insert into my_transactions values (2,'Second, after R.P. at ProductionDC:Primary');

1 row created.

SQL> commit;

Commit complete.

SQL> connect / as sysdba
Connected.
SQL> alter database switchover to stdbydb;

Database altered.

SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0
oracle19c>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:41:57 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.

Connected to an idle instance.

SQL> startup mount;
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, current_scn
  2  from v$databasse
  3
SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON       CURRENT_SCN
------- ----------- ---------------- ------------------ -----------
STANDBY ALLOWED     PHYSICAL STANDBY RESTORE POINT ONLY     4899284

SQL> alter database recover managed standby database disconnect from session;

Database altered.

SQL>


So, now the database at the Production site is a Standby database.

I now connect to the database at the D.R. site that is now a Primary

STDBYDB>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:45:02 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
CURRENT NOT ALLOWED PRIMARY          RESTORE POINT ONLY
                   4899284           0


SQL> shutdown ;
ORA-01109: database not open


Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
Database opened.
SQL>
SQL> alter pluggable database orclpdb1 open;

Pluggable database altered.

SQL> connect hemant/hemant@STDBYPDB1
Connected.
SQL> select * from my_transactions order by 1;

    TXN_ID TXN_DATA
---------- --------------------------------------------------
         1 First at ProductionDC:Primary
         2 Second, after R.P. at ProductionDC:Primary

SQL>
SQL> insert into my_transactions values (3,'Destructive change at DRDC');

1 row created.

SQL> commit;

Commit complete.

SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0
STDBYDB>


{Note that "STDBYDPDB1" is my tnsnames entry for the PDB which still has the name "orclpdb1" at the D.R. site.}

I have created a "destructive" change with the third row which should not be in production. However, I will switch back to the Production data centre and verify that the row has replicated back.

{at the D.R. site}
STDBYDB>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:50:29 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> alter database switchover to orclcdb;

Database altered.

SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0
STDBYDB>



{at the Production site}
oracle19c>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:52:21 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> shutdown immediate
ORA-01109: database not open


Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
Database opened.
SQL> alter pluggable database orclpdb1 open;
alter pluggable database orclpdb1 open
*
ERROR at line 1:
ORA-65019: pluggable database ORCLPDB1 already open


SQL>
SQL> connect hemant/hemant@orclpdb1
Connected.
SQL> select * from my_transactions order by 1;

    TXN_ID TXN_DATA
---------- --------------------------------------------------
         1 First at ProductionDC:Primary
         2 Second, after R.P. at ProductionDC:Primary
         3 Destructive change at DRDC

SQL>


So, I have been able to
1. SWITCHOVER from the Production site to the D.R. site
2. Create a new row when the database is Primary at the D.R. site
3. SWITCHOVER back to the Production site
4. Verify that the destructive row is now at the Production site.

I now need to reset both databases to the state they were in before I began the test.

{at the Production site}
oracle19c>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Mar 26 23:56:16 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
CURRENT NOT ALLOWED PRIMARY          RESTORE POINT ONLY
                   5000964           0


SQL>
SQL> select name, restore_point_time, database_incarnation#, scn, guarantee_flashback_database
  2  from v$restore_point
  3  /

NAME
--------------------------------------------------------------------------------
RESTORE_POINT_TIME
---------------------------------------------------------------------------
DATABASE_INCARNATION#        SCN GUA
--------------------- ---------- ---
PRODUCTION_BEFORE_SWITCH

                    2    4797182 YES


SQL>
SQL> FLASHBACK DATABASE TO RESTORE POINT PRODUCTION_BEFORE_SWITCH;

Flashback complete.

SQL> alter database open resetlogs ;

Database altered.

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
CURRENT NOT ALLOWED PRIMARY          RESTORE POINT ONLY
                   5000964     4798237


SQL>
SQL> connect hemant/hemant@orclpdb1
Connected.
SQL> select * from my_transactions order by 1;

    TXN_ID TXN_DATA
---------- --------------------------------------------------
         1 First at ProductionDC:Primary

SQL>


So, now, the database at the Production site has reverted to the Restore Point and all changes after the Restore Point have been discarded.

This includes TXN_ID=2 which I had added to demonstrate propagation of a change from the Production site to the D.R. site ---- in your testing, you must ensure that you do not make any changes after the Restore Point is created.   Typically, you'd create your Production Restore Point with the applications disconnecte, database shutdown and re-mounted just before switchover.  Remember, this is for D.R. testing when you do have control over applications and database shutdown and startup.


What about the database at the D.R. site ?  Can I flashback it and resume it's role as a Standby ?
Remember that the Restore Point I created on the D.R. site was at a *lower* SCN than that for the Production site.

STDBYDB>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Fri Mar 27 00:08:25 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.

Connected to an idle instance.

SQL> startup mount;
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
STANDBY ALLOWED     PHYSICAL STANDBY RESTORE POINT ONLY
                         0     5000964


SQL> select name, restore_point_time, database_incarnation#, scn, guarantee_flashback_database
  2  from v$restore_point
  3  /

NAME
--------------------------------------------------------------------------------
RESTORE_POINT_TIME
---------------------------------------------------------------------------
DATABASE_INCARNATION#        SCN GUA
--------------------- ---------- ---
DR_BEFORE_SWITCH

                    2    4796590 YES

PRODUCTION_BEFORE_SWITCH_PRIMARY

                    2    4797182 NO


SQL>  FLASHBACK DATABASE TO RESTORE POINT DR_BEFORE_SWITCH;

Flashback complete.

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
STANDBY ALLOWED     PHYSICAL STANDBY RESTORE POINT ONLY
                         0     4796590


SQL> alter database recover managed standby database disconnect from session;

Database altered.

SQL>


Now the database at the Production site has resumed as a Primary database, at SCN#4798237 and the database at the D.R. site has resumed as a Standby database at SCN#4796590  (lower than the Primary).

If you noticed the second entry in v$restore_point at the D.R. site -- Restore Point name "PRODUCTION_BEFORE_SWITCH_PRIMARY" -- this is a 19c enhancement where a Restore Point created on the Primary automatically propagates to the Standby, with the suffix "_PRIMARY"  (to indicate that it came from a database in PRIMARY role) attached to the Restore Point name.

Can I really really be sure that I have reverted both databases to their intended roles ?

I  can verify this again :

{at the Production site}
SQL> connect hemant/hemant@orclpdb1
Connected.
SQL> insert into my_transactions values (1001,'After DR Testing, back to normal life');

1 row created.

SQL> commit;

Commit complete.

SQL> select * from my_transactions order by 1;

    TXN_ID TXN_DATA
---------- --------------------------------------------------
         1 First at ProductionDC:Primary
      1001 After DR Testing, back to normal life

SQL>



{at the D.R site}
SQL> alter database recover managed standby database cancel;

Database altered.

SQL> alter database open read only;

Database altered.

SQL> alter pluggable database orclpdb1 open;

Pluggable database altered.

SQL> connect hemant/hemant@stdbypdb1
Connected.
SQL> select * from my_transactions order by 1;

    TXN_ID TXN_DATA
---------- --------------------------------------------------
         1 First at ProductionDC:Primary
      1001 After DR Testing, back to normal life

SQL>
SQL> connect / as sysdba
Connected.
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
SQL> alter database recover managed standby database disconnect from session;

Database altered.

SQL> select controlfile_type, open_resetlogs, database_role, flashback_on, standby_became_primary_scn, current_scn
  2  from v$database
  3  /

CONTROL OPEN_RESETL DATABASE_ROLE    FLASHBACK_ON
------- ----------- ---------------- ------------------
STANDBY_BECAME_PRIMARY_SCN CURRENT_SCN
-------------------------- -----------
STANDBY REQUIRED    PHYSICAL STANDBY RESTORE POINT ONLY
                         0     4802358


SQL>


To verify the behaviour, I added a new row (TXN_ID=1001) in the Primary database at the Production site and then did an OPEN READ ONLY of the Standby database at the D.R. site to check the table.
Note :  So as to not require an Active Data Guard licence, I stopped Recovery on the Standby before I did an OPEN READ ONLY.
Of course, after the verification, I resumed the Standby database in Recovery mode.

This whole exercise also did NOT need the databases to be "permanently" in FLASHBACK ON mode.  I used the Guaranteed Restore Point feature with the Recovery File Dest to generate the minimal flashback logs.  At the end of the exercise, I can DROP the Restore Points.

{at the Production site}
oracle19c>sqlplus

SQL*Plus: Release 19.0.0.0.0 - Production on Fri Mar 27 00:37:47 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.

Enter user-name: / as sysdba

Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup mount;
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
SQL> drop restore point PRODUCTION_BEFORE_SWITCH;

Restore point dropped.

SQL> alter database open;

Database altered.

SQL> select name, restore_point_time, database_incarnation#, scn, guarantee_flashback_database
  2  from v$restore_point
  3  /

no rows selected

SQL>


{at the D.R. site}
STDBYDB>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Fri Mar 27 00:40:47 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0

SQL> alter database recover managed standby database cancel;

Database altered.

SQL> select name from v$restore_point;

NAME
--------------------------------------------------------------------------------
DR_BEFORE_SWITCH
PRODUCTION_BEFORE_SWITCH_PRIMARY

SQL>
SQL> drop restore point PRODUCTION_BEFORE_SWITCH_PRIMARY;

Restore point dropped.

SQL> drop restore point DR_BEFORE_SWITCH;

Restore point dropped.

SQL> alter database recover managed standby database disconnect from session;

Database altered.

SQL>
SQL> select name, restore_point_time, database_incarnation#, scn, guarantee_flashback_database
  2  from v$restore_point
  3  /

no rows selected

SQL>


The only "catch" is that I had to bring up the Production site (Primary) database in MOUNT mode before I could drop the Restore Point.  So, you need to factor this into you D.R. testing.


15 March, 2020

Redo Shipping for Standby Database in 19c

Following my previous post, here is some setup information :

Relevant database instance parameter(s) for the Primary database :

*.local_listener='LISTENER_ORCLCDB'
*.log_archive_dest_1='LOCATION=/opt/oracle/archivelog/ORCLCDB'
*.log_archive_dest_2='SERVICE=STDBYDB ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=STDBYDB'
*.remote_login_passwordfile='EXCLUSIVE'


Relevant database instance parameter(s) for the Standby database :

*.audit_file_dest='/opt/oracle/admin/STDBYDB/adump'
*.control_files='/opt/oracle/oradata/STDBYDB/control01.ctl','/opt/oracle/oradata/STDBYDB/control02.ctl'
*.db_file_name_convert='/opt/oracle/oradata/ORCLCDB','/opt/oracle/oradata/STDBYDB'
*.db_name='ORCLCDB'
*.db_unique_name='STDBYDB'
*.dispatchers='(PROTOCOL=TCP) (SERVICE=STDBYDBXDB)'
*.fal_server='ORCLCDB'
*.local_listener='LISTENER_STDBYDB'
*.log_archive_dest_1='LOCATION=/opt/oracle/archivelog/STDBYDB'
*.log_archive_dest_2='SERVICE=ORCLCDB ASYNC VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=ORCLCDB'
*.log_file_name_convert='/opt/oracle/oradata/ORCLCDB','/opt/oracle/oradata/STDBYDB'
*.remote_login_passwordfile='EXCLUSIVE'
*.standby_file_management='AUTO'


The listener.ora and tnsnames.ora entries on the Primary server :

{listener}
LISTENER =
(DESCRIPTION_LIST =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1))
    (ADDRESS = (PROTOCOL = TCP)(HOST = x.x.x.x)(PORT = 1521))
  )
)

{tnsnames}
LISTENER_ORCLCDB =
  (ADDRESS = (PROTOCOL = TCP)(HOST = x.x.x.x)(PORT = 1521))

STDBYDB =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = x.x.x.x)(PORT = 1522))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = STDBYDB)
    )
  )


The listener.ora and tnsnames.ora entries on the Standby server :

{static listener entry}
LISTENER_STDBYDB =
(DESCRIPTION_LIST =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 0.0.0.0)(PORT = 1522))
  )
)

SID_LIST_LISTENER_STDBYDB =
 (SID_LIST=
  (SID_DESC =
   (ORACLE_HOME = /opt/oracle/product/19c/dbhome_1)
   (SID_NAME = STDBYDB)
   )
 )

{tnsnames}
LISTENER_STDBYDB =
  (ADDRESS = (PROTOCOL = TCP)(HOST = x.x.x.x)(PORT = 1522))

ORCLCDB =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = x.x.x.x)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORCLCDB)
    )
  )


Database listener and instance startup commands on the Standby :

STDBYDB_server>lsnrctl start listener_stdbydb

LSNRCTL for Linux: Version 19.0.0.0.0 - Production on 15-MAR-2020 23:05:43

Copyright (c) 1991, 2019, Oracle.  All rights reserved.

Starting /opt/oracle/product/19c/dbhome_1/bin/tnslsnr: please wait...

TNSLSNR for Linux: Version 19.0.0.0.0 - Production
System parameter file is /opt/oracle/product/19c/dbhome_1/network/admin/listener.ora
Log messages written to /opt/oracle/diag/tnslsnr/oracle-19c-vagrant/listener_stdbydb/alert/log.xml
Listening on: (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=0.0.0.0)(PORT=1522)))

Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=0.0.0.0)(PORT=1522)))
STATUS of the LISTENER
------------------------
Alias                     listener_stdbydb
Version                   TNSLSNR for Linux: Version 19.0.0.0.0 - Production
Start Date                15-MAR-2020 23:05:43
Uptime                    0 days 0 hr. 0 min. 0 sec
Trace Level               off
Security                  ON: Local OS Authentication
SNMP                      OFF
Listener Parameter File   /opt/oracle/product/19c/dbhome_1/network/admin/listener.ora
Listener Log File         /opt/oracle/diag/tnslsnr/oracle-19c-vagrant/listener_stdbydb/alert/log.xml
Listening Endpoints Summary...
  (DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=x.x.x.x)(PORT=1522)))
Services Summary...
Service "STDBYDB" has 1 instance(s).
  Instance "STDBYDB", status UNKNOWN, has 1 handler(s) for this service...
The command completed successfully
STDBYDB_server>
STDBYDB_server>sqlplus '/ as sysdba'

SQL*Plus: Release 19.0.0.0.0 - Production on Sun Mar 15 23:06:07 2020
Version 19.3.0.0.0

Copyright (c) 1982, 2019, Oracle.  All rights reserved.

Connected to an idle instance.

SQL> startup mount;
ORACLE instance started.

Total System Global Area 1207955552 bytes
Fixed Size                  9134176 bytes
Variable Size             436207616 bytes
Database Buffers          754974720 bytes
Redo Buffers                7639040 bytes
Database mounted.
SQL> alter database recover managed standby database disconnect from session;

Database altered.

SQL>



Once the Standby database instance is started I can see entries in the *Standby* database instance alert log file which show that backlog of archivelogs (43 to 46) that were generated in the Primary database instance but hadn't been applied yet  to the Standby (the Standby was shutdown while the Primary was still active):

Completed: ALTER DATABASE   MOUNT
2020-03-15T23:06:22.664060+08:00
 rfs (PID:6164): Primary database is in MAXIMUM PERFORMANCE mode
2020-03-15T23:06:22.756031+08:00
 rfs (PID:6164): Selected LNO:4 for T-1.S-47 dbid 2778483057 branch 1007421686
2020-03-15T23:06:23.159102+08:00
 rfs (PID:6168): Opened log for T-1.S-45 dbid 2778483057 branch 1007421686
2020-03-15T23:06:23.176308+08:00
 rfs (PID:6166): Opened log for T-1.S-43 dbid 2778483057 branch 1007421686
2020-03-15T23:06:23.201644+08:00
 rfs (PID:6170): Opened log for T-1.S-44 dbid 2778483057 branch 1007421686
2020-03-15T23:06:23.266812+08:00
 rfs (PID:6168): Archived Log entry 3 added for B-1007421686.T-1.S-45 ID 0xa59c8470 LAD:2
2020-03-15T23:06:23.342737+08:00
 rfs (PID:6166): Archived Log entry 4 added for B-1007421686.T-1.S-43 ID 0xa59c8470 LAD:2
2020-03-15T23:06:23.353286+08:00
 rfs (PID:6170): Archived Log entry 5 added for B-1007421686.T-1.S-44 ID 0xa59c8470 LAD:2
2020-03-15T23:06:23.402195+08:00
 rfs (PID:6168): Opened log for T-1.S-46 dbid 2778483057 branch 1007421686
2020-03-15T23:06:23.451732+08:00
 rfs (PID:6168): Archived Log entry 6 added for B-1007421686.T-1.S-46 ID 0xa59c8470 LAD:2
2020-03-15T23:06:30.118056+08:00
alter database recover managed standby database disconnect from session
2020-03-15T23:06:30.124297+08:00
Attempt to start background Managed Standby Recovery process (STDBYDB)
Starting background process MRP0
2020-03-15T23:06:30.138764+08:00
MRP0 started with pid=49, OS id=6178
2020-03-15T23:06:30.139465+08:00
Background Managed Standby Recovery process started (STDBYDB)
2020-03-15T23:06:35.172532+08:00
 Started logmerger process
2020-03-15T23:06:35.184395+08:00
PR00 (PID:6184): Managed Standby Recovery starting Real Time Apply
max_pdb is 3
2020-03-15T23:06:35.518115+08:00
Parallel Media Recovery started with 2 slaves
2020-03-15T23:06:35.563095+08:00
stopping change tracking
2020-03-15T23:06:35.733514+08:00
PR00 (PID:6184): Media Recovery Log /opt/oracle/archivelog/STDBYDB/1_43_1007421686.dbf
2020-03-15T23:06:36.129942+08:00
PR00 (PID:6184): Media Recovery Log /opt/oracle/archivelog/STDBYDB/1_44_1007421686.dbf
2020-03-15T23:06:36.142908+08:00
Completed: alter database recover managed standby database disconnect from session
2020-03-15T23:06:39.365000+08:00
PR00 (PID:6184): Media Recovery Log /opt/oracle/archivelog/STDBYDB/1_45_1007421686.dbf
2020-03-15T23:06:40.241700+08:00
PR00 (PID:6184): Media Recovery Log /opt/oracle/archivelog/STDBYDB/1_46_1007421686.dbf
2020-03-15T23:06:40.981414+08:00


Subsequently as redo generation continues on the Primary, the Standby starts showing that it waits for archive logs, applies redo and even does datafile resizes:

PR00 (PID:6184): Media Recovery Waiting for T-1.S-47 (in transit)
2020-03-15T23:06:40.997356+08:00
Recovery of Online Redo Log: Thread 1 Group 4 Seq 47 Reading mem 0
  Mem# 0: /opt/oracle/oradata/STDBYDB/stdbredo01.log
2020-03-15T23:12:52.195417+08:00
Resize operation completed for file# 1, old size 931840K, new size 942080K
2020-03-15T23:13:08.231444+08:00
 rfs (PID:6572): Primary database is in MAXIMUM PERFORMANCE mode
 rfs (PID:6572): Re-archiving LNO:4 T-1.S-47
2020-03-15T23:13:08.489447+08:00
PR00 (PID:6184): Media Recovery Waiting for T-1.S-48
2020-03-15T23:13:08.495944+08:00
 rfs (PID:6572): No SRLs available for T-1
2020-03-15T23:13:08.515405+08:00
 rfs (PID:6572): Opened log for T-1.S-48 dbid 2778483057 branch 1007421686
2020-03-15T23:13:08.516367+08:00
ARC2 (PID:6141): Archived Log entry 7 added for T-1.S-47 ID 0xa59c8470 LAD:1
2020-03-15T23:19:13.700490+08:00
 rfs (PID:6572): Archived Log entry 8 added for B-1007421686.T-1.S-48 ID 0xa59c8470 LAD:2
2020-03-15T23:19:13.769405+08:00
 rfs (PID:6572): Selected LNO:4 for T-1.S-49 dbid 2778483057 branch 1007421686
2020-03-15T23:19:14.445032+08:00
PR00 (PID:6184): Media Recovery Log /opt/oracle/archivelog/STDBYDB/1_48_1007421686.dbf
PR00 (PID:6184): Media Recovery Waiting for T-1.S-49 (in transit)
2020-03-15T23:19:14.947878+08:00
Recovery of Online Redo Log: Thread 1 Group 4 Seq 49 Reading mem 0
  Mem# 0: /opt/oracle/oradata/STDBYDB/stdbredo01.log


Log Group#4  is actually the Standby Redo Log :

{at the Primary}
SQL> select l.group#, f.member
  2  from v$standby_log l, v$logfile f
  3  where l.group#=f.group#
  4  /

    GROUP#
----------
MEMBER
--------------------------------------------------------------------------------
         4
/opt/oracle/oradata/ORCLCDB/stdbredo01.log


SQL>
{at the Standby}
SQL> select l.group#, f.member
  2  from v$standby_log l, v$logfile f
  3  where l.group#=f.group#
  4  /

    GROUP#
----------
MEMBER
--------------------------------------------------------------------------------
         4
/opt/oracle/oradata/STDBYDB/stdbredo01.log


SQL>


I can monitor the Standby with this query :

23:32:25 SQL> l
  1  select thread#, sequence#, group#, client_process, block#, blocks, delay_mins
  2  from v$managed_standby
  3  where thread#=1
  4  and sequence# is not null
  5  and sequence# != 0
  6* order by 1,2
23:32:25 SQL> /

   THREAD#  SEQUENCE# GROUP# CLIENT_P     BLOCK#     BLOCKS DELAY_MINS
---------- ---------- ------ -------- ---------- ---------- ----------
         1         47 4      ARCH          26624        945          0
         1         49 4      ARCH         139264        656          0
         1         50 N/A    N/A               0          0          0
         1         50 2      LGWR             86          1          0

23:32:26 SQL>
23:32:55 SQL> /

   THREAD#  SEQUENCE# GROUP# CLIENT_P     BLOCK#     BLOCKS DELAY_MINS
---------- ---------- ------ -------- ---------- ---------- ----------
         1         47 4      ARCH          26624        945          0
         1         49 4      ARCH         139264        656          0
         1         50 N/A    N/A               0          0          0
         1         50 2      LGWR          65490          3          0

23:32:56 SQL>
23:33:19 SQL> /

   THREAD#  SEQUENCE# GROUP# CLIENT_P     BLOCK#     BLOCKS DELAY_MINS
---------- ---------- ------ -------- ---------- ---------- ----------
         1         47 4      ARCH          26624        945          0
         1         49 4      ARCH         139264        656          0
         1         50 N/A    N/A               0          0          0
         1         50 2      LGWR         133538          1          0

23:33:19 SQL>
23:34:00 SQL> /

   THREAD#  SEQUENCE# GROUP# CLIENT_P     BLOCK#     BLOCKS DELAY_MINS
---------- ---------- ------ -------- ---------- ---------- ----------
         1         47 4      ARCH          26624        945          0
         1         49 4      ARCH         139264        656          0
         1         51 N/A    N/A               9     409600          0
         1         51 3      LGWR              9          1          0

23:34:01 SQL>
23:38:03 SQL> /

   THREAD#  SEQUENCE# GROUP# CLIENT_P     BLOCK#     BLOCKS DELAY_MINS
---------- ---------- ------ -------- ---------- ---------- ----------
         1         47 4      ARCH          26624        945          0
         1         49 4      ARCH         139264        656          0
         1         51 N/A    N/A           66201     409600          0
         1         51 3      LGWR          66201          1          0

23:38:04 SQL>


At my first execution of this query (at 23:32:25), Sequence#50 is the CURRENT Redo Log file in the Primary database.  V$MANAGED_STANDBY on the Standby shows two entries but the active one is the one where it shows that the CLIENT_PROGRAM is the LGWR (Log Writer) on the Primary that is shipping Redo to the Standby.
As transactions occur on the Primary, you can see that the current BLOCK# has also changed for Sequence#50.
When the Primary forces an Archive and Log switch to #51, V$MANAGED_STANDBY now reflects #51 as the redo sequence that is being applied.  Subsequently, the current BLOCK# changes as transactions occur on the Primary.

Thus, this monitoring does show that the Standby is receiving and applying Redo without waiting for actual Archival of the Redo Log file from the Primary.