ORA-00054: resource busy and acquire with NOWAIT specified
Problem Description
In my production database Oracle 10.2g while I was adding column to one of my transaction table it fails with ORA-54 error as below.
SQL> alter table student add b number;
alter table student add b number
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
Description of the Problem
Let's try to produce the problem in our development environment. I have opened two session that connected to database under a schema. In one session, I have created a table and inserted data into it.
SQL> create table a (a number);
Table created.
SQL> insert into a values(1);
1 row created.
I did not yet committed data in session 1. Now in another session whenever I try to any ddl like (alter table, drop table) ORA-00054 will produce.
In another session,
SQL> alter table a add b number;
alter table a add b number
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
SQL> drop table a;
drop table a
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
SQL> lock table a in exclusive mode nowait;
lock table a in exclusive mode nowait
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
Cause of the Problem
Whenever you try to do any structural changes on a table oracle try to lock the table exclusively with NOWAIT option(this is in 10.2g while in 11g you can change the wait timeout). If oracle fails to lock the table exclusively then ORA-00054 will occur.
Solution of the Problem
In 10.2g you are limited to several choices to solve the problem. To avoid it,
-Re run the DDL at a later time when the database become idle.
or,
-Kill the sessions that are preventing the exclusive lock.
or,
-Prevent end user to connect to the database and then run the DDL.
You have different views to see locking information about the table.
1)DBA_BLOCKERS: Displays a session if it is not waiting for a locked object but is holding a lock on an object for which another session is waiting. In our scenario this view will not help.
2)DBA_DDL_LOCKS: It lists all DDL locks held in the database and all outstanding requests for a DDL lock.
3)DBA_DML_LOCKS: It lists all DML locks held in the database and all outstanding requests for a DML lock.
If you query from it in the mode_held field you will see 'row exclusive lock'.
SQL> select mode_held from dba_dml_locks where owner='MAXIMSG';
MODE_HELD
-------------
Row-X (SX)
4)DBA_LOCK: It lists all locks or latches held in the database, and all outstanding requests for a lock or latch.
5)DBA_LOCK_INTERNAL: It displays a row for each lock or latch that is being held, and one row for each outstanding request for a lock or latch.
6)DBA_LOCKS is a synonym for DBA_LOCK.
7)DBA_WAITERS: Shows all the sessions that are waiting for a lock.
In order to see locked object query,
Here we see there is 3 types of locking. In our case the object is A. And we see the sid=142 and serial#=232 is preventing us from locking the table in exclusive mode. So to achieve our task we can kill the session as below.
SQL> alter system kill session '142, 232';
System altered.
SQL> alter table a add b number;
Table altered.
Now in the first session whenever you try to access error will be generated saying that session has been killed. In the first session.
SQL> commit;
commit
*
ERROR at line 1:
ORA-00028: your session has been killed
In my production database Oracle 10.2g while I was adding column to one of my transaction table it fails with ORA-54 error as below.
SQL> alter table student add b number;
alter table student add b number
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
Description of the Problem
Let's try to produce the problem in our development environment. I have opened two session that connected to database under a schema. In one session, I have created a table and inserted data into it.
SQL> create table a (a number);
Table created.
SQL> insert into a values(1);
1 row created.
I did not yet committed data in session 1. Now in another session whenever I try to any ddl like (alter table, drop table) ORA-00054 will produce.
In another session,
SQL> alter table a add b number;
alter table a add b number
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
SQL> drop table a;
drop table a
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
SQL> lock table a in exclusive mode nowait;
lock table a in exclusive mode nowait
*
ERROR at line 1:
ORA-00054: resource busy and acquire with NOWAIT specified
Cause of the Problem
Whenever you try to do any structural changes on a table oracle try to lock the table exclusively with NOWAIT option(this is in 10.2g while in 11g you can change the wait timeout). If oracle fails to lock the table exclusively then ORA-00054 will occur.
Solution of the Problem
In 10.2g you are limited to several choices to solve the problem. To avoid it,
-Re run the DDL at a later time when the database become idle.
or,
-Kill the sessions that are preventing the exclusive lock.
or,
-Prevent end user to connect to the database and then run the DDL.
You have different views to see locking information about the table.
1)DBA_BLOCKERS: Displays a session if it is not waiting for a locked object but is holding a lock on an object for which another session is waiting. In our scenario this view will not help.
2)DBA_DDL_LOCKS: It lists all DDL locks held in the database and all outstanding requests for a DDL lock.
3)DBA_DML_LOCKS: It lists all DML locks held in the database and all outstanding requests for a DML lock.
If you query from it in the mode_held field you will see 'row exclusive lock'.
SQL> select mode_held from dba_dml_locks where owner='MAXIMSG';
MODE_HELD
-------------
Row-X (SX)
4)DBA_LOCK: It lists all locks or latches held in the database, and all outstanding requests for a lock or latch.
5)DBA_LOCK_INTERNAL: It displays a row for each lock or latch that is being held, and one row for each outstanding request for a lock or latch.
6)DBA_LOCKS is a synonym for DBA_LOCK.
7)DBA_WAITERS: Shows all the sessions that are waiting for a lock.
In order to see locked object query,
SQL> set linesize 130
SQL> set pages 100
SQL> col username format a20
SQL> col sess_id format a10
SQL> col object format a25
SQL> col mode_held format a10
SQL> select oracle_username || ' (' || s.osuser || ')' username
2 , s.sid || ',' || s.serial# sess_id
3 , owner || '.' || object_name object
4 , object_type
5 , decode( l.block
6 , 0, 'Not Blocking'
7 , 1, 'Blocking'
8 , 2, 'Global') status
9 , decode(v.locked_mode
10 , 0, 'None'
11 , 1, 'Null'
12 , 2, 'Row-S (SS)'
13 , 3, 'Row-X (SX)'
14 , 4, 'Share'
15 , 5, 'S/Row-X (SSX)'
16 , 6, 'Exclusive', TO_CHAR(lmode)) mode_held
17 from v$locked_object v
18 , dba_objects d
19 , v$lock l
20 , v$session s
21 where v.object_id = d.object_id
22 and v.object_id = l.id1
23 and v.session_id = s.sid
24 order by oracle_username
25 , session_id
26 /
USERNAME SESS_ID OBJECT OBJECT_TYPE STATUS MODE_HELD
-------------------- ---------- ------------------------- ------------------- ------------ ----------
MAXIMSG (A) 142,232 MAXIMSG.A TABLE Not Blocking Row-X (SX)
OMS (DBA2\ershad) 143,280 OMS.T TABLE Not Blocking Row-X (SX)
OMS (DBA2\ershad) 143,280 OMS.T1 TABLE Not Blocking Row-X (SX)
Here we see there is 3 types of locking. In our case the object is A. And we see the sid=142 and serial#=232 is preventing us from locking the table in exclusive mode. So to achieve our task we can kill the session as below.
SQL> alter system kill session '142, 232';
System altered.
SQL> alter table a add b number;
Table altered.
Now in the first session whenever you try to access error will be generated saying that session has been killed. In the first session.
SQL> commit;
commit
*
ERROR at line 1:
ORA-00028: your session has been killed
Comments
Post a Comment