Use the Gripping Charm to grasp the possibilities that lie ahead. Read how Scott dodges danger and dementors with DB2 for i spells.
Good, you’re back. I was beginning to think that you had encountered some ugly business. After all, there is danger at every turn. For myself, I have been keeping a very public profile since we last spoke to one another. With the rollout of IBM i 7.3, everyone wants to know “What’s New in DB2 for i.” As I do my level best to tell them about the DB2 for i enhancements, I notice that frequently people aren’t fully utilizing the capabilities already at their fingertips. As you’ll read in this episode, an established DB2 for i column-level control will rescue me from an untimely demise.
In the previous episode, I shared the awful news that dementors were in the mist. I have since learned from my fellow Slytherin housemates that the Ministry of Magic has ordered the dementors as a protectionary measure for vulnerable students. I suspect those troublemakers in Gryffindor are at it again. Why they continue to get away with breaking the rules is beyond me, but their time will come.
To help you grasp the full possibilities of how to use DB2 for i’s enhancements, I have conjured up a whopper of a Gripping Charm. I don’t know how long this charm will last, so you really should apply yourself fully to learn about IBM i 7.3.
Previously, I explained how DB2 for i now includes a Time-Turner, in the form of System-period Temporal Table support. Figure 1 shows how simple it is to enable Temporality. So easy in fact, even a first-year student is allowed to use this support.
Figure 1: How to establish a temporal table
As the figure shows, three columns need to be added to your production table. These columns are known as GENERATED ALWAYS, which means that DB2 for i is responsible for supplying the values. SQL applications don’t need to change to compensate for the existence of the new column. When native I/O is used, DB2 for i will tolerate any sort of data in the row image and produce the correct value.
What is the purpose of these columns?
- GENERATED ALWAYS AS ROW BEGIN (aka row_birth)—The time when this row instance came to exist. The birth of the row.
- GENERATED ALWAYS AS ROW END (aka row_death)—The time when this row instance ceased to exist as an active row. The death of the row.
- GENERATED ALWAYS AS TRANSACTION START ID—The time of the first change made within the transaction or “unit of work.”
The ADD PERIOD SYSTEM_TIME specification is used to formalize the use of system time period specification and is a prelude to the other operations in the figure.
Next, you need to create the history table. The format of the history table must exactly match the production table, and as you can see, the CREATE TABLE … LIKE SQL statement can be used.
Finally, the ALTER TABLE ADD VERSIONING statement is used to hand over control of the history table to DB2 for i. “Versioning” is the term used to describe when history management is enabled. Conversely, ALTER TABLE DROP VERSIONING can be used to disable history management.
When versioning is enabled, the database will insert rows into the history table when rows are updated or deleted. For both update and delete, the previous instance of the row has died, so the dead row is added to the history file.
If you’re wondering about the storage implications for this support, here are some points to ponder:
- Review the rate at which rows are updated and deleted to estimate the expected history table growth rate. How?
Sonorus: Use SQL of course!
SELECT UPDATE_OPERATIONS, DELETE_OPERATIONS
FROM QSYS2.SYSTABLESTAT
WHERE TABLE_SCHEMA = 'TOYSTORE' AND TABLE_NAME = 'SALES';
- Reflect upon business requirements to determine how long historical rows need to be kept in the history table. The user who created the history table can (and should) periodically delete historical rows that have aged beyond the retention window.
- The history table must be an SQL table, but you could choose to implement it as a partitioned table.
- Consider whether you’ll reap some storage and processing savings by retiring any user-maintained history or point-in-time detail capture. Use the Lumos Maxima charm to help you seek out trigger programs that should be changed or perhaps even deleted in their entirety.
DB2 for i’s Invisibility cloak
Dementors are an awful bunch, but they aren’t that difficult to overcome. I used an invisibility cloak to hide myself from harm. Did you know that DB2 for i users have their own invisibility cloak? Columns within tables can be hidden from SQL users by defining the column as IMPLICITLY HIDDEN.
IMPLICITLY HIDDEN is defined as: Indicates the column is not visible in SQL statements unless it is referred to explicitly by name. For example, SELECT * FROM ACCOUNT will not return any hidden columns in the result. A table must contain at least one column that is not IMPLICITLY HIDDEN.
As shown in Figure 2, we can use this cloaking ability to hide the three temporal table columns from SQL users. Note that hidden columns are not cloaked to native I/O operations. If programs using native I/O directly reference the physical file, those programs will need to be recreated to avoid a format level-check error. If those same programs only reference logical files (a layer of data abstraction), there is no need to rebuild.
Figure 2: How to hide temporal columns from SQL users
Till Next Time…
The next episode will include something your auditors will love. Stay tuned and you’ll be equipped to confound your colleagues with how quickly you moved the business ahead. But remember, don’t speak of “he who shall not be named”!
LATEST COMMENTS
MC Press Online