After startup trigger on RAC

Recently, a colleague of mine had some problems with pinning application procedures into the shared pool. His database was upgraded to RAC and he wanted to pin the application procedures and packages into shared pool upon the database startup.
The non-RAC version of the database was using a shell script, something like $ORACLE_HOME/local/scripts/pin_procs.sh in the script that was starting DB when the system was booted
However, RAC starts the database automatically and no user scripts are invoked during startup. The alternative mechanism is to use a startup database trigger. The only question that remains is whether the trigger will file once for each instance or once for the database? The trigger will fire once for each instance. Let’s demonstrate the statement:

mgogala@umajor:~$ ssh oracle@rac1
Last login: Sat Aug 8 19:36:48 2015
[oracle@rac1 ~]$ srvctl start db -d orcl
[oracle@rac1 ~]$ srvctl status db -d orcl
Instance orcl2 is running on node rac1
Instance orcl1 is running on node rac2
[oracle@rac1 ~]$ srvctl config db -d orcl
Database unique name: orcl
Database name: orcl
Oracle home: /home/oracle/app/oracle/product/11.2.0/dbhome_1
Oracle user: oracle
Spfile: +DATA/orcl/spfileorcl.ora
Domain:
Start options: open
Stop options: immediate
Database role: PRIMARY
Management policy: AUTOMATIC
Server pools: orcl
Database instances: orcl2,orcl1
Disk Groups: DATA,REDO
Mount point paths:
Services:
Type: RAC
Database is administrator managed
[oracle@rac1 ~]$

This is a little 11.2.0.4 RAC database, running on two nodes. The proof will be achieved by creating a trigger which inserts the instance id and the host name into a table. If the table contains only a single record, the trigger have fired only once. If there are two records, with two different instance numbers and machine names, the trigger has fired twice, just as was the original statement. So, let’s first create a table in the SCOTT schema:
Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
With the Partitioning, Real Application Clusters, Automatic Storage Management, OLAP,
Data Mining and Real Application Testing options

SQL> create table startup(
2 inst_num integer,
3 inst_host varchar2(128));

Table created.

Elapsed: 00:00:00.11
SQL> grant insert on startup to system;

Grant succeeded.

Elapsed: 00:00:00.01

Next comes the trigger in the SYSTEM schema, because login triggers can only be created by the schema with the DBA privilege.

SQL> connect system@rac11
Enter password:
Connected.
CREATE OR REPLACE TRIGGER system.start_me_up AFTER startup ON DATABASE
DECLARE
instance_num INTEGER;
host VARCHAR2(128);
BEGIN
SELECT instance_number,host_name INTO INSTANCE_NUM,HOST FROM v$instance;
INSERT INTO scott.startup VALUES (instance_num,host);
END;
9 /

Trigger created.

Elapsed: 00:00:00.26

Now, the moment of truth. Let’s restart the database and see what is in the SCOTT.STARTUP table. First, the restart:

[oracle@rac1 ~]$ srvctl stop db -d orcl -o immediate
[oracle@rac1 ~]$ srvctl status db -d orcl
Instance orcl2 is not running on node rac1
Instance orcl1 is not running on node rac2
[oracle@rac1 ~]$ srvctl start db -d orcl
[oracle@rac1 ~]$ srvctl status db -d orcl
Instance orcl2 is running on node rac1
Instance orcl1 is running on node rac2
[oracle@rac1 ~]$

Now, let’s check SCOTT.STARTUP:
mgogala@umajor:~$ sqlplus scott/tiger@rac11

SQL*Plus: Release 12.1.0.2.0 Production on Wed Aug 12 18:32:01 2015

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

Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
With the Partitioning, Real Application Clusters, Automatic Storage Management, OLAP,
Data Mining and Real Application Testing options

SQL> column inst_host format a10;
SQL> select * from startup;

INST_NUM INST_HOST
---------- ----------
2 rac1
1 rac2

Elapsed: 00:00:00.01
SQL>

The table contains two records, once for each instance. That proves that the startup trigger will fire once for each instance. This also provides the mechanism for doing different things after starting different instances because it would be trivial to add IF … THEN clause based on the instance number. However, in this particular case, the task was to pin the same set of the application procedures in both instances. This was accomplished by the database trigger.

Advertisements

About mgogala

I am a long time Oracle DBA, who has worked on very large databases. I have worked with OPS and RAC since its inception.I am also a published book writer, having published two books about PHP. This blog is about the challenges and adventures in my professional life. Sorry, no family pictures here.
This entry was posted in Uncategorized. Bookmark the permalink.

One Response to After startup trigger on RAC

  1. What I always tell my students. You Startup an Instance, you Open the Database (access to the database). The STARTUP command operates for an INSTANCE.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s