Transaction Processing: Retrieving Query Results. Read Part 1 here and Part 2 here.
Editor's Note: This article is excerpted from chapter 6 of QuickStart Guide to Db2 Development with Python, by Roger Sanders.
When an SQL statement other than the SELECTstatement is executed, the only additional processing that might be performed is a check of the return code produced to verify the statement executed as expected. Or, a check to determine how many rows were affected by the operation. However, when a SELECTstatement (i.e., a query) is executed, any results that might have been produced will typically need to be retrieved and processed. With the ibm_db library, all the query results produced can be copied to a dictionary, tuple, or both (by calling the ibm_db.fetch_assoc(), ibm_db.fetch_tuple(), or ibm_db.fetch_both() API).Alternately,theibm_db.fetch_row()API can be used to advance the cursor to the next row (or move the cursor to a specific row) in a result set, and the ibm_db.result()API can be used to copy data from individual columns in that row to application variables.
When the ibm_db_dbi library is used, one or more records can be retrieved and copied to a tuple by executing the .fetchone(), .fetchmany(), or .fetchall() Cursor object method.
The following pseudo-source code example illustrates how ibm_ db.fetch_tuple() API in the ibm_db Python library might be used to retrieve data from a result set:
#! /usr/bin/python3
# Load The Appropriate Python Modules
import ibm_db
# Define And Initialize The Appropriate Variables
...
record = False
# Construct The String That Will Be Used To Connect
# To A Database, Then Establish A Connection
...
# Define The SQL Statement To Be Executed
sqlStmt = "SELECT deptname FROM department "
sqlStmt += "WHERE admrdept = 'A00'"
# Execute The SQL Statement Just Defined
results = ibm_db.exec_immediate(connID, sqlStmt)
# As Long As There Are Records In The Result Set, ...
noData = False
while noData is False:
# Retrieve A Record And Store It In A Tuple
record = ibm_db.fetch_tuple(results)
# If There Are No More Records, Exit The Loop
if record is False:
noData = True
# Otherwise, Display The Data Retrieved
else:
print(record[0])
...
The next pseudo-source code example illustrates how the .fetchall() Cursor object method could be used to retrieve data from a result set if the ibm_db_dbi Python library were used instead:
#! /usr/bin/python3
# Load The Appropriate Python Modules
import ibm_db_dbi
# Define And Initialize The Appropriate Variables
...
record = False
# Construct The String That Will Be Used To Connect
# To A Database, Then Establish A Connection
...
# Retrieve The Cursor Object That Was Created For
# The Connection Object
if not connID is None:
cursorID = connID.cursor()
# Define The SQL Statement To Be Executed
sqlStmt = "SELECT deptname FROM department "
sqlStmt += "WHERE admrdept = 'A00'"
# Execute The SQL Statement Just Defined
if not cursorID is None:
cursorID.execute(sqlStmt)
# Retrieve All Of The Records Returned
# And Store Them In A Python Tuple
results = cursorID.fetchall()
# Print Every Record Returned
for value in results:
print("{:24}" .format(value[0]))
...
Transaction Processing: Obtaining Result Set Information
If a SELECT statement is hard-coded into an application, the structure of the result set that will be produced is typically known in advance. However, if the SELECT statement used is created at application run time, you may need to acquire this information before you can process the results. With the ibm_db library, information about a result set can be obtained by executing any of the following APIs:
- num_fields()
- field_name()
- field_num()
- field_type()
- field_width()
- field_display_size()
- field_precision()
- field_precision()
When the ibm_db_dbi library is used, similar information can be obtained by examining the contents of the .description Cursor object attribute. The following pseudo-source code example illustrates how this attribute can be examined to obtain result set column information:
#! /usr/bin/python3
# Load The Appropriate Python Modules
import ibm_db_dbi
# Define And Initialize The Appropriate Variables
...
# Construct The String That Will Be Used To Connect
# To A Database, Then Establish A Connection
...
# Retrieve The Cursor Object That Was Created For
# The Current Connection Object
if not connID is None:
cursorID = connID.cursor()
# Define The SQL Statement To Be Executed
sqlStmt = "SELECT * FROM department "
sqlStmt += "WHERE admrdept = 'A00'"
# Execute The SQL Statement Just Defined
if not cursorID is None:
cursorID.execute(sqlStmt)
# Retrieve Attribute Information For Every Column
# In The Result Set Produced By The Statement
colInfo = cursorID.description
# Display Column Name And Data Type Information
x = 0
for record in colInfo:
print("Column name : ", end="")
print(colInfo[x][0])
dataTypes = colInfo[x][1]
typeNames = []
for type in dataTypes:
typeNames.append(type)
print("Data type name(s) : ", end="")
print(typeNames[0])
del typeNames[0]
for type in typeNames:
print(' ' * 27, end="")
print("{}" .format(type))
# Increment The x Variable And Print A Blank Line
x += 1
print()
...
Transaction Processing: Terminating the Current Transaction
You may recall that in Chapter 2, “Structured Query Language,” we saw that a transaction (also known as a unit of work) is a sequence of one or more SQL operations that are grouped together as a single unit, usually within an application process. Transactions are important because the initiation and termination of a single transaction defines points of data consistency within a database. Either the effects of all operations performed within a transaction are applied to the database and made permanent (committed), or, they are backed out (rolled back) and the database is returned to the state it was in before the transaction began.
When it comes to managing transactions, Python applications can be configured such that they run in one of two modes: auto-commit mode or explicit-commit mode. When auto-commit mode is used, every SQL operation performed is treated as a complete, individual transaction that is automatically committed as soon as it is successfully executed. When explicit-commit mode is used, transactions are started implicitly the first time an application connects to a data source or the first time an SQL operation is performed after a previously running transaction has been terminated. With Python applications, such transactions are explicitly ended when the ibm_db.commit() API or ibm_db.rollback() API is executed (ibm_db library) or the .commit() or .rollback() Connection object method is invoked (ibm_db_dbi library).
When the ibm_db library is used, auto-commit mode is enabled by default. However, the actual commit mode used can be controlled by assigning the value ibm_db.SQL_AUTOCOMMIT_ON or ibm_db.SQL_ AUTOCOMMIT_OFF to the ibm_db.SQL_ATTR_AUTOCOMMIT connection option at the time a connection to a Db2 database is made. Alternatively, the ibm_db.autocommit() API can be used to change the commit mode used after a database connection has been established. When the ibm_db_ dbi library is used, explicit-commit is the only commit mode available.
Consequently, every transaction must be terminated by executing the .commit() or .rollback() method of the Connection object that was returned when the ibm_db_dbi.connect() API was executed. Regardless of which type of commit mode is used, all transactions associated with a specific database connection should be completed before that connection is terminated.
When running in explicit-commit mode, the following should be taken into consideration:
- Only the current, active transaction can be committed or rolled back; therefore, all dependent SQL operations should be performed within the same
- Various table-level and row-level locks can be held by a single transaction and these locks are not released until the transaction is Consequently, other concurrently running transactions may be prevented from getting access to the locked data until the transaction holding the locks ends.
- Any transaction that has not been committed or rolled back before an application ends will be “lost” and its effects will be discarded. The same is true if a system or application failure Therefore, transactions should be ended as soon as reasonably possible.
When defining transaction boundaries, keep in mind that all resources associated with a transaction—with the exception of those coupled with a held cursor—are released. However, prepared SQL statements and parameter marker bindings are maintained from one transaction to the next. Therefore, once an SQL statement has been prepared, it does not need to be prepared again—even after a commit or rollback operation is performed—provided it remains associated with the same IBM_DBStatement or Cursor object.
More transaction processing awaits in Part 4, coming soon in an upcoming issue of MC TNT. Can't wait? You can pick up Roger Sander's book, QuickStart Guide to Db2 Development with Python, at the MC Press Bookstore Today!
LATEST COMMENTS
MC Press Online