25
Wed, Dec
0 New Articles

Practical SQL: SQL Monitor Part 3, the Program Logic

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

Using identity fields in RPG requires a little SQL, but that SQL can coexist with traditional record-level access, as this monitor program illustrates.

In my last two articles (1, 2), I presented a business requirement that could be met by creating a data model with an identity field. Identity fields are very powerful, but they are best handled using SQL. This particular program makes use of a number of different ILE techniques, so we should dive right in.

The Definitions

If you review the previous articles, you'll know that we have two files, SQLSTM and SQLJOB. In this program, the I/O to SQLSTM will be done via SQL, while SQLJOB will be maintained using record-level access. The program uses some data structures as well, and I'll explain why as we go along. But let's get through the definitions.

     ctl-opt actgrp(*new) option(*srcstmt:*nodebugio);

     // All I/O to this file is through qualified DS

     dcl-f SQLJOB keyed usage(*update:*output);

     dcl-ds ioSQLJOB extname('SQLJOB':*all) qualified end-ds;

     // These are used to define all the fields for SQL

     // The fields are unqualified

     dcl-ds dsSQLSTM extname('SQLSTM') end-ds;

     dcl-ds dsSQLJOB extname('SQLJOB') inz end-ds;

     // Monitor DS to bring job down

     dcl-ds dsSQLMON len(1) dtaara('SQLMON') end-ds;

     /COPY QCPYLESRC,DEFUTL

Several things are defined here. First, of course, is control option. I tend to use *NEW for the activation group for most utility programs, and the *SRCSTMT and *NODEBUGIO are there for debugging purposes. Next are the definitions used to update the detail file, SQLJOB. This file is maintained via record-level access, so I need a file declaration. I also use a data structure for all I/O, and you'll see why shortly.

The next two data structures are defined solely to provide work fields for my SQL statements. One of the great benefits of externally described files is the fact that you don't have to define all the fields yourself. But by taking advantage of externally described data structures, I at least don't have to define all the fields individually. Please note that these fields are unqualified; that's merely to keep my SQL statements from getting too verbose.

Next, I define a data area. Since this program sits in a loop, I wanted a clean way to exit, and a data area is one of my preferred methods. Finally, I have a quick /COPY that brings in the prototype for the sleep() function.

The Main Loop

     exec sql set option commit = *none;

     init();

      dow dsSQLMON = '';

      processJobs();

      sleep(60);

     in dsSQLMON;

      enddo;

     *inlr = *on;

This is the whole mainline. It's quite simple: I run an initialization routine and then sit in a loop until the data area is set. The loop process all the current ODBC jobs and then sleeps for 60 seconds. After I’m done, I set on *INLR and get out. One of these days, I'll get around to using NOMAIN in my utility programs. I should do that sooner rather than later, but I just haven't done it yet. One other thing: you may notice the EXEC SQL at the beginning; this allows me to use SQL statements without the trappings of commitment control.

Initialization

      dcl-proc init;

     in *lock dsSQLMON;

      dsSQLMON = *blank;

     out dsSQLMON;

     exec sql declare c cursor for

        select JOB_NAME, CPU_TIME, TOTAL_DISK_IO_COUNT, JOB_USER_IDENTITY,

                CLIENT_IP_ADDRESS, CHAR(SQL_STATEMENT_TEXT, 500)

        from table(ACTIVE_JOB_INFO(JOB_NAME_FILTER=>'QZDAS*',

                                    DETAILED_INFO=>'ALL'))

          where SQL_STATEMENT_TEXT <> ' ';

      end-proc;

The initialization routine is simple. I just clear the data structure used to end the program. As a habit, I usually store my non-executable SQL cursor definitions here as well just to keep them out of the way; they can be quite large. This one is not large, but it does use a pretty cool DB2 Service, ACTIVE_JOB_INFO. I'm not going to go into it in detail, but the first salient point is that my query returns the fully qualified (with slashes) job name, the total CPU time, the total disk I/O, the current user for the job (very important in server jobs), the IP address of the initiating job, and the first 500 characters of the SQL statement being executed. The other point is that I limit it to the QZDAS job because those are my external ODBC jobs, and I only include jobs that are actually executing SQL. Quite a powerful little query!

Main Processing

Processing is simple:

  • Get the next statement.
  • Create a new SQLSTM record if necessary.
  • Create or update the SQLJOB record.

      dcl-proc processJobs;

     dcl-s ni int(5);

     exec sql open c;

     exec sql fetch from c into

        :SJFQJN, :SJCPU, :SJDISK, :SJUSID, :SJCLIP:ni, :SSSTMT;

     dow SQLCOD = 0;

