Discussion:
ORA-01554: transaction concurrency limit reached reason:no undo segment found with available slot params:0, 0 :
Remigiusz Sokołowski
2018-06-29 09:23:02 UTC
Permalink
Hi,

lately I saw the error ORA-01554 and wonder in which circumstances it is
possible to hit this error.

Theoretically this is quite clear - the db hit the roof on concurrent
transactions, but:
- the database (12.1.0.2) is auto undo management
- transactions are set to 1647, transactions_per_rollback_segment to 5, but
I believe those are simply default settings and according to docs those
settings are ignored for automatic undo management
- in docs it is stated the undo on AUTO is limited mostly by the undo
tablespace size (but here this size was not depleted - overall there are
~524000 blocks with ~64000 used between midnight and 15 when the error was
hit according to v$undostat and maximum query lasting below 1h)
- also I would rather expect ORA-01652 on undo tablespace

From what I've found it seems the db creates undo segments automatically
and if no more space then assigns transactions to existing ones - but this
is very imprecise.

Anyone able to elaborate on that?

Regards
Remigiusz
--
------------------------------------------------------------------------------------
Remigiusz Sokołowski <***@gmail.com>
------------------------------------------------------------------------------------
Jonathan Lewis
2018-06-29 09:34:54 UTC
Permalink
Taking a quick guess:

An (automatic) undo segment has 34 slots in the transaction table (the thing in the undo segment header).
If you and up with a small number N of undo segments then you can't have more than 34 * N concurrent transactions active because each one needs a transaction table slot and the next attempt to start a transaction would see ORA-01554

It seems a little unlikely that this would happan in typical system since Oracle would usually end up stealing an extent from an existing undo segment to use it as the first extent of a new undo segment. But it wouldn't be hard to set up a mechanism that started with a small number of undo segments in a relatively small undo tablespace - started some transactions (then leave them idle forever after the first change - e.g. they might have come in from a remote database) that made it impossible to free any extents, then did a lot of work to allocate all the extents (but still left a little space in allocated extents for continuting transactions), then started lots of transactions until you hit the error.

Regards
Jonathan Lewis


________________________________________
From: oracle-l-***@freelists.org <oracle-l-***@freelists.org> on behalf of Remigiusz Sokołowski <***@gmail.com>
Sent: 29 June 2018 10:23:02
To: oracle-***@freelists.org
Subject: ORA-01554: transaction concurrency limit reached reason:no undo segment found with available slot params:0, 0 :



Hi,

lately I saw the error ORA-01554 and wonder in which circumstances it is possible to hit this error.

Theoretically this is quite clear - the db hit the roof on concurrent transactions, but:
- the database (12.1.0.2) is auto undo management
- transactions are set to 1647, transactions_per_rollback_segment to 5, but I believe those are simply default settings and according to docs those settings are ignored for automatic undo management
- in docs it is stated the undo on AUTO is limited mostly by the undo tablespace size (but here this size was not depleted - overall there are ~524000 blocks with ~64000 used between midnight and 15 when the error was hit according to v$undostat and maximum query lasting below 1h)
- also I would rather expect ORA-01652 on undo tablespace

From what I've found it seems the db creates undo segments automatically and if no more space then assigns transactions to existing ones - but this is very imprecise.

Anyone able to elaborate on that?

Regards
Remigiusz
--
------------------------------------------------------------------------------------
Remigiusz Sokołowski <***@gmail.com<mailto:***@gmail.com>>
------------------------------------------------------------------------------------
--
http://www.freelists.org/webpage/oracle-l
Remigiusz Sokołowski
2018-06-29 10:38:42 UTC
Permalink
Pretty much that is what I need :-)

At the moment of checking on that db there were 12 undo segments and
assuming the db was kept with them all the numbers are quite consistent.
I've checked the maxconcurrency in v$undostat for a week before the
incident - with the peak from the incident it was 4.4 on average and 2 as
median, so exactly as You said kept very low.
The transaction peak was obtained within less then 20 minutes - jump from
around 100 tx to 100000 tx, so again as You said very high slope. And 12x34
is 408, which is quite close to 331 in maxconcurrency.

