Create a Standby Instance

Create a standby cloud instance from the primary database.

Create an Archive Log

Check the log mode of your on-premises Oracle Exadata Database Machine. If it's in NOARCHIVELOG mode, then change it to ARCHIVELOG mode to create an archive log.

  1. View the log mode for the on-premises server.
    SQL> select log_mode from v$database;
    The output will look similar to the following when the log mode is in NOARCHIVELOG mode:
    LOG_MODE
    ------------
    NOARCHIVELOG
  2. Shut down the on-premises instance.
    SQL> shutdown immediate;
    The output will look similar to the following:
    Database closed.
    Database dismounted.
    ORACLE instance shut down.
  3. Mount the on-premises database.
    SQL> startup mount;
    The output will look similar to the following:
    ORACLE instance started.
    
    Total System Global Area 4966054520 bytes
    Fixed Size		    9144952 bytes
    Variable Size		  922746880 bytes
    Database Buffers	 4026531840 bytes
    Redo Buffers		    7630848 bytes
    Database mounted.
  4. Alter the database archive log, then open the database.
    SQL> alter database archivelog;
    SQL> alter database open;
  5. Change the log mode to ARCHIVELOG.
    SQL> select log_mode from v$database;
    LOG_MODE
    ------------
    ARCHIVELOG
  6. Display the archive log list.
    SQL> archive log list;
    The output will look similar to the following:
    Database log mode
           Archive Mode
    Automatic archival
           Enabled
    Archive destination
           USE_DB_RECOVERY_FILE_DEST
    Oldest online log sequence     4
    Next log sequence to archive   7
    Current log sequence           7
  7. Archive all logs.
    SQL> archive log all;
    ORA-00271:there are no logs that need archiving

Instantiate the Standby Database on OCI

