19
Fri, Apr
5 New Articles

TechTip: Simplify Your Development with DB2 Automatic Timestamp Support

Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

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.

 

090310MilliganFig1     

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.

 

090310MilliganFig2 

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.

 

090310MilliganFig3

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,

 

Kent Milligan
Kent Milligan is a Senior Db2 for i Consultant in the IBM Lab Services Power Systems Delivery Practice.  Kent has over 25 years of experience as a Db2 for IBM i consultant and developer working out of the IBM Rochester lab. Prior to re-joining the DB2 for i Lab Services practice in 2020, Kent spent 5 years working on healthcare solutions powered by IBM Watson technologies. Kent is a sought-after speaker and author on Db2 for i & SQL topics.
BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$0.00 Raised:
$

Book Reviews

Resource Center

  • SB Profound WC 5536 Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation. Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects. The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY the one package that solves all your document design and printing challenges on all your platforms. Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. How can you be sure you won’t miss important system events? Automate your message center with the Robot Message Management Solution. Key features include:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing. Manage your reports with the Robot Report Management Solution. Key features include:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed. Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • Profound Logic Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: