Jan 30, 2016

Table Fragmentation in Oracle Database - to get performance benifit

Some times In oracle schema you may found some tables which has huge difference in actual size (size from User_segments) and expected size from user_tables (Num_rows*avg_row_length (in bytes)). This all is due to fragmentation in the table or stats for table are not updated into user_tables.

We will discuss:
1) What is Table Fragmentation?
2) How to understand HWM (High Water Mark) in table?
3) What are the reasons to reorganization of table?
4) How to find most fragmented tables?
5) How to reset HWM / remove fragmentation?
6) How to get more performance benefits from most fragmented tables?
7) Demo

1) What is Table Fragmentation?

If a table is only subject to inserts, there will not be any fragmentation. Fragmentation comes with when we update/delete data in table. The space which gets freed up during non-insert DML operations is not immediately re-used (or sometimes, may not get  reuse ever at all). This leaves behind holes in table which results in table fragmentation.

To understand it more clearly, we need to be clear on how oracle manages space for tables.

When rows are not stored contiguously, or if rows are split onto more than one block, performance decreases because these rows require additional block accesses.

Note that table fragmentation is different from file fragmentation. When a lot of DML operations are applied on a table, the table will become fragmented because DML does not release free space from the table below the HWM.(High Water Mark).

2) How to understand HWM (High Water Mark) in table?

HWM is an indicator of USED BLOCKS in the database. Blocks below the high water mark (used blocks) have at least once contained data. This data might have been deleted. Since Oracle knows that blocks beyond the high water mark don't have data, it only reads blocks up to the high water mark when doing a full table scan.

DDL statement always resets the HWM.

3) What are the reasons to reorganization of table?

a) Slower response time (from that table)
b) High number of chained (actually migrated) rows. 
c) Table has grown many folds and the old space is not getting reused.

Note: Index based queries may not get that much benefited by reorg as compared to queries which does Full table 
scan.

4) How to find most fragmented tables?

In Oracle schema there are tables which has huge difference in actual size (size from User_segments) and expected size from user_tables (Num_rows*avg_row_length (in bytes)). This all is due to fragmentation in the table or stats for table are not updated into dba_tables.

5) What actions to be taken on most fragmented tables?

Steps to Check and Remove Table Fragmentation:- 

i)  Gather table stats:

To check exact difference in table actual size (dba_segments) and stats size (dba_tables). The difference between these value will report actual fragmentation to DBA. So, We have to have updated stats on the table stored in dba_tables. Check LAST_ANALYZED value for table in dba_tables. If this value is recent you can skip this step. Other wise i would suggest to gather table stats to get updated stats.

exec dbms_stats.gather_table_stats('&schema_name','&table_name');

ii) Check Table size:

Now again check table size using and will find reduced size of the table.

select table_name,bytes/(1024*1024*1024) 
from dba_table 
where table_name='&table_name';  -- keep a track to match after fragmentation 

iii) Check for Fragmentation in table:

Below query will show the total size of table with fragmentation, expected without fragmentation and how much % of size we can reclaim after removing table fragmentation. Database Administrator has to provide table_name and schema_name as input to this query.

SQL> set pages 50000 lines 32767;
SQL> select owner,
       table_name,
       round((blocks * 8), 2) || 'kb' "Fragmented size",
       round((num_rows * avg_row_len / 1024), 2) || 'kb' "Actual size",
       round((blocks * 8), 2) - round((num_rows * avg_row_len / 1024), 2) || 'kb',
       ((round((blocks * 8), 2) - round((num_rows * avg_row_len / 1024), 2)) /
       round((blocks * 8), 2)) * 100 - 10 "reclaimable space % "
  from dba_tables
 where table_name = '&table_Name'
   AND OWNER LIKE '&schema_name';
/

Note: This query fetch data from dba_tables, so the accuracy of result depends on dba_table stats.
To find Top 10 fragmentation tables
SQL> select *
      from (select table_name,
               round((blocks * 8), 2) "size (kb)",
               round((num_rows * avg_row_len / 1024), 2) "actual_data (kb)",
               (round((blocks * 8), 2) -
               round((num_rows * avg_row_len / 1024), 2)) "wasted_space (kb)"
          from dba_tables
         where (round((blocks * 8), 2) >
               round((num_rows * avg_row_len / 1024), 2))
         order by 4 desc)
 WHERE ROWNUM <= 10;
SQL> If you find reclaimable space % value more than 20% then we can expect fragmentation in the table.

 Suppose, DBA find 50% reclaimable space by above query, So he can proceed for removing fragmentation.

5) How to reset HWM / remove fragmentation?

We have three options to reorganize fragmented tables:

1. Alter table move (to another tablespace, or same tablespace) and rebuild indexes:- 
   (Depends upon the free space available in the tablespace)  
2. Export and import the table:- (difficult to implement in production environment)
3. Shrink command (from Oracle 10g onwards)
   (Shrink command is only applicable for tables which are tablespace with auto segment space management)

Here, I am following Options 1 and 3 option by keeping table availability in mind. 

Option: 1 

Alter table move (to another tablespace, or same tablespace) and rebuild indexes:-
Collect status of all the indexes on the table:-

We will record Index status at one place, So that we get back them after completion of this exercise,  

SQL> select index_name,status from dba_indexes 

where table_name like '&table_name';

Move table in to same or new tablespace:
---------------------------------------
In this step we will move fragmented table to same tablespace or from one tablespace to another tablespace to reclaim fragmented space. Find Current size of you table from dba_segments and check if same or any other tablespace has same free space available. So, that we can move this table to same or new tablespace.

Steps to Move table in to same tablespace:

-----------------------------------------
alter table <table_name> move;   ------> Move to same tablespace

OR

Steps to Move table in to new tablespace:
----------------------------------------
alter table <table_name> enable row movement;
alter table <table_name> move tablespace <new_tablespace_name>;

Now, get back table to old tablespaces using below command

alter table table_name move tablespace old_tablespace_name;

Now,Rebuild all indexes:
-----------------------
We need to rebuild all the indexes on the table because of move command all the index goes into unusable state.

SQL> select status,index_name from dba_indexes where table_name = '&table_name';

STATUS INDEX_NAME

-------- ------------------------------
UNUSABLE INDEX_NAME                            -------> Here, value in status field may be valid or unusable.

SQL> alter index <INDEX_NAME> rebuild online;  -------> Use this command for each index

Index altered.

SQL> select status,index_name from dba_indexes where table_name = '&table_name';


STATUS INDEX_NAME
-------- ------------------------------
VALID INDEX_NAME                               -------> Here, value in status field must be valid.

After completing these steps, table statistics must be gathered.

Option: 2 Export and import the table:-

Click here to read from my posts

Option: 3 Shrink command (from Oracle 10g onwards):-


Shrink command: 

Its a new 10g feature to shrink (reorg) the tables (almost) online which can be used with automatic segment space 
management.

This command is only applicable for tables which are tablespace with auto segment space management.

Before using this command, you should have row movement enabled.

SQL> alter table <table_name> enable row movement;
Table altered.

There are 2 ways of using this command.

a. Rearrange rows and reset the HWM:

Part 1: Rearrange (All DML's can happen during this time)

SQL> alter table <table_name> shrink space compact;
Table altered.

Part 2: Reset HWM (No DML can happen. but this is fairly quick, infact goes unnoticed.)

SQL> alter table <table_name> shrink space;
Table altered.

b. Directly reset the HWM:

(Both rearrange and restting HWM happens in one statement)
SQL> alter table <table_name> shrink space; 
Table altered.

Advantages over the conventional methods are:

1. Unlike "alter table move ..",indexes are not in UNUSABLE state.After shrink command,indexes are updated also.
2. Its an online operation, So you dont need downtime to do this reorg.
3. It doesnot require any extra space for the process to complete.

After completing these steps, table statistics must be gathered.

6) How to get more performance benefits from most fragmented tables?

After doing above steps, you must gather statistics to tell optimizer to create best execution plan for better performance during query execution. Here I have given some auto sampling method to gather stats. Most of cases I got performance benefits when I did auto sampling method.

Gather table stats:

