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

Home -> Community -> Mailing Lists -> Oracle-L -> Re: fetch across commit

Re: fetch across commit

From: z b <zimsbait_at_gmail.com>
Date: Tue, 30 Nov 2004 07:51:18 -0500
Message-ID: <5b1f2b7004113004513aebbe89@mail.gmail.com>


I actually posted the same thing to the asktom response.. his response was:

We have package a which has 1 procedure and 2 functions. procedure a
 cursor a select from taba
  open a loop fetch
    call function 1;
  end loop;

function 1
 cursor b select from tabb
  open b loop fetch
    call function 2
  end loop

function 2
  insert into tabc
  commit

We're getting 1555's. Is this a case of fetch across commit, even though tabc (the committed table) isn't in
the orirginal cursors?

Basically, cursor select, open another cursor on another table, cursor select and insert and commit into yet another table.  

Followup (Tom's response):
inline the code and you get:

for X in a
loop

   for Y in b
   loop

      insert into table...
      commit;

   end loop
end loop

so yes, you are not only fetching over a cursor (two of them) causing a very much self inflicted ora-1555, you probably are not "restartable" either -- meaning when you get the 1555 you are in a whole heap of trouble since you cannot really "pick up" where you left off (eg: transactional integrity = 0)  

On Tue, 30 Nov 2004 11:23:13 -0000, David Lord <dlord_at_ironmountain.co.uk> wrote:
> Seems to me that the fetch-across-commit is not actually the problem in this
> case. There is no DML activity on that table. Hence the blocks in the
> buffer cache are never made 'dirty'. On the other hand, there is a danger
> of snapshot too old with repeatedly inserting into the same table and then
> committing, due to delayed block cleanout: -
>
> 1. Inserting into a block generates rollback with a lock on it and puts a
> pointer to the rollback in the interested transaction list (ITL) of the
> block buffer.
> 2. Committing releases the lock on the rollback segment but doesn't clean
> out the ITL. The rollback segment is now available for reuse.
> 3. A second insert into the same block comes across the ITL entry and goes
> to find the rollback segment. If this has been overwritten, you get
> snapshot too old.
>
> I've seen a case of this with a script that inserted into a temporary table,
> committed, updated the table, committed, updated the table again, committed,
> etc. There was no cursor being fetched across the commits, there was no
> other session doing anything with the table and yet it still raised a
> snapshot too old.
>
> --
> David Lord
>
>
>
>
> > -----Original Message-----
> > From: Ganesh Raja [mailto:ganesh.raja_at_gmail.com]
> > Sent: 30 November 2004 10:36
> > To: dgoulet_at_vicr.com
> > Cc: Oracle List
> > Subject: Re: fetch across commit
> >
> >
> > Goulet,
> >
> > If you see the OP's Program he is Doing an Insert into a Different
> > Table and commiting there .. So Why Should he Get a 1555 here or a
> > Fetch Across Commit.
> >
> > He will get 1555 Only if another Program is doing Updates to the EMP
> > table and commiting so often that it wraps the Undo faster than this
> > Process.
> >
> > A Fetch Across commit will happen only if the Same Table is Updated
> > and Commitied in a Cursor Loop ...
> >
> > Additions and corrections welcome.
> >
> > Cheers!
> > Ganesh
> >
> >
> > On Fri, 26 Nov 2004 21:47:03 -0500, Goulet, Dick
> > <dgoulet_at_vicr.com> wrote:
> > > Seems you've asked this question twice now, which means you did not
> > > understand the answer the first time. OK; the short answer
> > is yes it
> > > can cause an ORA-1555 error. The reason is that when you opened the
> > > cursor Oracle captured the current SCN, say 100. You've
> > done several
> > > updates/inserts/deletes based on the logic of your program
> > and done a
> > > commit, which changed the SCN to say 105. In doing so you've told
> > > Oracle that you are no longer interested in any rollback
> > segments before
> > > SCN 105, when in fact you are. Immediately that is not a
> > problem, but
> > > sooner or later part of your cursor will need to recreate a
> > data row to
> > > SCN 100 with rollback data. Problem is that you've let it go &
> > > consequently Oracle cannot create a read consistent view as
> > of SCN 100 &
> > > you get ORA-01555.
> > >
> > > One trick I've used rather successfully in the past is to
> > put an "order
> > > by" clause on the cursor statement. Order By causes a
> > sort, which means
> > > Oracle has to find all of the data that your cursor will
> > need and sort
> > > it before handing you the first row. Now all of your
> > return rows are
> > > stored in a temp table in the Temp tablespace & no more
> > rollback or read
> > > consistent view activity is needed. It's a hack I'll admit, but one
> > > that appears to work 90% of the time.=20
> > >
> > > Dick Goulet
> > > Senior Oracle DBA
> > > Oracle Certified 8i DBA
> > > -----Original Message-----
> > > From: ryan_gaffuri_at_comcast.net [mailto:ryan_gaffuri_at_comcast.net]=20
> > > Sent: Wednesday, November 24, 2004 1:53 PM
> > > To: zimsbait_at_gmail.com; Oracle List
> > > Cc: z b
> > > Subject: Re: fetch across commit
> > >
> > > yes, because a commit releases the lock on the rollback segments and
> > > orac=3D
> > > le can overwrite them with another process.=3D20
> > > -------------- Original message --------------=3D20
> > >
> > > > Listers,=3D20
> > > >=3D20
> > > > I have a question where I need a little clarification
> > about fetching
> > > ac=3D
> > > ross=3D20
>
>
> > > > commits. Can this happen if the table being committed to
> > is not the
> > > sam=3D
> > > e=3D20
> > > > as the tables(s) in the cursors?=3D20
> > > >=3D20
> > > > For example, if I had :=3D20
> > > > cursor c1 is select empname form emp where=3D20
> > > > dept =3D3D 100;=3D20
> > >
> > >
> > >
> > > --
> > > http://www.freelists.org/webpage/oracle-l
> > > --
> > > http://www.freelists.org/webpage/oracle-l
> > > --
> > > http://www.freelists.org/webpage/oracle-l
> > >
> > --
> > http://www.freelists.org/webpage/oracle-l
> >
> This email and its attachments are confidential under applicable law and are intended for use of the sender's addressee only, unless the sender expressly agrees otherwise, or unless a separate written agreement exists between Iron Mountain and a recipient company governing communications between the parties and any data that may be so transmitted. Transmission of email over the Internet is not a secure communications medium. If you are requesting or have requested the transmittal of personal data, as defined in applicable privacy laws, by means of email or in an attachment to email, you may wish to select a more secure alternate means of transmittal that better supports your obligations to protect such personal data.
>
> If the recipient of this message is not the recipient named above, and/or you have received this email in error, you must take no action based on the information in this email. You are hereby notified that any dissemination, misuse or copying or disclosure of this communication by a recipient who has received this message in error is strictly prohibited. If this message is received in error, please return this email to the sender and immediately highlight any error in transmittal. Thank you.
>
>
>
> --
> http://www.freelists.org/webpage/oracle-l
>

--
http://www.freelists.org/webpage/oracle-l
Received on Tue Nov 30 2004 - 06:47:06 CST

Original text of this message

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