Use the DISPLAY_JOURNAL table function on QAUDJRN to answer a very common question.
An area I deal with regularly is change management. We promote programs from a development machine to a production machine, and one of the regular tasks is to make sure those objects are in sync, which requires comparing objects across machines. In an upcoming article, I’ll show how I compare existing objects using the OBJECTS_STATISTICS table function and the BOUND_MODULE_INFO view, but for this article I want to address the problem when a program that should be there simply isn’t.
Who Deleted My Program?
A particularly difficult situation arises when a program goes missing. The program is gone, so we can’t look at the object to see who deleted it. If only there were a log of some kind that showed object deletions…and there is! It’s QAUDJRN! And today we’re going to learn how to extract program deletion information from that journal using SQL statements.
The statement itself is relatively straightforward; the most unusual piece is the syntax required to access a table function. The other part is that you need to use the full 30-character QSYS name for the object, which is not entirely intuitive. But let’s look at the statement and the result:
selectUSER_NAME,ENTRY_TIMESTAMPas WHEN,
JOB_NUMBER || '/' || TRIM(JOB_USER) || '/' || JOB_NAME as JOB
from table(DISPLAY_JOURNAL('QSYS', 'QAUDJRN'))
where JOURNAL_ENTRY_TYPE = 'DO' and OBJECT = 'TESTPGM MYLIB'
USER_NAMEWHEN JOB
PLUTAJOE2022-12-04-12.53.06.305696373908/PLUTAJOE/JOEWS1
The way this statement works is that we’ve specifically selected the program in question (using the fully qualified 30-character name ‘TESTPGM MYLIB’) and the entry type of DO. IBM has an online list of all entry types, and DO is the entry type for object deletion. This simple statement extracts the timestamp when the deletion occurred, the user who performed the deletion, and the job in which the deletion was executed. Please note that this only works on the most recent journal entries. To search through all available history on the machine, you need to direct the query to all of the journal receivers, which requires this slight variation:
select ENTRY_TIMESTAMPas WHEN, USER_NAME,
JOB_NUMBER || '/' || TRIM(JOB_USER) || '/' || JOB_NAME as JOB
from table(DISPLAY_JOURNAL('QSYS', 'QAUDJRN',
STARTING_RECEIVER_NAME => '*CURCHAIN'))
where JOURNAL_ENTRY_TYPE = 'DO' and OBJECT = 'TESTPGM MYLIB'
As noted, this particular query is very specific; we’re looking for when the program MYLIB/TESTPGM was deleted. But it doesn’t have to be that specific. We can change the WHERE clause to change the search criteria:
where JOURNAL_ENTRY_TYPE = 'DO' and OBJECT_TYPE = '*PGM'
This will show deletions for all programs. Or perhaps we want to see all program creations and deletions in a specific library. We would change the query to look for multiple entry types, including only objects of type *PGM, and check the library name in the second 10 characters (position 11-20) of the fully qualified object name. The WHERE clause for the modified query would look like this:
where JOURNAL_ENTRY_TYPE in ('CO', 'DO') and OBJECT_TYPE = '*PGM'
and substr(OBJECT,11,10)= 'MYLIB'
You can get more information about DISPLAY_JOURNAL, including all the fields, from the IBM documentation.
Other Uses of the Audit Journal
As you might guess, this journal contains a lot more information than I’ve touched on so far. For example, you can extract creation and deletion events for other object types. An uncommon but extremely useful case is to check a user profile. Not only can we extract creation and deletion events, but we can also see changes. This includes password changes (you won’t see the actual password, only that the user profile was changed, but that’s usually all that’s needed to identify when a password was changed).
Another critical entry is the SV type, which indicates that a system value has changed. Given the potentially drastic sitewide ramifications of system values, it’s definitely nice to be able to see who touched one. An entire category of events centers on the PA and PS entry types. The PA type is logged whenever a program is changed to adopt authority. This is critical because it’s the most common way to circumvent normal IBM i authority rules. There are certainly legitimate uses for this action, but it’s something that should be tightly controlled and closely monitored. Similar scrutiny should be applied to the PS type, which indicates that a job has swapped user profiles, in effect becoming another user. While this is essential for server jobs to function correctly, it is also a potential back door to the system.
If you really want to get into some of the nuances of these entries, I recommend that you use the link I gave earlier in the article to the journal entry types. I’ll let you rummage through those, but here are a few that you might find interesting: ST (use of service tools), RU (restoring user profile authority), and SE (subsystem routing entry changed). Each of those has some potentially serious effects that aren’t within the realm of normal day-to-day operations.
One Additional Feature
One of the really nice things about Db2 for the IBM i is how easy IBM has made it for us to access our entire network.
221204RD - Practical SQL - Who Deleted my Program(1) - Copy.docx
If we have set up a relational database directory entry, we can access the data on any other machine or partition in the company, using something called a three-part name. Without going into too much detail, accessing a file on another partition is as simple as saying SELECT * FROM OTHERPART.MYLIB.MYFILE, where OTHERPART is the alias name within the relational database directory. Use the WRKRDBDIRE command to review the entries. What that means is that we can actually run queries on other machines; this is very helpful when implementing systemwide utilities. Be warned; there is a little bit of extra work when accessing a table function on another partition; I’ll address that in another article.
As Usual, Not a Silver Bullet
The biggest caveat here is that the audit journal doesn’t hold infinite history. How far back it goes depends on your journal receiver retention policy. My production partition goes back only a few days, while my development holds about a month of history. So it’s important to get to the history right away.
That being said, the audit journal is a critical tool to track down a lot of system anomalies that are otherwise difficult to identify. You might even run a nightly job to save some of the more important entries, like object deletion and program creation. With SQL, that’s a very simple utility.
Final Note
Some of the important information in these journal entries is buried in the entry-specific portion of the entry, and if we want to get to that information, we have to substring it out of the ENTRY_DATA column. Given how powerful and useful these audit journal entries can be, IBM decided to create some utility views to make them easier to use. You can find documentation about these functions in IBM documentation for Audit journal entry services. They are definitely a bit more convenient, but realize that if you want to look for multiple entry types (such as CO, create object, and DO, delete object), you’ll need two different queries. But still, it’s a nice timesaver when looking for a specific event.
I hope you enjoy digging into the many capabilities of the DISPLAY_JOURNAL table function and can find ways to make this functionality useful in your own environment.
LATEST COMMENTS
MC Press Online