But I thought oracle db would create more undo segments, when needed.
While here it seems it keeps with the number, which as I understand, is
established during the db opening or the txn pressure is so high, the db
is not able to init a new undo segment at certain point in time fast enough
to be ready for increased number of txn and at this point some number of
sessions would report ORA-01554 - which one is true?

And many thanks :-)
Remigiusz
Post by Jonathan Lewis
An (automatic) undo segment has 34 slots in the transaction table (the
thing in the undo segment header).
If you and up with a small number N of undo segments then you can't have
more than 34 * N concurrent transactions active because each one needs a
transaction table slot and the next attempt to start a transaction would
see ORA-01554
It seems a little unlikely that this would happan in typical system since
Oracle would usually end up stealing an extent from an existing undo
segment to use it as the first extent of a new undo segment. But it
wouldn't be hard to set up a mechanism that started with a small number of
undo segments in a relatively small undo tablespace - started some
transactions (then leave them idle forever after the first change - e.g.
they might have come in from a remote database) that made it impossible to
free any extents, then did a lot of work to allocate all the extents (but
still left a little space in allocated extents for continuting
transactions), then started lots of transactions until you hit the error.
Regards
Jonathan Lewis
________________________________________
Sent: 29 June 2018 10:23:02
Subject: ORA-01554: transaction concurrency limit reached reason:no undo
Hi,
lately I saw the error ORA-01554 and wonder in which circumstances it is
possible to hit this error.
- the database (12.1.0.2) is auto undo management
- transactions are set to 1647, transactions_per_rollback_segment to 5,
but I believe those are simply default settings and according to docs those
settings are ignored for automatic undo management
- in docs it is stated the undo on AUTO is limited mostly by the undo
tablespace size (but here this size was not depleted - overall there are
~524000 blocks with ~64000 used between midnight and 15 when the error was
hit according to v$undostat and maximum query lasting below 1h)
- also I would rather expect ORA-01652 on undo tablespace
From what I've found it seems the db creates undo segments automatically
and if no more space then assigns transactions to existing ones - but this
is very imprecise.
Anyone able to elaborate on that?
Regards
Remigiusz
--
------------------------------------------------------------
------------------------
------------------------------------------------------------
------------------------
--
------------------------------------------------------------------------------------
Remigiusz Sokołowski <***@gmail.com>
------------------------------------------------------------------------------------
Jonathan Lewis
2018-06-29 11:43:16 UTC
Permalink
"But I thought oracle db would create more undo segments, when needed."

My comments were a bit too concise - but I did say that "It seems a little unlikely that this would happan in typical system since Oracle would usually end up stealing an extent from an existing undo segment to use it as the first extent of a new undo segment."

To create more undo segments there has to be free space in the tablespace, or some undo segments that have extents that can be stolen (or released). The thought I had in mind was that if you had at least one old enough transaction that had not yet committed in each undo segment then you could end up with no free space and no releasable space and no stealable space.


(It's possible, I suppose, that if you have a massive peak of highly concurrent transactions over a very short period of time that Oracle might break because of an unexpected race condition. I'd prefer not to assume it's an esoteric bug until I have to, though.)


Regards
Jonathan Lewis

________________________________________
From: oracle-l-***@freelists.org <oracle-l-***@freelists.org> on behalf of Remigiusz Sokołowski <***@gmail.com>
Sent: 29 June 2018 11:38:42
To: oracle-***@freelists.org
Subject: Re: ORA-01554: transaction concurrency limit reached reason:no undo segment found with available slot params:0, 0 :

Pretty much that is what I need :-)

At the moment of checking on that db there were 12 undo segments and assuming the db was kept with them all the numbers are quite consistent.
I've checked the maxconcurrency in v$undostat for a week before the incident - with the peak from the incident it was 4.4 on average and 2 as median, so exactly as You said kept very low.
The transaction peak was obtained within less then 20 minutes - jump from around 100 tx to 100000 tx, so again as You said very high slope. And 12x34 is 408, which is quite close to 331 in maxconcurrency.

