<?xml version="1.0" encoding="UTF-8"?> <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"> <html lang="en-us" xml:lang="en-us"> <head> <meta http-equiv="Content-Type" content="text/html; charset=utf-8" /> <meta name="security" content="public" /> <meta name="Robots" content="index,follow" /> <meta http-equiv="PICS-Label" content='(PICS-1.1 "http://www.icra.org/ratingsv02.html" l gen true r (cz 1 lz 1 nz 1 oz 1 vz 1) "http://www.rsac.org/ratingsv01.html" l gen true r (n 0 s 0 v 0 l 0) "http://www.classify.org/safesurf/" l gen true r (SS~~000 1))' /> <meta name="DC.Type" content="reference" /> <meta name="DC.Title" content="Select a stringent level of commitment control" /> <meta name="abstract" content="Do not use commitment control unnecessarily. The overhead that is associated with locking not only increases utilization, but also reduces concurrency. However, if your application is not read-only, commitment control may be required." /> <meta name="description" content="Do not use commitment control unnecessarily. The overhead that is associated with locking not only increases utilization, but also reduces concurrency. However, if your application is not read-only, commitment control may be required." /> <meta name="DC.Relation" scheme="URI" content="rzaikodbcperfarch.htm" /> <meta name="DC.Relation" scheme="URI" content="../rzakj/rzakjcommitkickoff.htm" /> <meta name="DC.Relation" scheme="URI" content="../db2/rbafzmst02.htm" /> <meta name="copyright" content="(C) Copyright IBM Corporation 1999, 2006" /> <meta name="DC.Rights.Owner" content="(C) Copyright IBM Corporation 1999, 2006" /> <meta name="DC.Format" content="XHTML" /> <meta name="DC.Identifier" content="odbcselectcommitctl" /> <meta name="DC.Language" content="en-us" /> <!-- All rights reserved. Licensed Materials Property of IBM --> <!-- US Government Users Restricted Rights --> <!-- Use, duplication or disclosure restricted by --> <!-- GSA ADP Schedule Contract with IBM Corp. --> <link rel="stylesheet" type="text/css" href="./ibmdita.css" /> <link rel="stylesheet" type="text/css" href="./ic.css" /> <title>Select a stringent level of commitment control</title> </head> <body id="odbcselectcommitctl"><a name="odbcselectcommitctl"><!-- --></a> <!-- Java sync-link --><script language="Javascript" src="../rzahg/synch.js" type="text/javascript"></script> <h1 class="topictitle1">Select a stringent level of commitment control</h1> <div><p>Do not use commitment control unnecessarily. The overhead that is associated with locking not only increases utilization, but also reduces concurrency. However, if your application is not read-only, commitment control <em>may</em> be required.</p> <div class="section"><p>A common alternative is to use <strong>optimistic locking</strong>. Optimistic locking involves issuing explicit UPDATEs by using a WHERE clause that uniquely determines a particular record. Optimistic locking ensures that the record does not change after it is retrieved.</p> </div> <div class="section"><p>Many third-party tools use this approach, which is why they often require a unique index to be defined for updatable tables. This allows the record update to be made by fully qualifying the entire record contents. Consider the following example: </p> <pre> UPDATE table SET C1=new_val1, C2=new_val2, C2=new_val3 WHERE C1=old_val1 AND C2=old_val2 AND C3=old_val3</pre> </div> <div class="section"><p>This statement would guarantee that the desired row is accurately updated, but only if the table contained only three columns, and each row was unique. A better-performing alternative would be: </p> <pre> UPDATE table SET C1=new_val1, C2=new_val2, C3=CURRENT_TIMESTAMP WHERE C3=old_timestamp</pre> </div> <div class="section"><div class="p">This only works, however, if the table has a timestamp column that holds information on when the record was last updated. Set the new value for this column to CURRENT_TIMESTAMP to guarantee row uniqueness. <div class="note"><span class="notetitle">Note:</span> This technique does not work with any object model that uses automation data types (for example, Visual Basic, Delphi, scripting languages). The variant DATE data type has a timestamp precision of approximately one millisecond. The iSeries™ server timestamp is either truncated or rounded off, and the WHERE clause fails.</div> </div> </div> <div class="section"><p>If commitment control is required, use the lowest level of record locking possible. For example, use <strong>*CHG:</strong> over <strong>*CS</strong> when possible, and never use <strong>*ALL</strong> when <strong>*CS</strong> provides what you require. </p> </div> </div> <div> <div class="familylinks"> <div class="parentlink"><strong>Parent topic:</strong> <a href="rzaikodbcperfarch.htm" title="For the iSeries Access for Windows ODBC driver, all of the internal data flows between the client and the server are chained together, and transmit only when needed.">The performance architecture of the iSeries Access for Windows ODBC driver</a></div> </div> <div class="relinfo"><strong>Related information</strong><br /> <div><a href="../rzakj/rzakjcommitkickoff.htm">Database Commitment control</a></div> <div><a href="../db2/rbafzmst02.htm">DB2 UDB for iSeries SQL Reference</a></div> </div> </div> </body> </html>