Establishing a Db2 server or database connection and a look at transaction processing. Read Part 1 here.
Editor's Note: This article is excerpted from chapter 6 of QuickStart Guide to Db2 Development with Python, by Roger Sanders.
Establishing a Db2 Server or Database Connection
Before any type of operation can be performed against a Db2 server or database, a connection to that server or database must first be established. Python applications that use the ibm_db library can establish Db2 server and database connections by executing the ibm_db.connect() or the ibm_ db.pconnect() API. Python applications using the ibm_db_dbi library must execute the ibm_db_dbi.connect() API instead.
You can find the syntax for these APIs, (as well as the other APIs in the ibm_db library) in the IBM Db2-Python GitHub repository. That said, the most common way of executing these APIs is by providing a connection string for the first input parameter. The connection string used must adhere to the following format:
DRIVER={IBM DB2 ODBC DRIVER};
ATTACH=connType;
DATABASE=dbName;
HOSTNAME=hostName;
PORT=port;
PROTOCOL=TCPIP;
UID=userName;
PWD=password
where:
connType Specifies whether the connection is to be made to a Db2 server or a database; TRUE indicates the connection is to be made to a Db2 server, and FALSE indicates the connection is to be made to a database.
dbName The name of the Db2 server or database the connection is to be made to. This option is only required when connecting to a Db2 database.
hostName The host name or IP address of the Db2 server the connection is to be made to. (The host name is the name of the Db2 server, as it is known to the TCP/ IP network.) This option is only required when connecting to a Db2 server.
port The port number that receives Db2 connections on the server the connection is to be made to. (Port number 50000 is used by default.) This option is only required when connecting to a Db2 server.
userName The username/ID that is to be used for authentication purposes when the connection is first established.
password The password that corresponds to the username/ID specified in the userName parameter.
Thus, if the ibm_db library is used, the Python code needed to establish a connection to a database named SAMPLE with the user ID “db2inst1” and the password “Passw0rd” would look something like this:
#! /usr/bin/python3
# Load The Appropriate Python Modules
import ibm_db
# Define And Initialize The Appropriate Variables
dbName = "SAMPLE"
userID = "db2inst1"
passWord = "Passw0rd"
connID = None
# Construct The String That Will Be Used To Establish
# A Database Connection
connString = "DRIVER={IBM DB2 ODBC DRIVER}"
connString += ";ATTACH=FALSE"
connString += ";DATABASE=" + dbName
connString += ";PROTOCOL=TCPIP"
connString += ";UID=" + userID
connString += ";PWD=" + passWord
# Attempt To Establish A Connection
connID = ibm_db.connect(connString, '', '')
if connID is None:
print("\nERROR: Unable to connect.")
exit(-1)
# Display A Status Message
print("Connected!")
...
If the ibm_db_dbi library is used, the Python code needed to establish the exact same connection would be very similar; the following code snippet highlights the changes that would be required:
#! /usr/bin/python3
# Load The Appropriate Python Modules
import ibm_db_dbi
...
# Attempt To Establish A Connection
connID = ibm_db_dbi.connect(connString, ‘’, ‘’)
if connID is None:
print("\nERROR: Unable to connect.") exit(-1)
# Display A Status Message
print("Connected!")
...
Once a Db2 server or database connection is established, it remains in effect until it is explicitly terminated or until the application that established the connection ends.
Transaction Processing: Executing SQL Statements
The bulk of the work that is performed by most Python applications that interact with Db2 servers and databases revolves around transaction processing, which is where SQL statements are passed to the appropriate server or database, via API calls (ibm_db library) or object methods (ibm_ db_dbi library), for execution. This is also where operations performed against a Db2 database are made permeant or backed out, and where the results of SQL queries are retrieved. Depending upon which Db2 Python library is used, there can be two ways in which SQL statements are executed:
- Prepare and then Execute. This approach separates the preparation of an SQL statement from its actual execution and is typically used when a statement is to be executed repeatedly (often with different values being supplied for parameter markers with each execution). This method is also used when an application needs information about the columns that will exist in the result set that will be produced when the statement is executed, in advance. The ibm_ prepare() and ibm_db.execute() APIs found in the ibm_db library are used to process SQL statements in this manner.
- Execute immediately. This approach combines the preparation and execution of an SQL statement into a single step and is typically used when a statement only needs to be executed once. The exec_ immediate() API (ibm_db library) and the .execute() Cursor object method (ibm_db_dbi library) are used to process SQL statements in this manner.
Both methodologies allow the use of parameter markers in place of constants or expressions in the SQL statements used. Parameter markers are represented by question mark (?) characters and indicate positions in an SQL statement where the value of one or more application variables is to be substituted when the statement is executed. If an application variable has been associated with a specific parameter marker in an SQL statement, that variable is said to be “bound” to the parameter marker; such bindings can be carried out by executing the ibm_db.bind_param() API—provided the ibm_db library is being used.
The following pseudo-code example illustrates how an application variable would be bound to a parameter marker that has been coded in a simple SELECT statement. It also illustrates the way in which a value would be provided for the bound parameter before the statement is executed:
#! /usr/bin/python3
# Load The Appropriate Python Modules
import ibm_db
# Define And Initialize The Appropriate Variables
...
deptID = ['B01', 'C01', 'D01', 'E01']
# 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 projname FROM project "
sqlStmt += "WHERE deptno= ?"
# Prepare The SQL Statement Just Defined
prepStmt = ibm_db.prepare(connID, sqlStmt)
# If The SQL Statement Could Not Be Prepared
# Display An Error Message And Exit
if prepStmt is False:
print("Unable to prepare the statement.")
# For Every Value Specified In The deptID List, ...
for x in range(0, 4):
# Assign A Value To The Appropriate Variable
pValue = deptID[x]
# Bind The Variable To The Parameter Marker
retCode = ibm_db.bind_param(prepStmt, 1, pValue,
ibm_db.SQL_PARAM_INPUT, ibm_db.SQL_CHAR)
# Execute The Prepared Statement
rc = ibm_db.execute(prepStmt)
# Retrieve And Print The Records Produced
...
More transaction processing awaits in Part 3, 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