Instantiate the standby Oracle Database Exadata Cloud Service database.

  1. Stop or shutdown the Oracle Database Exadata Cloud Service database using the srvctl utility.
    • $ srvctl stop database -d standby DB_UNIQUE_NAME -o immediate
    • $ srvctl stop database -d DB1_phx3g7 -o immediate
  2. Connect to the database.
    SQL> startup nomount;
  3. On the primary on-premises Oracle Exadata Database Machine, run the following series of commands to force logging and define the log file.
    SQL> alter database force logging;
    SQL> set linesize 500 pages 0                                                                                                    
    SQL> col value for a90
    SQL> col name for a50
    SQL> select name, value from v$parameter where name in 
    ('db_name','db_unique_name','log_archive_config', 
    'log_archive_dest_1','log_archive_dest_2','log_archive_dest_state_1','log_archive_de
    st_state_2', 'remote_login_passwordfile', 
    'log_archive_format','log_archive_max_processes','fal_server','db_file_name_convert'
    ,'log_file_name_convert', 'standby_file_management');
    The output will look similar to the following:
    db_file_name_convert
    log_file_name_convert
    log_archive_dest_1
    location=USE_DB_RECOVERY_FILE_DEST 
    valid_for=(ALL_LOGFILES,ALL_ROLES) MAX_FAILURE=1 REOPEN
    =5 DB_UNIQUE_NAME=db1 ALTERNATE=LOG_ARCHIVE_DEST_2
    log_archive_dest_2
    location=+DATAC1 
    valid_for=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=db1 ALTERNATE=LOG_ARCHI
       VE_DEST_1
    log_archive_dest_state_1                   ENABLE
    log_archive_dest_state_2                   ALTERNATE
    fal_server
    log_archive_config
    log_archive_format                         %t_%s_%r.dbf
    log_archive_max_processes                  4
    standby_file_management                    MANUAL
    remote_login_passwordfile                  EXCLUSIVE
    db_name                                    db1
    db_unique_name                             db1
    14 rows selected.
  4. Set the standby file management.
    SQL> ALTER SYSTEM SET STANDBY_FILE_MANAGEMENT=AUTO SID='*';
  5. On the primary on-premises Oracle Exadata Database Machine, define the following parameters for log archive and standby management.
    LOG_ARCHIVE_CONFIG='DG_CONFIG=(PROD1,STAND1)'
    LOG_ARCHIVE_DEST_1='LOCATION=USE_DB_RECOVERY_FILE_DEST 
    VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=PROD1'
    LOG_ARCHIVE_DEST_2='SERVICE=STAND1 VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) 
    DB_UNIQUE_NAME=STAND1'
    LOG_ARCHIVE_DEST_STATE_1=ENABLE
    LOG_ARCHIVE_DEST_STATE_2=ENABLE
    REMOTE_LOGIN_PASSWORDFILE=EXCLUSIVE
    LOG_ARCHIVE_FORMAT=%t_%s_%r.arc
    LOG_ARCHIVE_MAX_PROCESSES=8
    FAL_SERVER=STAND1
    DB_FILE_NAME_CONVERT='STAND1',' PROD1'
    LOG_FILE_NAME_CONVERT= 'STAND1',' PROD1'
    STANDBY_FILE_MANAGEMENT=AUTO
    The following sample includes the parameter values:
    ALTER SYSTEM SET LOG_ARCHIVE_CONFIG='DG_CONFIG=(DB1, DB1_phx3g7)';
    ALTER SYSTEM SET LOG_ARCHIVE_DEST_1='LOCATION=USE_DB_RECOVERY_FILE_DEST 
    VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=DB1';
    ALTER SYSTEM SET LOG_ARCHIVE_DEST_2='SERVICE=DB1_phx3g7 
    VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=DB1_phx3g7’;
    ALTER SYSTEM SET LOG_ARCHIVE_DEST_STATE_1=ENABLE;
    ALTER SYSTEM SET LOG_ARCHIVE_DEST_STATE_2=DEFER;
    ALTER SYSTEM SET FAL_SERVER=DB1_phx3g7;
    ALTER SYSTEM SET FAL_CLIENT=DB1;
    ALTER SYSTEM SET DB_FILE_NAME_CONVERT='DB1_phx3g7','DB1' scope=spfile;
    ALTER SYSTEM SET LOG_FILE_NAME_CONVERT='DB1_phx3g7','DB1' scope=spfile;
    ALTER SYSTEM SET STANDBY_FILE_MANAGEMENT=AUTO;
  6. On the primary on-premises Oracle Exadata Database Machine, log in as sysdba, then run the following series of commands to force logging.
    $ sqlplus / as sysdba
    SQL> ALTER SYSTEM SET LOG_ARCHIVE_CONFIG='DG_CONFIG=(DB1, DB1_phx3g7)';
    System altered.
    SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_1='LOCATION=USE_DB_RECOVERY_FILE_DEST 
    VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=DB1';
    System altered.
    SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_2='SERVICE=DB1_phx3g7 
    VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=DB1_phx3g7';
    System altered.
    SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_STATE_1=ENABLE;
    System altered.
    SQL> ALTER SYSTEM SET LOG_ARCHIVE_DEST_STATE_2=DEFER;
    System altered.
    SQL> ALTER SYSTEM SET REMOTE_LOGIN_PASSWORDFILE=EXCLUSIVE;
    ERROR at line 1:
    ORA-02095: specified initialization parameter cannot be modified
    SQL> ALTER SYSTEM SET FAL_SERVER=DB1_phx3g7;             
    System altered.
    SQL> ALTER SYSTEM SET FAL_CLIENT=DB1;
    System altered.
    SQL> ALTER SYSTEM SET DB_FILE_NAME_CONVERT='DB1_phx3g7','DB1' scope=spfile;
    System altered.
    SQL> ALTER SYSTEM SET LOG_FILE_NAME_CONVERT= 'DB1_phx3g7','DB1' scope=spfile;
    System altered.
    SQL> ALTER SYSTEM SET STANDBY_FILE_MANAGEMENT=AUTO;
    System altered.
    Do not create a pfile on the primary on-premises Oracle Exadata Database Machine. Instead, use the default Pfile created by the Oracle Database Exadata Cloud Service.
  7. On the standby Oracle Database Exadata Cloud Service, log in as sysdba, then start the instance without mounting the database.
    $ sqlplus / as sysdba
    SQL> startup nomount;
  8. On the standby Oracle Database Exadata Cloud Service, run the following series of commands to define the server, logging, and file management.
    alter system set fal_server='DB1' scope =spfile;
    alter system set fal_client='DB1_PHX3G7' scope =spfile;
    alter system set log_archive_config='DG_CONFIG=(DB1, DB1_phx3g7)' scope =spfile;
    alter system set log_archive_dest_1='LOCATION=USE_DB_RECOVERY_FILE_DEST 
    VALID_FOR=(ALL_LOGFILES,ALL_ROLES) DB_UNIQUE_NAME=DB1_PHX3G7' scope =spfile;
    alter system set log_archive_dest_2='SERVICE=DB1 
    VALID_FOR=(ONLINE_LOGFILES,PRIMARY_ROLE) DB_UNIQUE_NAME=DB1' scope =spfile;
    alter system set log_archive_dest_state_1='ENABLE' scope =spfile;
    alter system set log_archive_dest_state_2='ENABLE' scope =spfile;
    alter system set log_archive_format='%t_%s_%r.dbf' scope =spfile;
    alter system set log_file_name_convert='DB1','DB1_phx3g7' scope =spfile;
    alter system set db_file_name_convert='DB1','DB1_phx3g7' scope =spfile;
    alter system set remote_login_passwordfile='exclusive' scope =spfile;
    alter system set standby_file_management='AUTO' scope =spfile;
  9. On the standby Oracle Database Exadata Cloud Service, use Oracle Recovery Manager (RMAN) to define a test target and standby in the cloud, then run RMAN to create the standby.
    rman target sys/Test_Dr_123@DB1 auxiliary sys/Test_Dr_123@DB1_Phx3g7
    The output will be similar to the following:
    connected to target database: DB1 (DBID=1657313530)
    connected to auxiliary database: DB1 (not mounted)
    RMAN> run
  10. On the standby Oracle Database Exadata Cloud Service, log in as sysdba, then disconnect from the session.
    $ sqlplus / as sysdba
    SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
  11. On the standby Oracle Database Exadata Cloud Service, view the logs to verify that the Media recovery is in Transit.
    [oracle@exacs82-vm3sv1 DB11]$ pwd /u02/app/oracle/diag/rdbms/db1_phx3g7/DB11
    [oracle@exacs82-vm3sv1 trace]$ tail -f alert_DB11.log 
    The output will include a line similar to the following:
    PR00 (PID:253670): Media Recovery Waiting for T-1.S-125 (in transit)
  12. On the primary on-premises Oracle Exadata Database Machine, log in to sqlplus as sysdba, then run the following series of sql commands to switch the log file.
    $ sqlplus / as sysdba
    SQL> alter system switch logfile;
    SQL> /
    SQL> /
    SQL> /
  13. On the standby Oracle Database Exadata Cloud Service, log in as sysdba, then run the following series of commands.
    SQL> SELECT ARCH.THREAD# "Thread", ARCH.SEQUENCE# "Last Sequence Received", APPL.SEQUENCE# 
    "Last Sequence Applied", (ARCH.SEQUENCE# - APPL.SEQUENCE#) "Difference" FROM (SELECT 
    THREAD#,SEQUENCE# FROM V$ARCHIVED_LOG WHERE (THREAD#,FIRST_TIME ) IN (SELECT 
    THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)) ARCH,(SELECT THREAD# 
    ,SEQUENCE# FROM V$LOG_HISTORY WHERE (THREAD#,FIRST_TIME ) IN (SELECT 
    THREAD#,MAX(FIRST_TIME) FROM V$LOG_HISTORY GROUP BY THREAD#)) APPL WHERE ARCH.THREAD# = 
    APPL.THREAD# ORDER BY 1;
    Thread     Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              124                  124                  0
     2               26                   26                  0
    SQL> /
    Thread     Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              124                124                      0
     2               26                 26                      0
    SQL> /
    Thread     Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              130                    128                  2
     2               27                     27                  0
    SQL> /
    Thread     Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              130                    128                  2
     2               27                     27                  0
    SQL> /
    Thread     Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              130                    130                 0
     2               28                     28                 0
  14. On the standby Oracle Database Exadata Cloud Service, log in as sysdba, then run the following series of commands.
    SQL> alter database recover managed
          standby database cancel;
    SQL> show parameter cluster
    NAME                                 TYPE          VALUE
    ------------------------------------ ----------- ------------------------------
    cdb_cluster                           boolean        FALSE
    cdb_cluster_name                      string
    cluster_database                      boolean        FALSE
    cluster_database_instances            integer         1
    cluster_interconnects                 string         192.0.2.22:192.0.2.23
    SQL> alter system set cluster_database=TRUE scope=spfile;
    System altered.
    SQL> alter system set cluster_database=TRUE scope=spfile;
    SQL> show parameter cluster;
    NAME                                  TYPE           VALUE
    ------------------------------------ ----------- ------------------------------
    cdb_cluster                             boolean         FALSE
    cdb_cluster_name                        string
    cluster_database                        boolean         FALSE
    cluster_database_instances              integer         1
    cluster_interconnects                   string         192.0.2.22:192.0.2.23
    SQL> /
    System altered.
    SQL> show parameter pluggable;
    NAME                                 TYPE             VALUE
    ------------------------------------ ----------- ------------------------------
    enable_pluggable_database             boolean         FALSE
    SQL> shutdown;
    ORA-01109: database not open
    Database dismounted.
    ORACLE instance shut down.
  15. On the standby Oracle Database Exadata Cloud Service, display the status of the resources and confirm that they are all online.
    [grid@exacs82-vm3sv1 ~]$ crsctl stat res
    The output will include the type, target status, and state for each resource. For example, :
    NAME=ora.ASMNET1LSNR_ASM.lsnr(ora.asmgroup)
    TYPE=ora.asm_listener.type
    TARGET=ONLINE                  , ONLINE
    STATE=ONLINE on exacs82-vm3sv1, ONLINE on exacs82-vm3sv2
    
    NAME=ora.DATAC1.ACFSVOL01.advm
    TYPE=ora.volume.type
    TARGET=ONLINE                  , ONLINE
    STATE=ONLINE on exacs82-vm3sv1, ONLINE on exacs82-vm3sv2
    
    NAME=ora.DATAC1.dg(ora.asmgroup)
    TYPE=ora.diskgroup.type
    TARGET=ONLINE                  , ONLINE
    STATE=ONLINE on exacs82-vm3sv1, ONLINE on exacs82-vm3sv2
    NAME=ora.LISTENER.lsnr
    TYPE=ora.listener.type
    TARGET=ONLINE                  , ONLINE
    STATE=ONLINE on exacs82-vm3sv1, ONLINE on exacs82-vm3sv2
    .
    .
    .
  16. On the standby Oracle Database Exadata Cloud Service, start and mount the database.
    [oracle@exacs82-vm3sv1 ~]$ source DB1.env 
    [oracle@exacs82-vm3sv1 ~]$ srvctl start database -db db1_phx3g7 -startoption mount
  17. On Node 1 of the standby Oracle Database Exadata Cloud Service, log in as sysdba, mount the database in open_mode, then exit.
    oracle@exacs82-vm3sv1
    SQL> select open_mode from v$database;
    The output will be similar to the following:
    OPEN_MODE
    --------------------
    MOUNTED
    SQL> exit
  18. On Node 2 of the standby Oracle Database Exadata Cloud Service, log in as sysdba, mount the database in open_mode, then exit.
    oracle@exacs82-vm3sv2
    SQL> select open_mode from v$database;
    The output will be similar to the following:
    OPEN_MODE
    --------------------
    MOUNTED
    SQL> exit
  19. Disconnect from the session.
    SQL> ALTER DATABASE RECOVER MANAGED STANDBY DATABASE DISCONNECT FROM SESSION;
    The output will be similar to the following:
  20. On the primary on-premises Oracle Exadata Database Machine, run the following series of SQL commands for the log file.
    SQL> alter database force logging;
    SQL> /
    SQL> /
  21. On the standby Oracle Database Exadata Cloud Service, log in as sysdba, then run the following series of commands.
    SQL> SELECT ARCH.THREAD# "Thread", ARCH.SEQUENCE# "Last Sequence Received", APPL.SEQUENCE# 
    "Last Sequence Applied", (ARCH.SEQUENCE# - APPL.SEQUENCE#) "Difference" FROM (SELECT 
    THREAD#,SEQUENCE# FROM V$ARCHIVED_LOG WHERE (THREAD#,FIRST_TIME ) IN (SELECT 
    THREAD#,MAX(FIRST_TIME) FROM V$ARCHIVED_LOG GROUP BY THREAD#)) ARCH,(SELECT THREAD# 
    ,SEQUENCE# FROM V$LOG_HISTORY WHERE (THREAD#,FIRST_TIME ) IN (SELECT 
    THREAD#,MAX(FIRST_TIME) FROM V$LOG_HISTORY GROUP BY THREAD#)) APPL WHERE ARCH.THREAD# = 
    APPL.THREAD# ORDER BY 1;
    Thread     Last Sequence Received  Last Sequence Applied  Difference
    ---------- ----------------------  ---------------------  ----------
     1          161                        161                      0
     2           41                         41                      0
    SQL> /
    Thread     Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1          161                   161                      0
     2           41                   41                       0
    SQL> /
    Thread Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1          161                    161                    0
     2           41                     41                    0
    SQL> /
    Thread Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              163                161                      2
     2               41                 41                      0
    SQL> /
    Thread Last Sequence Received Last Sequence Applied Difference
    ---------- ---------------------- --------------------- ----------
     1              163                    161                  2
     2               41                     41                  0
    SQL> /
    Thread Last  Sequence Received     Last Sequence Applied  Difference
    ----------   ---------------------- ---------------------  ----------
     1              163                    163                      0
     2               42                     42                      0
  22. On the primary on-premises Oracle Exadata Database Machine, verify that the tnsnames.ora file is properly configured for the following:
    DB1 =
      (DESCRIPTION =
        (ADDRESS = (PROTOCOL = TCP)(HOST = exa11-scan1)(PORT = 1521))
        (CONNECT_DATA =
          (SERVER = DEDICATED)
    (SERVICE_NAME = db1.us.osc.oracle.com)
          (INSTANCE_NAME = db12)
        )
      )
    DB1_phx3g7 =
      (DESCRIPTION =
        (SDU = 65536)
        (RECV_BUF_SIZE = 134217728)
        (SEND_BUF_SIZE = 134217728)
        (ADDRESS_LIST =
          (CONNECT_TIMEOUT = 3)
          (RETRY_COUNT = 3)
          (ADDRESS = (PROTOCOL = TCP)(HOST = 10.255.195.136)(PORT = 1521))
        )
        (CONNECT_DATA =
          (SERVER = DEDICATED)
          (SERVICE_NAME = DB1_phx3g7.datasubnetactiv.oscphevcn.oraclevcn.com)
          (UR = A)
        )
      )
    Verify the tnsnames for the on-premises database (db1):
    [oracle@exa11db01 admin]$ tnsping db1
    Used parameter files:
    /u01/app/oracle/product/19.0.0.0/dbhome_1/network/admin/sqlnet.ora
    Used TNSNAMES adapter to resolve the alias
    Attempting to contact (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = exa11-scan1)(PORT = 
    1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = db1.us.osc.oracle.com) 
    (INSTANCE_NAME = db11)))
    OK (0 msec)
    Verify the tnsnames for the Oracle Database Exadata Cloud Service instance (DB1_phx3g7):
    [oracle@exa11db01 admin]$ tnsping DB1_phx3g7
    TNS Ping Utility for Linux: Version 19.0.0.0.0 - Production on 05-FEB-2021 16:19:15
    Copyright (c) 1997, 2020, Oracle.  All rights reserved.
    Used parameter files:
    /u01/app/oracle/product/19.0.0.0/dbhome_1/network/admin/sqlnet.ora
    Used TNSNAMES adapter to resolve the alias
    Attempting to contact (DESCRIPTION = (SDU = 65536) (RECV_BUF_SIZE = 134217728) 
    (SEND_BUF_SIZE = 134217728) (ADDRESS_LIST = (CONNECT_TIMEOUT = 3) (RETRY_COUNT = 3) 
    (ADDRESS = (PROTOCOL = TCP)(HOST = 10.255.195.136)(PORT = 1521))) (CONNECT_DATA = (SERVER = 
    DEDICATED) (SERVICE_NAME = DB1_phx3g7.datasubnetactiv.oscphevcn.oraclevcn.com) (UR = A)))
    OK (40 msec)
  23. On the standby Oracle Database Exadata Cloud Service, verify that the tnsnames.ora file is properly configured for the following:
    db1 = 
    (DESCRIPTION = 
    (SDU=65536) (RECV_BUF_SIZE=134217728) 
    (SEND_BUF_SIZE=134217728) 
    (ADDRESS_LIST = 
    (CONNECT_TIMEOUT=3)(RETRY_COUNT=3)
    (ADDRESS = (PROTOCOL = TCP)(HOST = 10.136.74.18)(PORT = 1521)) 
    ) 
    (CONNECT_DATA = 
    (SERVER = DEDICATED) 
    (SERVICE_NAME = db1.us.osc.oracle.com) 
    (UR=A) 
    )
             ) 
    DB1_phx3g7 =
      (DESCRIPTION =
        (SDU = 65536)
        (RECV_BUF_SIZE = 134217728)
        (SEND_BUF_SIZE = 134217728)
        (ADDRESS_LIST =
          (CONNECT_TIMEOUT = 3)
          (RETRY_COUNT = 3)
          (ADDRESS = (PROTOCOL = TCP)(HOST = 10.255.195.136)(PORT = 1521))
        )
        (CONNECT_DATA =
          (SERVER = DEDICATED)
          (SERVICE_NAME = DB1_phx3g7.datasubnetactiv.oscphevcn.oraclevcn.com)
          (INSTANCE_NAME = DB12)
          (UR = A)
        )
      )
    Verify the tnsnames for the on-premises database (db1):
    [oracle@exacs82-vm3sv2 DB1]$ tnsping db1
    TNS Ping Utility for Linux: Version 19.0.0.0.0 - Production on 05-FEB-2021 16:34:59
    Copyright (c) 1997, 2020, Oracle.  All rights reserved.
    Used parameter files:
    /u02/app/oracle/product/19.0.0.0/dbhome_5/network/admin/DB1/sqlnet.ora
    Used TNSNAMES adapter to resolve the alias
    Attempting to contact (DESCRIPTION = (SDU=65536) (RECV_BUF_SIZE=134217728) 
    (SEND_BUF_SIZE=134217728) (ADDRESS_LIST = (CONNECT_TIMEOUT=3)(RETRY_COUNT=3) (ADDRESS = 
    (PROTOCOL = TCP)(HOST = 10.136.74.18)(PORT = 1521))) (CONNECT_DATA = (SERVER = DEDICATED) 
    (SERVICE_NAME = db1.us.osc.oracle.com) (UR=A)))
    OK (40 msec)
    Verify the tnsnames for the Oracle Database Exadata Cloud Service instance (DB1_phx3g7):
    [oracle@exacs82-vm3sv2 DB1]$ tnsping DB1_phx3g7
    TNS Ping Utility for Linux: Version 19.0.0.0.0 - Production on 05-FEB-2021 16:35:15
    Copyright (c) 1997, 2020, Oracle.  All rights reserved.
    Used parameter files:
    /u02/app/oracle/product/19.0.0.0/dbhome_5/network/admin/DB1/sqlnet.ora
    Used TNSNAMES adapter to resolve the alias
    Attempting to contact (DESCRIPTION = (SDU = 65536) (RECV_BUF_SIZE = 134217728) 
    (SEND_BUF_SIZE = 134217728) (ADDRESS_LIST = (CONNECT_TIMEOUT = 3) (RETRY_COUNT = 3) 
    (ADDRESS = (PROTOCOL = TCP)(HOST = 10.255.195.136)(PORT = 1521))) (CONNECT_DATA = (SERVER = 
    DEDICATED) (SERVICE_NAME = DB1_phx3g7.datasubnetactiv.oscphevcn.oraclevcn.com) 
    (INSTANCE_NAME = DB12) (UR = A)))
    OK (0 msec)