SQL> exec dbms_stats.gather_table_stats('&owner_name','&table_name');
PL/SQL procedure successfully completed.
OR
SQL> exec dbms_stats.gather_table_stats('&owner_name', '&table_name', estimate_percent => dbms_stats.auto_sample_size);
OR 
SQL> exec dbms_stats.gather_table_stats(ownname=>'&owner_name',
tabname=>'&table_name',estimate_percent => 100, cascade=>true, method_opt=>'for all columns size AUTO'); 

–- For entire schema
SQL>  EXECUTE DBMS_STATS.GATHER_SCHEMA_STATS('&schema_name',DBMS_STATS.AUTO_SAMPLE_SIZE);

Check Table size:

Now again check table size using and will find reduced size of the table.

SQL> select table_name,bytes/(1024*1024*1024) from dba_table where table_name='&table_name';

Now match with your earlier track, You must have some benefits. Sure performance will improve.

7) Demonstration:

Here I ll show you one demo activity. But when you will do, you first complete in your pre-prod database and collect performance statistics before and after. Then based on benefit, you can plan for production.

Demo:
1) Take all invalid objects counts for whole database as well as applied schema

select count(1) from dba_objects where status='INVALID' -- 2386

select count(1) from dba_objects where status='INVALID' and owner='CUSTOMER' -- 0

2) Take Top list ( preferably 10) of tables for fragmenation

select *
  from (select table_name,
               round((blocks * 8), 2) "size (kb)",
               round((num_rows * avg_row_len / 1024), 2) "actual_data (kb)",
               (round((blocks * 8), 2) -
               round((num_rows * avg_row_len / 1024), 2)) "wasted_space (kb)"
          from dba_tables
         where (round((blocks * 8), 2) >
               round((num_rows * avg_row_len / 1024), 2))
         order by 4 desc)
 WHERE ROWNUM <= 10;

Output:

TABLE_NAME                      size (kb) actual_data (kb) wasted_space (kb)

------------------------------ ---------- ---------------- -----------------
CUSTOMER_SERVICES_DTLS       12382432      10341757.49       2040674.51
PKG_ACTUAL_AVAILABLE           7291976       5736686.1         1555289.9
PROCESSED_TRAN                  1601072       367932.44         1233139.56
PROCESSED_CUURENCY              1314672       145479.1          1169192.9
ACTUAL_SERVICES_DTLS            7452568       6332113.25        1120454.75
SERVICEREQUESTDETAILS           3037840       1932758.36        1105081.64
PKG_RESULTREPORTDTLS            1436632       440030.4          996601.6
BATCH_TXN_SERIALITEM            2621128       1820127.37        801000.63
CUSTOMER_BILLDETAILS            233616        1451156.52        782459.48


10 rows selected

-- Find size
SQL> select segment_name, bytes/(1024*1024*1024) "Size GB" from
  2  dba_segments where segment_name='CUSTOMER_SERVICES_DTLS';
  

SEGMENT_NAME                           Size GB
-------------------------------------- ----------
CUSTOMER_SERVICES_DTLS             11.828125

SQL> 

3) Take one sample table. Here we ll take "CUSTOMER_SERVICES_DTLS". Find the owner.

SQL>
select owner,table_name,tablespace_name,num_rows,blocks
from dba_tables where table_name='CUSTOMER_SERVICES_DTLS';

output:


OWNER      TABLE_NAME                     TABLESPACE_NAME    NUM_ROWS     BLOCKS

---------------------------- ------------------------------ ---------- ----------
CUSTOMER      CUSTOMER_SERVICES_DTLS     CUSTOMER              74055662    1542825

4) Do below activities for safe purpose:

a) Take DDL


-- Create table
create table CUSTOMER.CUSTOMER_SERVICES_DTLS
(
 xxxxxx
) tablespace CUSTOMER;
--Create/Recreate indexes 
create index CUSTOMER.INDX_TXNID on CUSTOMER.CUSTOMER_SERVICES_DTLS (TXNID)
  tablespace CUSTOMER;
create index CUSTOMER.INDX_SYSTEMUPDATEDDATE on CUSTOMER.CUSTOMER_SERVICES_DTLS (SYSTEMUPDATEDDATE)
  tablespace CUSTOMER;

b) take logical backup using expdp:


