Apr 30, 2017

SP2-0618: Cannot find the Session Identifier. Check PLUSTRACE role is enabled











We often want to enable AUTOTRACE ON,
for administering explain plan, and encounter below error;


U1@mydb_us> set autotrace on
SP2-0618: Cannot find the Session Identifier.  Check PLUSTRACE role is enabled
SP2-0611: Error enabling STATISTICS report
U1@mydb_us> 

Please grant PLUSTRACE role to concerned user.

SYS@mydb_us> grant plustrace to u1;
grant plustrace to u1
      *
ERROR at line 1:
ORA-01919: role 'PLUSTRACE' does not exist

In case you encounter above error, execute $ORACLE_HOME/sqlplus/admin/plustrce.sql script to fix this issue;

SYS@mydb_us> @?/sqlplus/admin/plustrce.sql
SYS@mydb_us>
SYS@mydb_us> drop role plustrace;
drop role plustrace
          *
ERROR at line 1:
ORA-01919: role 'PLUSTRACE' does not exist

SYS@mydb_us> create role plustrace;

Role created.

SYS@mydb_us>
SYS@mydb_us> grant select on v_$sesstat to plustrace;

Grant succeeded.

SYS@mydb_us> grant select on v_$statname to plustrace;

Grant succeeded.

SYS@mydb_us> grant select on v_$mystat to plustrace;

Grant succeeded.

SYS@mydb_us> grant plustrace to dba with admin option;

Grant succeeded.

SYS@mydb_us>
SYS@mydb_us> set echo off

Now, once you created the role, grant it to concerned user

SYS@mydb_us> grant plustrace to u1;

Grant succeeded.

Finally enable AUTOTRACE ON;

U1@mydb_us> set autotrace on explain statistics
U1@mydb_us> select * from dual;

D
-
X

1 row selected.

Execution Plan
----------------------------------------------------------
Plan hash value: 272002086

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |     2 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS FULL| DUAL |     1 |     2 |     2   (0)| 00:00:01 |
--------------------------------------------------------------------------


Statistics
----------------------------------------------------------
          2  recursive calls
          0  db block gets
          5  consistent gets
          2  physical reads
          0  redo size
        522  bytes sent via SQL*Net to client
        499  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          1  rows processed

No comments:

Post a Comment