Minimize your application development costs by moving your timestamp logic into the DB2 for i database engine.
Many applications have logic to capture and record a timestamp that indicates when certain business events occurred, such as when an order was placed or changed. While this application logic is fairly simple, there is still a cost to coding, testing, and maintaining this code. You can reduce these application development costs by instead moving this timestamp logic into your DB2 table definitions and relying on DB2's "automatic" timestamp support.
The example table definition shown below will be used to explain the capabilities of DB2's automatic timestamp support. Let's start by using the automatic timestamp behavior of the ordOrig column. The purpose of the ordOrig column is to store the timestamp value of when the order was originally placed into the system. The DEFAULT CURRENT TIMESTAMP clause enables DB2 to automatically supply this original-order timestamp value. This ability to have DB2 use current date, time, or timestamp values as the default value for a column has been available for many releases, all the way back to V3R1.
CREATE TABLE orders(
ordID INTEGER PRIMARY KEY,
ordCust INTEGER,
ordStatus CHAR(1),
ordOrig TIMESTAMP
NOT NULL
DEFAULT CURRENT TIMESTAMP,
ordLChg TIMESTAMP
NOT NULL
IMPLICITLY HIDDEN
FOR EACH ROW ON UPDATE
AS ROW CHANGE TIMESTAMP);
With the default clause in place, DB2 will assign the current default value whenever the row (or record) being inserted does not supply a value for the ordOrig column. The SQL Insert statement provides two different methods of not supplying a column value on an insert operation. The following code demonstrates these two techniques.
INSERT INTO orders VALUES(1001, 9398, 'P', DEFAULT)
INSERT INTO orders(ordID, ordCust, ordStatus)
VALUES(1001, 9398, 'P')
The first Insert statement uses the DEFAULT keyword to have DB2 use the defined default value for the specified column. In this case, the specified column is the ordOrig column since the DEFAULT keyword is the fourth value on the VALUES clause and ordOrig is the fourth column within the orders table definition. The second Insert statement omits the ordOrig column from the list of column names specified for the orders table. This omission of the ordOrig column prevents the Insert statement from supplying a value for the column. When a column value is not provided on an Insert operation, DB2 uses the default value, which in this case is the current timestamp value. Both SQL Insert techniques result in DB2 assigning the current timestamp value to the ordOrig column. The default current timestamp behavior for native, non-SQL interfaces is discussed later.
To confirm that DB2 correctly assigns the current timestamp value for the ordOrig column, a simple query (SELECT * FROM orders) can be run after the Insert statement completes. Figure 1 contains the output of this simple query for the example Insert statements. Even though neither Insert statement supplied a timestamp value, the ordOrig column contains the timestamp value of when the order was stored into the orders table.
Figure 1: Here's the example output from the SELECT * FROM order query. (Click images to enlarge.)
You may be wondering why the ordLChg column is missing from the SELECT * FROM order output in Figure 1. The ordLChg column is not missing because of image editing software; instead, this behavior is the result of the IMPLICITLY HIDDEN clause. The IMPLICITLY HIDDEN syntax was delivered in IBM i 6.1 to provide the ability for a column value to be returned on a SQL SELECT statement only when the column is explicitly named. This new syntax is useful for columns that exist only for internal processing, such as audit trails, and that provide no value to the business applications accessing the table. The IMPLICITLY HIDDEN clause is not limited to just timestamp columns; it can be specified for any data type. The IMPLICITY HIDDEN clause is not honored by non-SQL interfaces.
As a result, the only way to see the value of the ordLChg column is to explicitly name that column on the SELECT statement. Here's an example of a Select statement that explicitly includes the ordLChg column:
SELECT ordId, ordCustid, ordStatus, ordOrig, ordLChg
FROM orders
Figure 2 contains the result of this Select statement.
Figure 2: This is the output from the SELECT statement that explicitly names ordLChg column.
The output in Figure 2 also demonstrates a portion of the second automatic DB2 timestamp behavior, known as Row Change Timestamp support, which was also made available with the IBM i 6.1 release. Notice how the example Insert statement also assigns the same timestamp value to the ordLChg column as it did to the ordOrig column. Even though the row-change timestamp clause, FOR EACH ROW ON UPDATE AS ROW CHANGE TIMESTAMP, references only the UPDATE operation, this clause causes DB2 to generate timestamp values for both insert and update operations. Furthermore, DB2 assigns the generated timestamp value for both SQL and non-SQL interfaces and ignores any user-supplied values for a row-change timestamp column. It should be noted that the row-change timestamp support can be used independently from the IMPLICITLY HIDDEN clause.
To see the impact of the row-change timestamp clause on Update operations, assume the following SQL Update statement has been executed to record that the items for this order have been shipped:
UPDATE orders SET ordStatus='S' WHERE ordId=1001
After this Update request is completed, another Select statement that explicitly requests ordLChg is run. This produces the output found in Figure 3. The ordLChg now contains an updated timestamp value that signifies that at least one column in this row from the orders table has been changed and identifies when that change occurred. In this example, the change to the ordStatus column caused the row-change timestamp column to be updated automatically by DB2. The row-change timestamp column is updated every time a row is updated in the orders table, all without any assistance from an application developer.
Figure 3: This is the output from the explicit SELECT statement after Update.
If you want to ensure that DB2 always assigns and maintains the timestamp values for these two columns for the native, non-SQL interfaces, it would be simplest to create a logical file over the orders table that excludes the ordOrig and ordLChg fields. The native, non-SQL interfaces would then use the logical file whenever an insert or update operation needs to be performed on the orders table. The usage of the logical file is just a precaution to prevent applications from assigning a non-default value to the ordOrig column defined with the DEFAULT CURRENT TIMESTAMP clause. As mentioned previously, DB2 always ignores any application or user-supplied values for row-change timestamp columns; this is true for both SQL and non-SQL interfaces.
Hopefully, you now have a good understanding of how to minimize your application development costs by moving your timestamp logic into the DB2 for i database engine.
as/400, os/400, iseries, system i, i5/os, ibm i, power systems, 6.1, 7.1, V7,
LATEST COMMENTS
MC Press Online