Real-Time Query for Read-Mostly Applications

Here is one nice little demonstration from my last 11gR2 Data Guard class that I’d like to share with the Oracle Community. It is about enabling Read-Mostly Applications to run on a Physical Standby database, leveraging the 11g New Feature Real-Time Query (part of the Active Data Guard Option). One of the main 11g New Features is the possibility to run Reports anytime on our Physical Standby while it is doing Redo Apply. I have posted about that already here. Now what if we have an Application that is mainly reading but needs to write also to a small amount? That is a problem at first sight:

DGMGRL> show configuration

Configuration - myconf

 Protection Mode: MaxAvailability
 Databases:
 prima - Primary database
 physt - Physical standby database

Fast-Start Failover: DISABLED

Configuration Status:
SUCCESS

DGMGRL> show database physt

Database - physt

 Role:            PHYSICAL STANDBY
 Intended State:  APPLY-ON
 Transport Lag:   0 seconds
 Apply Lag:       0 seconds
 Real Time Query: ON
 Instance(s):
 physt

Database Status:
SUCCESS

This is my (11gR2) Data Guard Configuration. Now my „Read-Mostly Application“ – enter Scott:

SYS@prima > create user scott identified by tiger;

User created.
SYS@prima > alter user scott quota unlimited on users;

User altered.

SYS@prima > grant create session,create table to scott;

Grant succeeded.
SYS@prima > connect scott/tiger@prima

Connected.
SCOTT@prima>  CREATE TABLE DEPT
 (DEPTNO NUMBER(2),
 DNAME VARCHAR2(14),
 LOC VARCHAR2(13) );

INSERT INTO DEPT VALUES (10, 'ACCOUNTING', 'NEW YORK');
INSERT INTO DEPT VALUES (20, 'RESEARCH',   'DALLAS');
INSERT INTO DEPT VALUES (30, 'SALES',      'CHICAGO');
INSERT INTO DEPT VALUES (40, 'OPERATIONS', 'BOSTON');
commit;
Commit complete.

SCOTT@prima > create table flag (database_role varchar2(30), start_date date, end_date date);

Table created.

My Read-Mostly Applications inserts into the flag-table, then run a „huge“ report and inserts into the flag table again:

SCOTT@prima > @report

PL/SQL procedure successfully completed.


1 row created.


Commit complete.


 DEPTNO DNAME          LOC
---------- -------------- -------------
 10 ACCOUNTING     NEW YORK
 20 RESEARCH       DALLAS
 30 SALES          CHICAGO
 40 OPERATIONS     BOSTON


1 row created.


Commit complete.

The content of the report.sql script:

SCOTT@prima > host cat report.sql
vari c char(30)
exec select SYS_CONTEXT('USERENV','DATABASE_ROLE') into :c from dual;
insert into flag values(:c, sysdate,null);
commit;
select * from dept;
insert into flag values(:c, null, sysdate);
commit;

This is right now not possible to run on the Physical Standby because of the insert commands:

SCOTT@prima > connect scott/tiger@physt

Connected.

SCOTT@physt > @report

PL/SQL procedure successfully completed.

insert into flag values(:c, sysdate,null)
 *
ERROR at line 1:
ORA-16000: database open for read-only access

Commit complete.

 DEPTNO DNAME          LOC
---------- -------------- -------------
 10 ACCOUNTING     NEW YORK
 20 RESEARCH       DALLAS
 30 SALES          CHICAGO
 40 OPERATIONS     BOSTON

insert into flag values(:c, null, sysdate)
 *
ERROR at line 1:
ORA-16000: database open for read-only access

Commit complete.

We need to enable that in an Application-Transparent way. Therefore, we create a Dummy-user to switch to silently when Scott accesses the Physical Standby:

SYS@prima > grant create session to rmostly identified by rmostly;

Grant succeeded.

SYS@prima > grant select on scott.dept to rmostly;

Grant succeeded.

SYS@prima > grant all on scott.flag to rmostly;

Grant succeeded.

SYS@prima > grant create synonym to rmostly;

Grant succeeded.

The user rmostly now gets synonyms with the same name as the Original Applications table. The table that need to get inserts is reached via a database link that points to the Primary – modifying it there.

SYS@prima > create public database link prod connect to scott identified by tiger using 'prod';

Database link created.

SYS@prima > connect rmostly/rmostly@prima

Connected.

RMOSTLY@prima > create synonym dept for scott.dept;

Synonym created.

RMOSTLY@prima > create synonym flag for scott.flag@prod;

Synonym created.

The used connect descriptor prod should always lead to the Primary Database even after Role Changes. We will discuss that later on in more detail. Now we need a Logon Trigger that silently switches to the rmostly schema if Scott connects to the Physical Standby:

SYS@prima > CREATE or replace TRIGGER switch_schema_trigger
 AFTER LOGON ON scott.schema
 BEGIN
 IF (SYS_CONTEXT('USERENV','DATABASE_ROLE')
 IN ('PHYSICAL STANDBY'))
 THEN
 execute immediate
 'alter session set current_schema = rmostly';
 END IF;
end;
/
Trigger created.

Also, we need a connect descriptor that always connects Scott to the Physical Standby regardless of Role Changes. Now we are going to setup this part:

SYS@prima > exec dbms_service.create_service('prod','prod')

PL/SQL procedure successfully completed.

SYS@prima > exec dbms_service.create_service('rmostly','rmostly')