But I thought oracle db would create more undo segments, when needed.
While here it seems it keeps with the number, which as I understand, is established during the db opening or the txn pressure is so high, the db is not able to init a new undo segment at certain point in time fast enough to be ready for increased number of txn and at this point some number of sessions would report ORA-01554 - which one is true?

And many thanks :-)
Remigiusz

2018-06-29 11:34 GMT+02:00 Jonathan Lewis <***@jlcomp.demon.co.uk<mailto:***@jlcomp.demon.co.uk>>:
Taking a quick guess:

An (automatic) undo segment has 34 slots in the transaction table (the thing in the undo segment header).
If you and up with a small number N of undo segments then you can't have more than 34 * N concurrent transactions active because each one needs a transaction table slot and the next attempt to start a transaction would see ORA-01554

It seems a little unlikely that this would happan in typical system since Oracle would usually end up stealing an extent from an existing undo segment to use it as the first extent of a new undo segment. But it wouldn't be hard to set up a mechanism that started with a small number of undo segments in a relatively small undo tablespace - started some transactions (then leave them idle forever after the first change - e.g. they might have come in from a remote database) that made it impossible to free any extents, then did a lot of work to allocate all the extents (but still left a little space in allocated extents for continuting transactions), then started lots of transactions until you hit the error.

Regards
Jonathan Lewis


________________________________________
From: oracle-l-***@freelists.org<mailto:oracle-l-***@freelists.org> <oracle-l-***@freelists.org<mailto:oracle-l-***@freelists.org>> on behalf of Remigiusz Sokołowski <***@gmail.com<mailto:***@gmail.com>>
Sent: 29 June 2018 10:23:02
To: oracle-***@freelists.org<mailto:oracle-***@freelists.org>
Subject: ORA-01554: transaction concurrency limit reached reason:no undo segment found with available slot params:0, 0 :



Hi,

lately I saw the error ORA-01554 and wonder in which circumstances it is possible to hit this error.

Theoretically this is quite clear - the db hit the roof on concurrent transactions, but:
- the database (12.1.0.2) is auto undo management
- transactions are set to 1647, transactions_per_rollback_segment to 5, but I believe those are simply default settings and according to docs those settings are ignored for automatic undo management
- in docs it is stated the undo on AUTO is limited mostly by the undo tablespace size (but here this size was not depleted - overall there are ~524000 blocks with ~64000 used between midnight and 15 when the error was hit according to v$undostat and maximum query lasting below 1h)
- also I would rather expect ORA-01652 on undo tablespace

From what I've found it seems the db creates undo segments automatically and if no more space then assigns transactions to existing ones - but this is very imprecise.

Anyone able to elaborate on that?

Regards
Remigiusz
--
------------------------------------------------------------------------------------
Remigiusz Sokołowski <***@gmail.com<mailto:***@gmail.com><mailto:***@gmail.com<mailto:***@gmail.com>>>
------------------------------------------------------------------------------------



--
------------------------------------------------------------------------------------
Remigiusz Sokołowski <***@gmail.com<mailto:***@gmail.com>>
------------------------------------------------------------------------------------
--
http://www.freelists.org/webpage/oracle-l
Remigiusz Sokołowski
2018-06-29 12:34:42 UTC
Permalink
Many thanks, Johnatan - with this info I hope, quite well established
what happened and possibly how to prevent this in future - seems
_rollback_segment_count would enforce initially a higher number of
undo segements, thus raising the total possible number of concurrent
transactions

Regards
Remigiusz

p.s. sorry to not cut the answers, but not sure how to enforce gmail
not to attach previous mail in the text
--
------------------------------------------------------------------------------------
Remigiusz Sokołowski <***@gmail.com>
------------------------------------------------------------------------------------
--
http://www.freelists.org/webpage/oracle-l
Loading...