expdp directory=data_pump dumpfile=CUSTOMER_SERVICES_DTLS.dmp logfile=CUSTOMER_SERVICES_DTLS.log tables=CUSTOMER.CUSTOMER_SERVICES_DTLS exclude=statistics

5) Verify all index status

SQL> select index_name,status
  2  from dba_indexes where table_name='CUSTOMER_SERVICES_DTLS';

INDEX_NAME                     STATUS
------------------------------ --------
INDX_TXNID             VALID
INDX_SYSTEMUPDATEDDATE         VALID

SQL> 

6) Now move the table:
SQL> connect / as sysdba
SQL> set timing on;
SQL> alter table CUSTOMER.CUSTOMER_SERVICES_DTLS move;

Table altered.


Elapsed: 00:11:12.18

SQL> 

(Note: Based of table size, more archivelogs will be generated. You must have sufficient space on required tablespace/ datafile, including TEMP tablespace)

7) Now again verify these:
a) No. of records
SQL> select count(rowid) from CUSTOMER.CUSTOMER_SERVICES_DTLS;

COUNT(ROWID)
------------
    74055662

SQL> 

b) Index statistics

SQL> select index_name,status

  2  from dba_indexes where table_name='CUSTOMER_SERVICES_DTLS';

INDEX_NAME                     STATUS
------------------------------ --------
INDX_TXNID             UNUSABLE
INDX_SYSTEMUPDATEDDATE         UNUSABLE

SQL> 

Here Indexes are "Unusable" status. So these must be rebuild.

8) Rebuild the Indexes

SQL> alter index CUSTOMER.INDX_TXNID rebuild online;

Index altered.

SQL> alter index CUSTOMER.INDX_SYSTEMUPDATEDDATE rebuild online;

Index altered.

SQL> 

Now check the index stats

SQL> select index_name,status from dba_indexes where table_name='CUSTOMER_SERVICES_DTLS';
INDEX_NAME                     STATUS
------------------------------ --------
INDX_TXNID             VALID
INDX_SYSTEMUPDATEDDATE         VALID

SQL> 


--> Now all are valid.


9) Now Chek no. of rows and blocks

SQL> select owner,table_name,tablespace_name,num_rows,blocks
from dba_tables where table_name='CUSTOMER_SERVICES_DTLS';

output:

OWNER      TABLE_NAME                     TABLESPACE_NAME    NUM_ROWS     BLOCKS

---------------------------- ------------------------------ ---------- ----------
CUSTOMER      CUSTOMER_SERVICES_DTLS     CUSTOMER              74055662    151033

--> See here no. of blocks reduced.


10) Now Gather table stats:

SQL> exec dbms_stats.gather_table_stats(ownname=>'CUSTOMER',tabname=>'CUSTOMER_SERVICES_DTLS',estimate_percent => 100, cascade=>true, method_opt=>'for all columns size AUTO'); 


11) Check Table size:

Now again check table size using and will find reduced size of the table.

SQL> 
SQL> select segment_name, bytes/(1024*1024*1024) "Size GB" from
  2  dba_segments where segment_name='CUSTOMER_SERVICES_DTLS';
  

SEGMENT_NAME                           Size GB
-------------------------------------- ----------
CUSTOMER_SERVICES_DTLS             10.02131

SQL> 


--> Here table size reduced also.

12) Now crosscheck all valid/ invalid object counts and match. You can release your database if you have taken downtime.

Issues may come during the above activity:

SQL> alter table CUSTOMER.CUSTOMER_SERVICES_DTLS move; 
alter table CUSTOMER.CUSTOMER_SERVICES_DTLS move
*
ERROR at line 1:
ORA-01652: unable to extend temp segment by 8192 in tablespace CUSTOMER


i.e., you don't have sufficient space on required tablespace and temp tablespace also.

So add more datafiles and tempfles if your datafiles and tempfile reached 32G.






Jan 25, 2016

flashback_on is "RESTORE POINT ONLY" - How to restore ?

Guaranteed Restore Point creates Flashback Log even Flashback logging is Disabled

Recently, we experienced couple of issues regarding Flash Recovery area space. 
  One is exhausted disk space on production database servers
  And another is Load testing before migration on pre-prod with flash back option

The problem is that the Flashback Recovery Area (FLA), where usually daily RMAN backup are going, So , disk space (90% full) issue some times the big headache . Anyway we have preserved sufficient space for FLA (near two times of actual size of database) and configured backup retention copy to 1,  that problem should be caused by exceptional database activities. Like more on retention policy, generation of huge archivelogs, etc.  After investigation, we shortly found that a folder /flashback, which sits under FLA, consumed over ~25% disk space on FLA.

It’s doubtable that the files within with extension name .flb are Flashback Log Files(OMF). But, the question was raised next: 

Why is flashback log files created even Flashback Logging is disabled?

According to “Oracle Database Backup and Recovery Basics 10gR2 and above”, flashback log files are deleted automatically when:

  • If the database needs to create a new flashback log and the flash recovery area is full or there is no disk space, then the oldest flashback log is reused instead.
  • If the flash recovery area is full, then an archived redo log may be automatically deleted by the flash recovery area to make space for other files. 

In such a case, any flashback logs that would require the use of that redo log file for the use of FLASHBACK DATABASE are also deleted.

since Oracle 10g database, Oracle Flashback Technology is a group of Oracle Database features that that let you view past states of database objects or to return database objects to a previous state without using point-in-time media recovery. To enable flashback, we need to explicitly issue command “alter database flashback on” and the flashback status could be found at view v$database.

Click here to read how to set / configure flashback database.

 Even I’m sure that flashback feature was disabled, I would like to check the view v$database again.

SQL> select name, log_mode, flashback_on from v$database;

NAME  LOG_MODE   FLASHBACK_ON
----- ---------  ------------------
PROD  ARCHIVELOG RESTORE POINT ONLY

         
Usually we made FLASHBACK on, then start your activity. After I issued this query, I surprisedly found that the value of field “FLASHBACK_ON” is “RESTORE POINT ONLY”, instead of “YES” and “NO”. Thus, it’s obvious that we have (guaranteed) restore point inside the database and probably that’s why flashback log files kept creating on FLA. Because restore point is created like below:

SQL> create restore point B4_UPGRADE guarantee flashback database;

 So, “Guaranteed Restore Points” means,  “The best part of this feature is, it uses db_file_recovery_dest to keep the changed blocks, even if flashback logging is not enabled for your database.”

Next, I executed query to check the Restore Point on this database.

SQL> select name, scn, time, guarantee_flashback_database
from v$restore_point;

NAME     SCN     TIME       GUA
------   ------   ---------   -------------
B4_UPGRADE 9329582780 22-JAN-16 06.01.43.00AM YES


The query results clearly  shows that there is Guaranteed Restore Point created almost year ago. And then, I tried to drop this obsolete restore point.

SQL> startup mount;

SQL> flashback database to restore point B4_UPGRADE;

Flashback complete.

SQL> drop restore point B4_UPGRADE ;

Restore point dropped.

SQL> alter database open resetlogs;

Database altered.

SQL>

Note : If you are using Cluster database, then stop all instances. Work from only one node. After activity complete, you can start all nodes again.

Here some more concepts about RESTORE POINT:

Use the CREATE RESTORE POINT statement to create a restore point, which is a name associated with an SCN of the database corresponding to the time of the creation of the restore point. A restore point can be used to flash a table or the database back to the time of creation of the restore point without the need to determine the SCN or timestamp.
There are two types of restore point:
  • Guaranteed restore points: A guaranteed restore point enables you to flash the database back deterministically to the restore point regardless of the DB_FLASHBACK_RETENTION_TARGET initialization parameter setting. The guaranteed ability to flash back depends on sufficient space being available in the flash recovery area.
    Guaranteed restore points guarantee only that the database will maintain enough flashback logs to flashback the database to the guaranteed restore point. It does not guarantee that the database will have enough undo to flashback any table to the same restore point.
    Guaranteed restore points must be dropped explicitly by the user using the DROP RESTORE POINT statement. They do not age out. Guaranteed restore points can use considerable space in the flash recovery area. Therefore, Oracle recommends that you create guaranteed restore points only after careful consideration.
  • Normal restore points: A normal restore point enables you to flash the database back to a restore point within the time period determined by theDB_FLASHBACK_RETENTION_TARGET initialization parameter. The database automatically manages normal restore points. When the maximum number of restore points is reached, according to the Oracle Document rules described restore_point, the database automatically drops the oldest restore point. However, you can explicitly drop a normal restore point using the DROP RESTORE POINT statement.
You can create either type of restore point on a primary or standby database. The database can be open or mounted but not open. If the database is mounted, then it must have been shut down cleanly before being mounted unless it is a physical standby database.
 This command may take long time and during the processing, You may observe  that the flashback log files within folder flashback will be purged automatically. Meanwhile, I monitored the process and noticed that the major session waits of this process is “control file parallel write”. It’s quite understandable that the “drop” command kept reading/writing the control file to reflect the SCN changes incurred with this command.

Once the execution was finished, the folder flaskback has been purged to empty. Out attempt to release disk space then got success by lowering the disk space utilization from 90% to 60%. Also, the field “FLASHBACK_ON” of view v$database was set back to “NO” instead.

SQL> select name, log_mode, flashback_on from v$database;

NAME  LOG_MODE    FLASHBACK_ON
----- ----------- ------------
PROD   ARCHIVELOG           NO

My approach to solve this problem verified that “Guaranteed Restore Points” does generate flashback log files even flashback logging is disabled.

Furthermore, I would like to share several practical points relating to restore point from other blogs.

Guaranteed restore points guarantee only that the database will maintain enough flashback logs to flashback the database to the guaranteed restore point. It does not guarantee that the database will have enough undo to flashback any table to the same restore point.

Click here to read from Oracle Document.

Jan 23, 2016

Listener INTERMEDIATE status with "Not All Endpoints Registered"

Listener INTERMEDIATE status with "Not All Endpoints Registered" in 11gR2 RAC

During load testing of pre-prod server, I found load balancing is not happening properly. During investigation, When I issue clusterware services status resources command "crsctl stat res -t" it shows the listeners are in INTERMEDIATE status on node 1. The problem is caused by another listener defined statically in listener.ora,  using the same port and IP is running from the  ORACLE_HOME, started manually causing the default listener starting from GRID_HOME can not register its endpoint.

See, from which node “ Not All Endpoints Registered” message is coming.

$ crsctl stat res -t
--------------------------------------------------------------------------------
NAME           TARGET  STATE        SERVER                   STATE_DETAILS      
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.DATA.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.FRA.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.LISTENER.lsnr
               ONLINE  INTERMEDIATE racdb1                   Not All Endpoints Registered          
               ONLINE  ONLINE       racdb2                                      
ora.OCRVD.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.asm
               ONLINE  ONLINE       racdb1                   Started            
               ONLINE  ONLINE       racdb2                   Started            
ora.gsd
               OFFLINE OFFLINE      racdb1                                      
               OFFLINE OFFLINE      racdb2                                      
ora.net1.network
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.ons
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.registry.acfs
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
--------------------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------------------
ora.LISTENER_SCAN1.lsnr
      1        ONLINE  ONLINE       racdb2                                      
ora.LISTENER_SCAN2.lsnr
      1        ONLINE  ONLINE       racdb1                                      
ora.LISTENER_SCAN3.lsnr
      1        ONLINE  ONLINE       racdb1                                      
ora.cvu
      1        ONLINE  ONLINE       racdb1                                      
ora.racdb1.vip
      1        ONLINE  ONLINE       racdb1                                      
ora.racdb2.vip
      1        ONLINE  ONLINE       racdb2                                      
ora.PROD.db
      1        ONLINE  ONLINE       racdb1                   Open              
      2        ONLINE  ONLINE       racdb2                   Open              
ora.PROD.prdoltp.svc
      1        ONLINE  ONLINE       racdb1                                      
      2        ONLINE  ONLINE       racdb2                                      
ora.oc4j
      1        ONLINE  ONLINE       racdb1                                      
ora.scan1.vip
      1        ONLINE  ONLINE       racdb2                                      
ora.scan2.vip
      1        ONLINE  ONLINE       racdb1                                      
ora.scan3.vip
      1        ONLINE  ONLINE       racdb1                                      
bash-4.2$

Now see listeners are running from which home?

bash-3.2$ ps -ef|grep tns
bash-4.2$ ps -ef|grep tns
  oracle  6488180 10813910   0 16:47:56  pts/0  0:00 grep tns
    grid  7471174        1   0   Nov 09      -  3:33 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER_SCAN3 -inherit
    grid  7602274        1   0   Nov 09      -  3:15 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER_SCAN2 -inherit
    grid 10223706        1   0 16:36:04      -  0:00 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER -inherit
  oracle 11272200        1   0   Jan 18  pts/0  1:00 /u01/app/oracle/11.2.0/db_home/bin/tnslsnr LISTENER -inherit
bash-4.2$

But, from 11g release 2 onwards  in RAC environment all listeners should run from GRID_HOME, listener and listener_scan(n) entry should be added automatically in listener.ora file.

To resolve this issue, simply stop the all listeners and start grid listener only from grid home.

See the below steps:

1.Stop the listener running from ORACLE_HOME (RDBMS)

 $<ORACLE_HOME>/bin/lsnrctl stop

2. stop the listener from GRID_HOME

$<GRID_HOME>/bin/srvctl stop listener -n <node name>

3. restart the LISTENER and LISTENER_SCAN1  from GRID_HOME

$<GRID_HOME>/bin/srvctl start listener -n <node name>

4. check crsctl stat res -t output, they both should show ONLINE status now.

See the real time steps:

$ crsctl stat res -t
--------------------------------------------------------------------------------
NAME           TARGET  STATE        SERVER                   STATE_DETAILS      
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.DATA.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.FRA.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.LISTENER.lsnr
               ONLINE  INTERMEDIATE racdb1                   Not All Endpoints R
                                                             egistered          
               ONLINE  ONLINE       racdb2                                      
ora.OCRVD.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.asm
               ONLINE  ONLINE       racdb1                   Started            
               ONLINE  ONLINE       racdb2                   Started            
ora.gsd
               OFFLINE OFFLINE      racdb1                                      
               OFFLINE OFFLINE      racdb2                                      
ora.net1.network
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.ons
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.registry.acfs
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
--------------------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------------------
ora.LISTENER_SCAN1.lsnr
      1        ONLINE  ONLINE       racdb2                                      
ora.LISTENER_SCAN2.lsnr
      1        ONLINE  ONLINE       racdb1                                      
ora.LISTENER_SCAN3.lsnr
      1        ONLINE  ONLINE       racdb1                                      
ora.cvu
      1        ONLINE  ONLINE       racdb1                                      
ora.racdb1.vip
      1        ONLINE  ONLINE       racdb1                                      
ora.racdb2.vip
      1        ONLINE  ONLINE       racdb2                                      
ora.PROD.db
      1        ONLINE  ONLINE       racdb1                   Open              
      2        ONLINE  ONLINE       racdb2                   Open              
ora.PROD.prdoltp.svc
      1        ONLINE  ONLINE       racdb1                                      
      2        ONLINE  ONLINE       racdb2                                      
ora.oc4j
      1        ONLINE  ONLINE       racdb1                                      
ora.scan1.vip
      1        ONLINE  ONLINE       racdb2                                      
ora.scan2.vip
      1        ONLINE  ONLINE       racdb1                                      
ora.scan3.vip
      1        ONLINE  ONLINE       racdb1                                      
bash-4.2$

and, the listener status are :

bash-4.2$ ps -ef|grep tns
  oracle  6488180 10813910   0 16:47:56  pts/0  0:00 grep tns
    grid  7471174        1   0   Nov 09      -  3:33 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER_SCAN3 -inherit
    grid  7602274        1   0   Nov 09      -  3:15 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER_SCAN2 -inherit
    grid 10223706        1   0 16:36:04      -  0:00 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER -inherit
  oracle 11272200        1   0   Jan 18  pts/0  1:00 /u01/app/oracle/11.2.0/db_home/bin/tnslsnr LISTENER -inherit
bash-4.2$

Now stop the listener from RDBMS home:

bash-3.2$ cd $ORACLE_HOME/bin
bash-3.2$
bash-4.2$ lsnrctl stop

LSNRCTL for IBM/AIX RISC System/6000: Version 11.2.0.4.0 - Production on 22-JAN-2016 17:06:11

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

Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=LISTENER)))
The command completed successfully
bash-4.2$

bash-4.2$ lsnrctl status

LSNRCTL for IBM/AIX RISC System/6000: Version 11.2.0.4.0 - Production on 22-JAN-2016 17:06:59

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

Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=IPC)(KEY=LISTENER)))
TNS-12541: TNS:no listener
 TNS-12560: TNS:protocol adapter error
  TNS-00511: No listener
   IBM/AIX RISC System/6000 Error: 2: No such file or directory
bash-4.2$

bash-3.2$ ps -ef |grep tns
  oracle 58261656 58720430   0 13:18:32  pts/1  0:00 grep tns
bash-3.2$
bash-3.2$ srvctl stop listener -n  racdb1
bash-3.2$ srvctl stop listener -n  racdb2
bash-3.2$

bash-4.2$ crsctl stat res -t
--------------------------------------------------------------------------------
NAME           TARGET  STATE        SERVER                   STATE_DETAILS      
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
…..                                  
ora.LISTENER.lsnr
               OFFLINE OFFLINE      racdb1                                      
               OFFLINE OFFLINE      racdb2  
….....

bash-3.2$ srvctl status listener
Listener LISTENER is enabled
Listener LISTENER is running on node(s): racdb2
bash-3.2$
bash-3.2$ srvctl start listener -n  racdb1
bash-3.2$ srvctl start listener -n  racdb2
bash-3.2$
Now see, all listeners are running from grid home only.
bash-4.2$ ps -ef |grep tns
    grid  7471174        1   0   Nov 09      -  3:33 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER_SCAN3 -inherit
    grid  7602274        1   0   Nov 09      -  3:15 /u01/app/11.2.0/grid/bin/tnslsnr LISTENER_SCAN2 -inherit
    grid  9503172  7995474   0 17:08:34  pts/2  0:00 grep tns

bash-4.2$ crsctl stat res -t
--------------------------------------------------------------------------------
NAME           TARGET  STATE        SERVER                   STATE_DETAILS      
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.DATA.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.FRA.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.LISTENER.lsnr
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.OCRVD.dg
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.asm
               ONLINE  ONLINE       racdb1                   Started            
               ONLINE  ONLINE       racdb2                   Started            
ora.gsd
               OFFLINE OFFLINE      racdb1                                      
               OFFLINE OFFLINE      racdb2                                      
ora.net1.network
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.ons
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
ora.registry.acfs
               ONLINE  ONLINE       racdb1                                      
               ONLINE  ONLINE       racdb2                                      
--------------------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------------------
ora.LISTENER_SCAN1.lsnr
      1        ONLINE  ONLINE       racdb2                                      
ora.LISTENER_SCAN2.lsnr
      1        ONLINE  ONLINE       racdb1                                      
ora.LISTENER_SCAN3.lsnr
      1        ONLINE  ONLINE       racdb1                                      
ora.cvu
      1        ONLINE  ONLINE       racdb1                                      
ora.racdb1.vip
      1        ONLINE  ONLINE       racdb1                                      
ora.racdb2.vip
      1        ONLINE  ONLINE       racdb2                                      
ora.PROD.db
      1        ONLINE  ONLINE       racdb1                   Open              
      2        ONLINE  ONLINE       racdb2                   Open              
ora.PROD.prdoltp.svc
      1        ONLINE  ONLINE       racdb1                                      
      2        ONLINE  ONLINE       racdb2                                      
ora.oc4j
      1        ONLINE  ONLINE       racdb1                                      
ora.scan1.vip
      1        ONLINE  ONLINE       racdb2                                      
ora.scan2.vip
      1        ONLINE  ONLINE       racdb1                                      
ora.scan3.vip
      1        ONLINE  ONLINE       racdb1                                      
bash-4.2$
bash-3.2$
bash-3.2$
bash-4.2$ srvctl status listener
Listener LISTENER is enabled
Listener LISTENER is running on node(s): racdb1,racdb2
bash-4.2$      

Thanks. Hope this Doc will help you.

Translate >>