I start by opening the cursor and fetching the first record into the fields defined in the two unqualified data structures. As I said earlier, I like to use unqualified fields just because it reduces the clutter in the SQL statement. One thing to be careful about is null-capable fields. There are a couple of ways to handle them, but perhaps the easiest is just to create a null indicator (the ni field) and use it wherever a value can be null. As it turns out, only one field can be null; that's the IP address, SJCLIP.

        // Find statement ID, if not found add new one and get ID

        exec sql set :SJSQID:ni =

          (select SSID from SQLSTM where SSSTMT = :SSSTMT);

        if ni < 0;

          exec sql insert into SQLSTM (SSSTMT) values(:SSSTMT);

          exec sql set :SJSQID = identity_val_local();

        endif;

This is the code that handles the identity field. It's so very cool. In a moment, I'm going to write or update an SQLJOB record, and to do that, I need the ID associated with the SQL statement. The statement is currently in the field SSSTMT, and I need to either get the ID if that statement is already in the file, or add it to the file and get the ID of the newly added record. The code is not complex. First, try to get the ID of a matching record using the SET syntax (this is a variant of SELECT INTO, and I prefer it because it's more like an EVAL). A matching record will set SJSQID to that record's ID. Otherwise, the SET returns a null and the ni indicator will be set to a negative value. If that occurs, I have to do two things: add a record and get its ID. The INSERT statement adds a record. Note that it only adds the SSSTMT field; the SSID field is the auto-generated identity field, so I don't specify a value. The system generates it. But that means I have to retrieve that value for the following SQLJOB I/O. That's what the identity_val_local() function does; it returns the last ID value generated.

So to recap: either I get the ID of a matching record or I add a new record and get the ID that the system generated for it.

        // Now find job, and either update or add

        chain ( SJFQJN: SJUSID: SJCLIP: SJSQID) SQLJOB ioSQLJOB;

        if %found(SQLJOB);

          // If found, only update cumulative data and audit fields

          // Get current values for cumulative data

          ioSQLJOB.SJCPU = SJCPU;

          ioSQLJOB.SJDISK = SJDISK;

          // Audit fields

          ioSQLJOB.SJLCTS = %timestamp();

          ioSQLJOB.SJCHGS += 1;

          update SQLJOBR ioSQLJOB;

        else;

          // If not found, populate I/O record from unqualified fields

          // Initialize job values and cumulative data

          //   The only fields in dsSQLJOB with data are the ones that

          //   are populated by the FETCH

          ioSQLJOB = dsSQLJOB;

          // Parse fully qualified job name into components

          parseFQJN( ioSQLJOB);

          // Get ID for SQL statement

          ioSQLJOB.SJSQID = SJSQID;

          // Audit fields

          ioSQLJOB.SJCRTS = %timestamp();

          write SQLJOBR ioSQLJOB;

        endif;

This part of the logic is more familiar to us traditional record-level access programmers, with just a slight twist: I use data structures. But there's a method to my madness as we'll see. If a record exists, the logic is very simple: CHAIN to the record, update the fields, update the record. All I do is store the cumulative data and update the audit fields. The slightly trickier bit comes when I don't find a record; this is where I use data structures. Remember that the SQL statement fetches all that data into the dsSQLJOB data structure. So rather than move the fields individually, I can move everything all at once using a simple EVAL. Yes, it's lazy, but I'm a programmer. I thrive on lazy code, as long as it's architecturally sound.

Once I've moved all those fields (the fully qualified job name, IP address, etc.), then I can initialize the other fields. I parse the job name into individual fields, store the ID, and initialize the audit fields. Time to write the record!

        // Get the next record

        exec sql fetch from c into

          :SJFQJN, :SJCPU, :SJDISK, :SJUSID, :SJCLIP:ni, :SSSTMT;

     enddo;

     exec sql close c;

      end-proc;

The rest of the procedure is mundane. Fetch the next record, loop if one exists, otherwise close the cursor and exit.

Buttoning It Up

That's the end of the program, with one exception. Let me show you the parseFQJN function.

      dcl-proc parseFQJN;

     dcl-pi *n;

        uSQLJOB likeds(ioSQLJOB);

     end-pi;

     dcl-s slash2 int(3);

     // Find second slash (we know first is at 7)

      slash2 = %scan( '/': uSQLJOB.SJFQJN:8);

     // Parse the segments

      uSQLJOB.SJJOBN = %subst( uSQLJOB.SJFQJN: 1: 6);

      uSQLJOB.SJUSER = %subst( uSQLJOB.SJFQJN: 8: slash2-8);

      uSQLJOB.SJJOB = %subst( uSQLJOB.SJFQJN: slash2+1);

      end-proc;

This is the code to parse a fully qualified IBM i job name, such as 654321/JPLUTA/MYJOB. To parse the string, you have to know the positions of the two slashes. But here's the trick: you already know the position of the first slash; it's the seventh character, because job number is always six digits. So all you have to do is get the second slash. The %scan BIF does that and stores it in the slash2 variable. After that, it's just a matter of using %subst to break up the chunks.

And that's it for this program. With the exception of the sleep procedure (which is just a prototype to the system-supplied sleep function), this is all the code you need to implement this procedure. Enjoy!

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

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: