Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> Re: SET TRANSACTION statements within PL/SQL?
Fewer, but larger, undo segments (auto or rbs) can actually cause other
problems. If you have many processes running at the same time, you may
run into contention for the transaction table (undo header waits). If
you have very few processes running in parallel (but many transactions
running sequentially), you may run into space management issues (unable
to extend).
For this process only, you might look at creating 1 undo segment per parallel transaction and size them to 2x the largest transaction. This reduces the risk of header waits and space management issues.
Of course, no matter which approach you adopt, you always need to consider ORA-1555s. If you intend to reuse undo blocks as quickly as possible, you increase the risk. You can minimize the risk by 'partitioning' the data so that each process does not try to query data that may have been changed by another process.
Regards,
Daniel Fink
Powell, Mark D wrote:
>Mark, from within pl/sql you should probably consider using
>dbms_transaction.use_rollback_segment('segname') to assign DML activity to a
>specific rollback segment.
>
>Remember that the assignment is only maintained until a commit or rollback
>is issued and the assignment will have to be reset immediately after each
>transaction prior to doing any other work or the re-assignment will fail.
>
>You might want to consider re-creating your RBS segments so that you have
>fewer but larger segments available at all times. This would eliminate the
>need to try to assign segments to begin with.
>
>DDL statements are generally very small and do not require assignment which
>is a good thing considering that every DDL statement is preceeded and
>followed by an implicit commit making assignment a practical immpossibility.
>
>Just some thoughts on the matter.
>-- Mark D Powell --
>
>
>-----Original Message-----
>From: oracle-l-bounce_at_freelists.org
>[mailto:oracle-l-bounce_at_freelists.org]On Behalf Of Mark Richard
>Sent: Wednesday, August 25, 2004 12:07 AM
>To: oracle-l_at_freelists.org
>Subject: SET TRANSACTION statements within PL/SQL?
>
>Dear List,
>
>I am working on some large data conversion scripts and we would like to
>assign specific Rollback Segments to the queries. I have done some testing
>in standard SQL using "set transaction use rollback segment blah" and the
>results have been positive.
>
>Typically, however, we write most conversion scripts in PL/SQL to provide a
>standard mechanism for exception handling and also to deal nicely with
>various tests / reporting. My concern is how to combine the set
>transaction statement with PL/SQL. The PL/SQL blocks are simply anonymous
>blocks within a script - Can I put a "set transaction" statement before the
>DECLARE line or does it need to be within the PL/SQL itself?
>
>Also, sometimes the queries are just placed within the PL/SQL and other
>times EXECUTE IMMEDIATE is used (particularly when the same PL/SQL block
>first adds a new column to be populated) - I at least have the freedom to
>use either approach if it matters. Does this confuse the issue at all?
>Unfortunately I'm not clear on how the parsing of PL/SQL and calling of
>EXECUTE IMMEDIATE fit amongst a "set transaction" statement. Suggestions
>anyone?
>
>Thanks in advance,
>
>Mark.
>
>-----------------------------------------------------------------
>----------------------------------------------------------------
>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
>-----------------------------------------------------------------
>
>
-- 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 Wed Aug 25 2004 - 08:57:17 CDT