ILE presents some challenges for change management, but another DB2 service comes to the rescue.
Not long ago, I wrote an article about using a DB2 service for change management. That article made use of some of the DB2 for i services, including the table function OBJECT_STATISTICS and the view BOUND_MODULE_INFO. Between the two of them, I was able to get the source file library, name, and member used to create the object. I also mentioned that I could probably use that to do another level of change management, and that’s the topic of this article.
A Quick Recap
To recap, in the previous article I presented an SQL statement that used the services mentioned already and a LEFT OUTER JOIN to provide a simple view of the objects and their source:
SELECT OBJLIB, OBJNAME, OBJTYPE, BDMOD,
O.SOURCE_FILE, SOURCE_LIBRARY, SOURCE_MEMBER, SOURCE_TIMESTAMP,
SRCLIB, SRCFILE, SRCMBR, SRC_CHGTS
FROM TABLE(OBJECT_STATISTICS('MYLIB','ALL')) O
LEFT OUTER JOIN BOUND_MODULE_INFO ON
(PGM_LIB, PGM_NAME, BDMOD) = (OBJLIB, OBJNAME, OBJNAME)
Listing 1: The original SQL combining OBJECT_STATISTICS and BOUND_MODULE_INFO
You can read the previous article for more information, but here’s the short version: The query selects records from OBJECT_STATISTICS, which is the SQL version of DSPOBJD. It includes source information, but there’s a catch: The source information in OBJECT_STATISTICS is only populated for OPM objects. That’s good for files created using DDS (physical, logical, display, and printer) and also for OPM programs but not for ILE programs. Since ILE programs can be created from multiple independently compiled objects, there may be many source members for an ILE program. That’s where the LEFT OUTER JOIN comes in; it brings in ILE module information, including the source for each module.
Expanding Our Architectural Horizon
That original SQL query is a reasonable starting point for ILE objects, but it has a couple of deficiencies. First, it only brings in a single module and only if that module’s name matches the program name. For simpler ILE environments, where you have a single source member for a program and use commands like CRTBNDRPG or CRTBNDCL (or CRTBNDCBL for you crazy COBOL kids), then the program will typically have a single module and it will have the same name as the program. In that case, the query will work fine. However, if you create programs using multiple modules using CRTRPGMOD and CRTPGM, or if you use service programs, then you’ll need something a little more robust. First, I need to expand the query to support multiple bound modules. I simply remove the third argument on the JOIN, which picks only the module whose name matches the program name. It’s easy, I just change the JOIN clause from:
(PGM_LIB, PGM_NAME, BDMOD) = (OBJLIB, OBJNAME, OBJNAME)
to:
(PGM_LIB, PGM_NAME) = (OBJLIB, OBJNAME)
In simple terms, this will bring in all modules for an object. For an ILE program compiled using the CRTBNDxxx commands, it will work the same way it always did, bringing in that single module that has the same name as the program. But let’s take a more complex example. I have a service program called SPSYS made up of four modules: SPINZ, SPINZDFT, SPSYSDBG, and SPSYSLOG. If I run the modified query, I get this:
Figure 1: The first pass at retrieving information for all modules of a complex ILE object
It’s passable, but you can immediately see that there’s a lot of empty space. And for those who noticed, you are correct: This is not STRSQL. I took this screenshot, and subsequent ones, using DBeaver. It’s a free SQL client that I highly recommend. Anyway, those NULL columns are from OBJECT_STATISTICS, because it doesn’t provide any source information for ILE objects. And if I keep with this, then OPM objects will have columns 5-8 populated, while ILE objects will have data in columns 9-12. If only there were some way to sort of coalesce those values into one column. Well, guess what, there is such a way to do it in SQL, and it’s called COALESCE!
Using COALESCE to Reduce Column Complexity
To use COALESCE, you simply list your fields in order of precedence. If the first field in the list is NULL, COALESCE will move to the next field and so on. If all the fields are NULL, then COALESCE returns NULL. If you would rather have a default value, you can provide that as a literal as the last entry to COALESCE. Here is my updated SQL:
SELECT OBJLIB, OBJNAME, OBJTYPE, COALESCE(BDMOD,'*OPM') MODULE,
COALESCE(SRCLIB, SOURCE_LIBRARY,'*NOSRC') SRCLIB,
COALESCE(SRCFILE, OS.SOURCE_FILE) SRCFILE,
COALESCE(SRCMBR, SOURCE_MEMBER) SRCMBR,
COALESCE(SRC_CHGTS, SOURCE_TIMESTAMP) SRCTS
FROM TABLE(OBJECT_STATISTICS('MYLIB','SRVPGM')) OS
LEFT OUTER JOIN BOUND_MODULE_INFO
ON (PGM_LIB, PGM_NAME) = (OBJLIB, OBJNAME)
Listing 2: Using COALESCE to present ILE values but use OPM values where no ILE value exists
I’ve done a couple of things. In my first use of COALESCE, I present the module name for ILE objects. If the module name (BDMOD) is NULL, however, I default to the literal *OPM. The next COALESCE first looks at the ILE source library from the BOUND_MODULE_INFO (SRCLIB), and if that is NULL, it then attempts to use the OPM source library from OBEJCT_STATISTICS (SOURCE_LIBRARY). If both are null, then the literal *NOSRC is used. The next three COALESCE calls do the same thing, attempting to first get an ILE value, and failing that, to use the OPM value. Unlike the previous call, though, there is no default value, since that’s already been done in the source library column. Running that on just my service program, I see this:
Figure 2: Using COALESCE provides a complete view of all the modules for a service program
Running the expanded query over a library with a mix of OPM and simple ILE objects gives this:
Figure 3: Running the COALESCE version over an entire library gives a more complete picture.
You can see that this library contains a mix of both OPM and ILE programs. And yes, this is an absolutely ancient library; it’s one of the original test libraries for VisualAge for Java. There are also some files, including one that has no source at all, which makes sense because that file, APPSOURCE, is itself actually a source file. It was created using the CRTSRCPF command and so has no source.
Back to the Source
I hinted at the beginning of this article that we would do a little more advanced change management. And while I’ve expanded the query to better handle complex ILE objects, I really haven’t done much to advance our change-management goals. To do that, I’m going to provide a way to compare the source timestamp in my object to the timestamp from the source file member itself. I do this by introducing the SYSPARTITIONSTAT view, which provides information on file members. In this case, I will be retrieving the member information for the source member I identified in my original query. Using COALESCE to use either ILE or OPM values as necessary makes that relatively easy. Here is the final query for today:
WITH T1 AS (
SELECT OBJLIB, OBJNAME, OBJTYPE, COALESCE(BDMOD,'*OPM') MODULE,
COALESCE(SRCLIB, SOURCE_LIBRARY,'*NOSRC') SRCLIB,
COALESCE(SRCFILE, OS.SOURCE_FILE) SRCFILE,
COALESCE(SRCMBR, SOURCE_MEMBER) SRCMBR,
COALESCE(SRC_CHGTS, SOURCE_TIMESTAMP) SRCTS
FROM TABLE(OBJECT_STATISTICS('ADTSLAB','PGM,FILE')) OS
LEFT OUTER JOIN BOUND_MODULE_INFO
ON (PGM_LIB, PGM_NAME) = (OBJLIB, OBJNAME)
) SELECT T1.*, LASTSRCUPD
FROM T1 LEFT OUTER JOIN SYSPARTITIONSTAT
ON (SRCLIB, SRCFILE, SRCMBR) = (SYS_DNAME, SYS_TNAME, SYS_MNAME)
Listing 3: Define the original query as a CTE and JOIN it to SYSPARTITIONSTAT
What I’ve done is include the original query as a common table expression (CTE) named T1. I join that CTE to the SYSPARTITIONSTAT view and select all of the columns from the CTE followed by the source change timestamp (LASTSRCUPD) from SYSPARTITIONSTAT. This is the result:
Figure 4: The final version includes both source timestamps, one from the object and one from the source file
While the query results reflect only the incremental difference of the additional timestamp, the next step would be to include only records where the two source timestamps don’t match. That’s when you can start really reviewing your change management requirements. As a simple example, you can see that the object RTVUSRCLAS has no source timestamp because in this case the library LEUNGA is not on the machine. So what we have is an object that was compiled from source that does not exist. And that’s something we need to identify!
I hope you enjoy how we managed to go from a simple object list to a reasonably sophisticated source/object analysis. Look for more on this subject in a subsequent article.
LATEST COMMENTS
MC Press Online