“I'm an artist, and if you give me a tuba, I'll bring you something out of it.”
—John Lennon
Full disclosure: I am not a good developer. I’m even a worse artist. Heck, I’m not even a Beatles fan. But I do love that quote.
If given code in just about any readable language and a little bit of time, most of us tech guys can bring something out of it. It might not be pretty (especially in my case), but it’s going to get the job done.
Which brings me to IBM i Services.
If you’re unaware what IBM i Services is, you’re missing out. This feature that IBM has been building into the operating system for the last few releases allows easy access to information about an IBM i partition—from active jobs to Service Tools and everything in between. How easy? It’s as easy as a table read. Information previously retrieved with RPG programs calling APIs or layers of RUNQRY operations are now often at the end of a simple SQL statement.
I’m going to share with you some examples of IBM i Services to show you exactly what value you can retrieve from your system. Some of these I’ve pulled straight from the IBM Access Client Solutions examples IBM is nice enough to provide inside Run SQL Scripts, and some I’ve cobbled together personally and/or Frankensteined from other examples around the web to get the result I wanted.
You can start building your own library of handy SQL tools and even start building your own dashboards.
Determine What Jobs Are Running Unsupported Versions of Java
SELECT * FROM qsys2.jvm_info WHERE JAVA_HOME NOT LIKE '%/jdk7%' AND JAVA_HOME NOT LIKE '%/jdk8%';
You can also find this information by doing a WRKJVMJOB and manually checking what version of Java each job is using. I like the SQL way better. As you can see, it’s selecting all records from qsys2.jvm_info (an SQL view showing all active Java processes) and then determining whether the JAVA_HOME variable doesn’t contain strings signifying the supported releases of Java 7 and Java 8.
Determine the Top Five Consuming Java Jobs by Heap Size Allocated
SELECT CURRENT_HEAP_SIZE, JOB_NAME, JAVA_HOME FROM QSYS2.JVM_INFO
ORDER BY CURRENT_HEAP_SIZE DESC
FETCH FIRST 5 ROWS ONLY
From a memory standpoint, a Java job will not go over its allocated heap size. However, once it reaches that size, the Java application will cease to perform optimally, to put it nicely. Knowing your Java heap characteristics will help you keep those applications running smoothly.
Deleted Records Report
select trim(SYSTEM_TABLE_SCHEMA)
concat '/' concat
trim(SYSTEM_TABLE_NAME)
concat '.' concat
trim(SYSTEM_TABLE_MEMBER) as Lib_File_Member,
NUMBER_DELETED_ROWS,
NUMBER_ROWS as NUMBER_ACTIVE_ROWS,
NUMBER_DELETED_ROWS + NUMBER_ROWS as TOTAL_ROWS,
case NUMBER_ROWS
when 0 then 100.00
else
(CAST(NUMBER_DELETED_ROWS AS DEC(10,0)) / (CAST(NUMBER_DELETED_ROWS AS DEC(10,0)) + CAST(NUMBER_ROWS AS DEC(10,0)))) * 100
end as Percent_Deleted,
DATA_SIZE / 1000000 as Data_Size_in_MB,
(DATA_SIZE / 1000000) * (CAST(NUMBER_DELETED_ROWS AS DEC(10,0)) / (CAST(NUMBER_DELETED_ROWS AS DEC(10,0)) + CAST(NUMBER_ROWS AS DEC(10,0)))) as Data_Size_in_MB_to_Reclaim
from QSYS2.SYSPARTITIONSTAT
where NUMBER_DELETED_ROWS > 0
order by NUMBER_DELETED_ROWS desc;
This ugly little script (if you can make it prettier, be my guest) gives a listing of all tables that have any deleted records. It’ll also show the amount of storage that can be recovered by way of a database reorganization (RGZPFM). Quite handy information if you have a lot of files with transient data. Like I told someone last week, a file with 200 million deleted records may not be performance-friendly!
Find the Top Temporary Indexes Advised by IBM i
WITH last_ipl(ipl_time)
AS (SELECT job_entered_system_time
FROM TABLE(qsys2.job_info(job_status_filter => '*ACTIVE', job_user_filter
=> 'QSYS')) x
WHERE job_name = '000000/QSYS/SCPF')
SELECT *
FROM last_ipl, qsys2.condidxa
WHERE last_advised > ipl_time and TIMES_ADVISED > 250000;
Whether you’re a DBA, admin, or developer, Index Advisor is your friend. I’ve seen systems that were online 10 days and had over 2 billion indexes advised on the same table. The system is telling you how to make it go faster. As an experiment, take the top 25 indexes advised and build proper indices. You may yield some good performance results.
Group PTF Currency
WITH iLevel(iVersion, iRelease)
AS (SELECT OS_VERSION, OS_RELEASE
FROM sysibmadm.env_sys_info)
SELECT P.*
FROM iLevel, systools.group_ptf_currency P
WHERE ptf_group_release = 'R' CONCAT iVersion CONCAT iRelease concat '0'
ORDER BY ptf_group_level_available - ptf_group_level_installed DESC;
This is my favorite IBM i Service by far. It shows your current PTF levels and compares them with the levels available to download from IBM.
What Jobs Consume the Most Temporary Storage?
SELECT bucket_current_size, bucket_peak_size, RTRIM(job_number) concat '/'
concat RTRIM(job_user_name) concat '/' concat RTRIM(job_name) AS q_job_name
FROM QSYS2.SYSTMPSTG
WHERE job_status = '*ACTIVE'
ORDER BY bucket_current_size DESC;
Knowing what temporary storage is actually being used has always been a bit of a mystery. The other ways to dump a listing to the QSYSOPR message queue have been a little clunky. This SQL script is easy to use and yields a simple result set.
What Users Are Your Top Spooled File Storage Consumers?
SELECT USER_NAME, SUM(SIZE) AS TOTAL_SPOOL_SPACE
FROM TABLE(QSYS2.OBJECT_STATISTICS('QSYS ', '*LIB')) AS a,
TABLE(QSYS2.OBJECT_STATISTICS(a.objname, 'OUTQ')) AS b,
TABLE(QSYS2.OUTPUT_QUEUE_ENTRIES(a.objname, b.objname, '*NO')) AS c
WHERE USER_NAME NOT LIKE 'Q%'
GROUP BY USER_NAME
ORDER BY TOTAL_SPOOL_SPACE DESC
FETCH FIRST 10 ROWS ONLY;
Can’t get appropriations for some additional disk, but you’re running at 90 percent? Time to torpedo Bob in accounting, who’s got 10 percent of the system tied up with spooled files dating back to the 1980s.
When Was Your Last SAVSYS?
SELECT SAVE_TIMESTAMP FROM TABLE (QSYS2.OBJECT_STATISTICS('QSYS','DTAARA', 'QSAVSYS' ) ) AS X;
Knowing the date of your last SAVSYS is paramount. The older the date, the more likely it’ll be ineffective because you’ve put PTFs on since then. If your returned result is NULL, then you might be in trouble because you don’t have a SAVSYS. I put this on my LinkedIn page recently, and someone had a little fun with the script:
SELECT ifnull(SAVE_TIMESTAMP,'Danger Will Robinson') FROM TABLE (QSYS2.OBJECT_STATISTICS('QSYS','DTAARA', 'QSAVSYS' ) ) AS X;
More IBM i Services
To learn more about IBM i Services, please visit this IBM web page.
If you can think of something that IBM can provide you by way of an IBM i Service, please open a Request for Enhancement (RFE) here.
LATEST COMMENTS
MC Press Online