Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> SV: How do commits release row level locks?

SV: How do commits release row level locks?

From: Jesper Haure Norrevang <jhn.aida_at_cbs.dk>
Date: Mon, 16 Feb 2004 14:02:53 +0100
Message-id: <000001c3f48d$3057eaa0$4a28e282@AIDA.local>


Hi Naveen,

That was a good question. I have played a little with your test:

SESSION 1


SELECT DISTINCT sid
FROM V$MYSTAT
/

DROP TABLE test
/

CREATE TABLE test (COL1 NUMBER)
PCTFREE 0 INITRANS 2 MAXTRANS 3
/

begin
  for i in 1 .. 1000
  loop
    INSERT into test values(i);
  end loop;
end;
/

COMMIT
/

DELETE Test WHERE col1 =3D 1
/

SESSION 2


SELECT DISTINCT sid
FROM V$MYSTAT
/

DELETE Test WHERE col1 =3D 2
/

SESSION 3


SELECT DISTINCT sid
FROM V$MYSTAT
/

DELETE Test WHERE col1 =3D 3
/

SESSION 4


select *
from v$session_wait
where sid =3D <the SID of SESSION 3 that is waiting>
/

REM Session 3 are waiting on an enqueue. REM What are we waiting for

select *
from v$lock
where sid =3D <the SID of SESSION 3>
and request <> 0
/

REM Which session is blocking

select *
from v$lock
where id1 =3D <ID1 from above>
and id2 =3D <ID2 from above>
/

Here we see the session we are waiting for. If we rollback that session, SESSION 3 will get a signal and proceed immediately.
If we rollback another session, we will still be waiting.

Thus all the ITL slots do not need to be empty before SESSION 3 can proceed.

Regards
Jesper Haure Norrevang

-----Oprindelig meddelelse-----
Fra: oracle-l-bounce_at_freelists.org =
[mailto:oracle-l-bounce_at_freelists.org] P=E5 vegne af Naveen, Nahata (IE10)
Sendt: 16. februar 2004 13:10
Til: oracle-l_at_freelists.org
Emne: RE: How do commits release row level locks?

Hi All,

Can someone please explain me why the following happens:

Step 1.  CREATE TABLE TEMP (COL1 NUMBER) PCTFREE 0 INITRANS 2 MAXTRANS 3
Step 2.  INSERT values from 1 to 100,000 in the table
Step 3.  COMMIT
Step 4.  Since the insert was sequential, I assume the values 1, 2, 3, =
4, 5
should be in the same block (I can test the same using rowid as well)
Step 5.  From one session issue "DELETE TEMP WHERE col1 =3D 1"
Step 6.  From the second session issue "DELETE TEMP WHERE col1 =3D 2"
Step 7.  From the third session issue "DELETE TEMP WHERE col1 =3D 3"
Step 8.  The third session waits on "enqueue". This is understandable =
since
PCTFREE is 0 and the block has no space to create a third ITL Slot. Step 9. ROLLBACK the second session. This should release the ITL Slot = (???)
Step 10. Still the third session waits on "enqueue". Should it not go = ahead
with the delete now that one transaction has rolled back? Step 11. ROLLBACK the first session and the delete issued by the third session goes ahead.=20

I tried the same experiment with INITRANS set to 3, and the fourth = session
hangs, and doesn't move ahead until all the other three session rollback = or
commit. It seems that the waiting session doesn't go ahead until all the sessions have finished their transactions.

Moreover, when I look at V$SESSION_WAIT, it shows the session waiting on "enqueue" and SECONDS_IN_WAIT increment from 0 to 3 and then again get = reset
to 0.

Can someone please explain this? It seems I'm missing something, but = what?

9.2.0.3 on Solaris

Regards
Naveen



Please see the official ORACLE-L FAQ: http://www.orafaq.com

To unsubscribe send email to: oracle-l-request_at_freelists.org put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request_at_freelists.org
put 'unsubscribe' in the subject line.
--
Archives are at http://www.freelists.org/archives/oracle-l/
FAQ is at http://www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------
Received on Mon Feb 16 2004 - 07:02:53 CST

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US