PL/SQL procedure successfully completed.

SYS@prima > exec dbms_service.start_service('prod')

PL/SQL procedure successfully completed.

SYS@prima > @physt
Connected.
SYS@physt > exec dbms_service.start_service('rmostly')

PL/SQL procedure successfully completed.

Please notice that the rmostly service was started on the Physical Standby. For now, the services are on the appropriate Database, but the following trigger ensures that this will be still the case after Role Changes like switchover:

SYS@prima > CREATE or replace TRIGGER service_management AFTER STARTUP ON DATABASE
DECLARE
 VROLE VARCHAR(30);
 VOPEN_MODE VARCHAR(30);
BEGIN
 SELECT DATABASE_ROLE INTO VROLE FROM V$DATABASE;
 SELECT OPEN_MODE INTO VOPEN_MODE FROM V$DATABASE;
 IF VROLE = 'PRIMARY' THEN begin
 DBMS_SERVICE.START_SERVICE ('PROD');
 DBMS_SERVICE.STOP_SERVICE ('RMOSTLY');
 end;
 ELSIF VROLE = 'PHYSICAL STANDBY' THEN begin
 IF VOPEN_MODE like 'READ ONLY%' THEN
 DBMS_SERVICE.START_SERVICE ('RMOSTLY');
 END IF;
 DBMS_SERVICE.STOP_SERVICE ('PROD');
 end;
 END IF;
END;
/
Trigger created.

The tnsnames.ora used by the Application Clients looks like this:

$ cat $ORACLE_HOME/network/admin/tnsnames.ora
PROD =
 (DESCRIPTION =
 (ADDRESS_LIST =
 (ADDRESS = (PROTOCOL = TCP)(HOST = uhesse1)(PORT = 1521))
 (ADDRESS = (PROTOCOL = TCP)(HOST = uhesse2)(PORT = 1521))
 )
 (CONNECT_DATA =
 (SERVER = DEDICATED)
 (SERVICE_NAME = prod)
 )
 )

RMOSTLY =
 (DESCRIPTION =
 (ADDRESS_LIST =
 (ADDRESS = (PROTOCOL = TCP)(HOST = uhesse1)(PORT = 1521))
 (ADDRESS = (PROTOCOL = TCP)(HOST = uhesse2)(PORT = 1521))
 )
 (CONNECT_DATA =
 (SERVER = DEDICATED)
 (SERVICE_NAME = rmostly)
 )
 )

In effect, an Application Client connecting to the Physical Standby with RMOSTLY can insert into the Primary table while selecting from the Physical Standby. We assume, that the main part of that Application is doing select, so we have still offloaded the major work from the Primary to the Physical Standby:

SCOTT@rmostly > alter session set nls_date_format='hh24:mi:ss';

Session altered.

SCOTT@rmostly > @report

PL/SQL procedure successfully completed.


1 row created.


Commit complete.


 DEPTNO DNAME          LOC
---------- -------------- -------------
 10 ACCOUNTING     NEW YORK
 20 RESEARCH       DALLAS
 30 SALES          CHICAGO
 40 OPERATIONS     BOSTON


1 row created.


Commit complete.

SCOTT@rmostly > select * from flag;

DATABASE_ROLE                  START_DA END_DATE
------------------------------ -------- --------
PRIMARY                        14:24:35
PRIMARY                                 14:24:35
PHYSICAL STANDBY               14:53:21
PHYSICAL STANDBY                        14:53:21

The SQL prompt BTW changes accordingly because of this little login.sql:

SCOTT@rmostly > host cat login.sql
set lines 800
set pages 300
column name format a50
column file_name format a50
column client_info format a10
column machine format a20
column MASTER_LINK format a10
column parameters format a10
column def_parameters format a10
SET SQLPROMPT "_USER'@'_CONNECT_IDENTIFIER > "

Conclusion: We can even offload Read-Mostly Applications to Physical Standby Databases in 11g with little effort!

, , ,

  1. #1 von mdinh am November 14, 2010 - 15:36

    Just wanted to share with you the new column GAP_STATUS from v$archive_dest_status which makes monitoring redo apply much easier in 11.2.0.2 http://mdinh.wordpress.com/2010/11/11/data-guard-monitor-redo-apply-11-2-0-2/

  2. #2 von Uwe Hesse am November 15, 2010 - 11:46

    Thank you for this information!

  3. #3 von Mathias Zarick am September 21, 2011 - 15:11

    Hi Uwe,
    very cool demo. For me a little pitty as it seems that this trick only works with a public database link. With private database links it did not work for me. For security reasons a public database link cannot be used.
    Cheers Mathias

  4. #4 von Uwe Hesse am September 21, 2011 - 16:10

    Hi Matthias,
    thank you for stopping by and sharing that information!

    Funny thing is that I was just presenting that very same demonstration during my current Data Guard course in Vienna. Thought at first that one of the attendees commented 🙂

  5. #5 von Jun Santos am November 28, 2014 - 12:12

    Hi Uwe,

    I want to thank you for sharing this info and it was very helpful to us. However, I read from one of your powerpoint presentations that this will not work for insert statements inside stored procedures?

    Could you confirm on this? We will also test this next week if that is truly the case.

    Thank you very much and more power.

    Best regards,

    Jun

  1. Real-Time Query and Automatic Block Media Recovery in 11gR2 « The Oracle Instructor

Hinterlasse einen Kommentar

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