Sidebar

SQL Triggers and Other Trigger Enhancements in V5

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

 

Read Trigger

Read triggers have been implemented in OS/400 to satisfy a U.S. federal statute (HIPAA) requiring that all access to patient records in the medical profession be logged and auditable.

Read triggers are supported only via external triggers and are implemented via the new read trigger event, and there is no support for a read trigger with SQL triggers. The reason for this is that a read trigger has a very specific function; it is not intended for general use because indiscriminate use can have a significant negative impact on system performance and throughput due to System i and iSeries performance characteristics being altered.

Any read-only access to a file with a read trigger defined—either user program or system function—will cause the trigger to fire. This means that using the Copy File (CPYF) command, the Display Physical File Member (DSPPFM) command, query products like Query/400 or SQL, or user-written display or report programs will cause a read trigger to fire every time a record is accessed in each of the above scenarios. If you access one million records, you just fired the read trigger one million times. Get the picture?

The use of a read trigger will disable some system functions that are used to optimize system performance and throughput. For example, a read trigger prevents adaptive blocking and double buffering when processing a file sequentially (arrival sequence) and asynchronous fetch of the next record in keyed sequence when processing a file sequentially by key or index. This means that records are read from the file one at time instead of in optimized blocks, dramatically increasing file I/O time.

The effect is that batch programs using these processing techniques on a file with a read trigger defined will run orders of magnitude longer. This negative impact on performance can be mitigated to a certain extent by increasing CPU power, adding memory, and adding disk arms.

Multiple Triggers per Database or Trigger Event

OS/400 releases prior to V5R1 limited a file to a maximum of six triggers per file. Many software providers now include triggers in their application packages, which can conflict with the trigger requirements of System i and iSeries users.

When conflicting trigger requirements occur, it can be very difficult or impossible to combine two or more trigger programs into one. IBM's V5R1 solution was to increase the limit of six triggers to 300 and to allow more than one trigger with the same trigger time and trigger event to be defined for a file.

When multiple triggers are defined for the same database event, the triggers are fired in the order they were created. The first trigger created is the first one fired; the last created is the last one fired.

This raises some interesting questions when a trigger has to be deleted and recreated. Suppose the first trigger on the execution list must be deleted and then recreated. It then moves from being first on the execution list to last on the list. The question that you must ask is if the trigger depends on its place in the execution list to function properly. If the answer to that question is "yes, the trigger firing order must be maintained," you will need to create two CL or SQL scripts: One script removes all the triggers for the file in question, and the second recreates all the triggers in the required sequence.

Named Triggers

The increase to 300 triggers per file means that the combination of trigger time and trigger event can no longer be used to identify a trigger. Starting in V5R1, both external and SQL triggers are given a name to provide unique identification when they are created. The trigger name must be unique within a given library (not per file) and can be a maximum of 128 characters long. If you do not provide a name when the trigger is created, DB2 UDB will create a default name, and I guarantee you will not like it!

To support the naming of a trigger, a trigger name and library parameters have been added to the ADDPFTRG and RMVPFTRG commands and the new CREATE TRIGGER and DROP TRIGGER SQL statements (more on these SQL statements later).

Change Physical File Trigger (CHGPFTRG) Command

The CHGPFTRG command changes the state of one or all triggers defined for a file or table. There are two possible trigger states: disabled or enabled. When a trigger is disabled, its corresponding trigger program will not be invoked when the trigger event is satisfied. When a trigger is enabled, its corresponding trigger program will be invoked when the trigger event is satisfied.

This eliminates the problem of having to delete a trigger to disable it and then recreate the trigger again to enable it in prior releases of OS/400. Following is an example of the CHGPFTRG command syntax.

CHGPFTRG   FILE(Lib_Name/File_Name)   TRG(Trigger_Name)   
          TRGLIB(Lib_Name)   STATE(*DISABLED)

System Catalog Trigger Enhancements

As an aid in managing the V5R1 trigger enhancements, IBM has added four new files to the System Catalog to log and store information about triggers:

  • SYSTRIGGERS contains one row for each trigger in a library for both external and SQL triggers.
  • SYSTRIGCOL contains one row for each column or field either implicitly or explicitly referenced in the WHEN clause or the SQL statements for an SQL trigger.
  • SYSTRIGDEP contains one row for each object referenced in the WHEN clause or SQL statements for an SQL trigger.
  • SYSTRIGUPD contains one row for each column identified in the UPDATE column list, if any.

SQL Triggers

SQL triggers are a V5R1 enhancement and use one or more SQL statements (instead of a user-provided or written program) within the trigger body to perform the desired action when the trigger fires. SQL trigger support in V5R1 is a superset of the support found in DB2 UDB Version 7.1 and provides an industry-standard method for defining and managing triggers that has a high degree of portability to other database management systems.

SQL triggers use IBM's SQL procedural language to implement the trigger implementation, and they also provide more granularity and function than external triggers with column or field-level triggers, row or record-level triggers, and (SQL) statement-level triggers.

An SQL trigger can be added to a file or table with the CREATE TRIGGER statement and can be removed with the DROP TRIGGER statement, or both can be done with the Database function in iSeries Navigator.

SQL Trigger Components

In V5R1, an external trigger has the following five components (remember that the trigger name was just added in V5R1): base file or table, trigger name, trigger event, trigger time, and trigger program.

An SQL trigger has the same first four components; however, the trigger program is replaced by five additional components: trigger granularity, transition variables, transition tables, trigger mode, and triggered action.

The base file or table is the physical file or table to which the trigger is added. The trigger name provides unique trigger identification within a library. The trigger event is the condition that causes the trigger to fire. It can be the insert of a new record or row, the delete of an existing row, the update of an existing row or column, or, in very limited circumstances, the read of an existing row (see "read trigger" earlier in this article). The trigger time is when the triggered action will be performed, either before or after the trigger event completes. The trigger granularity, in conjunction with the trigger event, determines what causes the trigger to fire. Granularity can be at the column or field level, row or record level, or (SQL) statement level.

Column-level triggers are an extension of the Update trigger event and are available only with SQL triggers. Only an update of those columns listed as part of the update trigger event will cause the trigger to fire and the triggered action to be performed.

The following SQL syntax shows how the column names are listed:

UPDATE OF   Column_Name1, Column_Name2,...

If no columns are listed in the UPDATE OF clause, then an update to any column defined in the row causes the associated trigger to fire.

With a row-level trigger, the associated trigger is fired and the triggered action is performed each time the trigger event is satisfied. If the trigger condition is never satisfied, the triggered action is never performed. An SQL trigger is defined as a row-level trigger with the FOR EACH ROW clause. An external trigger is implicitly a row-level trigger.

Statement-level triggers are available only with SQL triggers, and the triggered action is performed only once per trigger event, regardless of the number of rows processed. If the trigger event is never satisfied, the triggered action is still performed once at the end of the SQL statement processing. A statement-level trigger can be used only in conjunction with a trigger time of After and a trigger mode of DB2SQL (more on trigger mode later) and is defined with the FOR EACH STATEMENT clause.

Transition variables provide the same function as the before and after images in the trigger buffer used with external triggers. They provide qualification of the column names for the image of the single row that caused the trigger to fire, before and/or after the trigger event has completed.

Transition variables are not valid with statement-level triggers. They are defined with the OLD ROW clause for the before image and the NEW ROW clause for the after image.

The following SQL syntax is used to describe and reference transition variables as part of an SQL trigger.

...REFERENCING   OLD ROW   AS   Oldrow   NEW ROW   AS   Newrow
...
...WHERE   Newrow.Salary   >   Oldrow.salary   + 10000...

A transition table provides a function analogous to the before and after images in the trigger buffer used with external triggers and is a temporary table that contains the image of all rows affected before and/or after the trigger event completes. Since a single SQL statement can process multiple rows in a file, a mechanism is needed to be able to track/log the activity on those rows processed. Transition tables provide that capability.

A transition table can be used only in conjunction with a trigger time of After and a trigger mode of DB2SQL. It is defined with the OLD TABLE clause for a before image of all affected rows and the NEW TABLE clause for an after image of all affected rows.

The following SQL syntax is used to describe and reference a transition table as part of an SQL trigger.

...REFERENCING   OLD TABLE   AS   Old_Table_Name...
...
...(SELECT   COUNT(*)   FROM   Old_Table_Name)...

There are two trigger modes: DB2ROW and DB2SQL. A mode of DB2ROW causes the trigger to fire after each row operation and is valid only with row-level triggers. It is an exclusive function of DB2 UDB for System i and iSeries and is not available in other DB2 UDB implementations. A mode of DB2SQL causes the trigger to fire after all row operations are complete and is valid only with a trigger time of After. If it is specified for a row-level trigger, the triggered action is executed n times after all row operations, where n equals the number of rows processed. This is not as efficient as DB2ROW, since each row is effectively processed twice.

The triggered action is analogous to the trigger program in external triggers and has three parts: the SET OPTION clause, the WHEN clause, and the SQL trigger body:

The SET OPTION clause specifies the options that will be used to create the trigger.

The WHEN clause specifies the search or selection criteria or the execution criteria for the trigger body. In other words, it specifies when the SQL statements in the trigger body will be executed.

The SQL trigger body contains one or more SQL statements that perform the desired action when the trigger fires. Multiple SQL statements in the trigger body are delineated with the BEGIN and END statements. Each complete SQL statement in the trigger body must be ended with a semicolon (;).

The standard DDL and DML SQL statements—such as SELECT, INSERT, DELETE, and CREATE—can be used in the trigger body along with IBM's SQL procedural language.

An SQL trigger can be added to a file with the CREATE TRIGGER statement and removed with the DROP TRIGGER statement. The SQL syntax for these statements is shown below.

Detailed SQL Syntax for Create Trigger Statement

                                    +-NO CASCADE--+          
>>--CREATE TRIGGER--trigger-name--+-+-------------+-BEFORE-+-->  
                                  +-AFTER------------------+     

>--+--INSERT--------------------------+--ON--table-name------->  
   |--DELETE--------------------------|               
   +--UPDATE--+---------------------+-+                         
              |    +-,-----<-----+  |
              |    |             |  |
              +-OF-+-column-name-+--+

>-+---------------------------------------------------------+->  
  |             +-----------------------<-----------------+ |     
  |             |                                         | |
  |             |       +-ROW-+ +-AS-+                    | |   
  +-REFERENCING-+-+-OLD-+-----+-+----+-correlation-name-+-+-+
                  |                                     |
                  |     +-ROW-+ +-AS-+                  |
                  +-NEW-+-----+-+----+-correlation-name-+
                  |                                     |
                  |           +-AS-+                    |
                  +-OLD TABLE-+----+---table-identifier-+ 
                  |                                     |
                  |           +-AS-+                    |
                  +-NEW TABLE-+----+---table-identifier-+

   +--FOR EACH STATEMENT--+  +--MODE DB2SQL--+         
   |                      |  |               |
>--+----------------------+--+---------------+---------------->
   |                      |  |               |
   +--FOR EACH ROW--------+  +--MODE DB2ROW--+

>--+-----------------------------------+---------------------->
   |                                   |
   +--SET OPTION---option-statement----+  

>--+---------------------------------------------------+------>
   |                                                   |
   +--WHEN--(--trigger-body-execution-criteria------)--+  

>--SQL-trigger-body------------------------------------------><


Detailed SQL Syntax for Drop Trigger Statement

>>--DROP TRIGGER----trigger-name------------------------------><

When SQL triggers are created, they have an implicit attribute of ALWREPCHG(*YES). This attribute must be explicitly specified when using external triggers; otherwise, it defaults to ALWREPCHG(*NO).

SQL Trigger Examples


Column-Level Trigger with Simple Trigger Body

CREATE  TRIGGER  empsal
     BEFORE  UPDATE  OF  salary  ON  emp
     REFERENCING  NEW  AS  new  OLD  AS  old
     FOR  EACH  ROW  MODE  DB2ROW
     WHEN  (new.salary  >  1.5  *  old.salary)
          SET  new.salary  =  1.5  *  old.salary;

The SQL trigger created in this example is called empsal and is fired before the update of a row in the table or file called salary. Transition variables called new and old have been defined for new row (the after image) and old row (the before image) and will be used to qualify field names referenced in the trigger body. The trigger is a row-level trigger, and its mode is DB2ROW.

The SQL statement in the trigger body will be executed when new.salary equals 1.5 times the old.salary. When this criteria is satisfied, the new.salary is set to 1.5 times the old salary. Note that this is the preferred method for modifying or changing data before it is actually written to a table or file.

Row-Level Trigger with Complex Trigger Body

CREATE  TRIGGER  big_spenders  
     AFTER  INSERT  ON  expenses
     REFERENCING  NEW  ROW  AS  n
     FOR  EACH  ROW
     MODE  DB2ROW
     WHEN  (n.totalamount  >  10000)
BEGIN   
     DECLARE  emplname  CHAR(30);
     SET  emplname  =  
          (SELECT  lname  FROM  employee
               WHERE  empid  =  n.empno);
     INSERT  INTO  travel_audit 
          VALUES(n.empno,  emplname,  n.deptno,  
               n.totalamount,  n.enddate);
END

The SQL trigger created in this example is called big_spenders and is fired after the insert of a row in the table or file called expenses. A transition variable called n has been defined for new row (the after image) and will be used to qualify field names referenced in the trigger body. The trigger is a row-level trigger, and its mode is DB2ROW.

Note that there are multiple SQL statements in the trigger body and that they are delineated with a BEGIN and END statement. Also note that each SQL statement is ended with a semicolon. These SQL statements in the trigger body will be executed when n.totalamount is greater than 10,000. When this criteria is satisfied, the SLQ statements in the trigger body are executed, and the result is that a row is inserted into the table called travel_audit, which contains the columns or fields called n.empno, emplname, n.deptno, n.totalamount, and n.enddate.

New Trigger Enhancements

IBM has provided significant trigger enhancements in V5R1.The maximum number of triggers per file has been raised from 6 to 300. To support 300 triggers per file, triggers are now given a name, which must be unique within a library, when they are created. The new CHGPFTRG command allows you to easily disable/enable a single trigger or a group of related triggers, and the System Catalog has had four new files added to it to log and store trigger information.

SQL triggers provide a new level of function and use one or more SQL statements (instead of a user-provided/written program) within the trigger body to perform the desired action when the trigger fires. SQL trigger support in V5R1 provides an industry-standard method for defining and managing triggers that has a high degree of portability to other database management systems. SQL triggers also provide more granularity and function than external triggers, with column or field-level triggers, row or record-level triggers, and statement-level (SQL) triggers.

Lastly, there is the new read trigger, which is not intended for general use, so you must approach it with extreme caution. Use of read triggers can have a severe detrimental impact on System i and iSeries performance and throughput.

The V5R1 trigger enhancements offer additional options for fulfilling application requirements. With proper use, these enhancements can be very beneficial to programmers.

Skip Marchesani retired from IBM after 30 years and is now a consultant with Custom Systems Corp. and one of the founding partners of System i Developer. Skip spent much of his IBM career working with the Rochester Development Lab on projects for S/38 and AS/400 and was involved with the development of the AS/400. He was part of the team that taught early AS/400 education to customers and IBM lab sites worldwide.

Skip is recognized as an industry expert on DB2 UDB (aka DB2/400) and author of the book DB2/400: The New AS/400 Database. He specializes in providing customized education for any area of the System i, iSeries, and AS/400; does database design and design reviews; and performs general System i, iSeries, and AS/400 consulting for interested clients. He has been a speaker for user groups, technical conferences, and System i, iSeries, and AS/400 audiences around the world. He is an award-winning COMMON speaker and has received its Distinguished Service Award.

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

RESOURCE CENTER

  • WHITE PAPERS

  • WEBCAST

  • TRIAL SOFTWARE

  • Mobile Computing and the IBM i

    SB ASNA PPL 5450Mobile computing is rapidly maturing into a solid platform for delivering enterprise applications. Many IBM i shops today are realizing that integrating their IBM i with mobile applications is the fast path to improved business workflows, better customer relations, and more responsive business reporting.

    This ASNA whitepaper takes a look at mobile computing for the IBM i. It discusses the different ways mobile applications may be used within the enterprise and how ASNA products solve the challenges mobile presents. It also presents the case that you already have the mobile programming team your projects need: that team is your existing RPG development team!

    Get your copy today!

  • Automate IBM i Operations using Wireless Devices

    DDL SystemsDownload the technical whitepaper on MANAGING YOUR IBM i WIRELESSLY and (optionally) register to download an absolutely FREE software trail. This whitepaper provides an in-depth review of the native IBM i technology and ACO MONITOR's advanced two-way messaging features to remotely manage your IBM i while in or away from the office. Notify on-duty personnel of system events and remotely respond to complex problems (via your Smartphone) before they become critical-24/7. Problem solved!

    Order your copy here.

  • DR Strategy Guide from Maxava: Brand New Edition - now fully updated to include Cloud!

    SB Maxava PPL 5476PRACTICAL TOOLS TO IMPLEMENT DISASTER RECOVERY IN YOUR IBM i ENVIRONMENT

    CLOUD VS. ON-PREMISE?
    - COMPREHENSIVE CHECKLISTS
    - RISK COST CALCULATIONS
    - BUSINESS CASE FRAMEWORK
    - DR SOLUTIONS OVERVIEW
    - RFP BUILDER
    Download your free copy of DR Strategy Guide for IBM i from Maxava today.

     

  • White Paper: Node.js for Enterprise IBM i Modernization

    SB Profound WP 5539

    If your business is thinking about modernizing your legacy IBM i (also known as AS/400 or iSeries) applications, you will want to read this white paper first!

    Download this paper and learn how Node.js can ensure that you:
    - Modernize on-time and budget - no more lengthy, costly, disruptive app rewrites!
    - Retain your IBM i systems of record
    - Find and hire new development talent
    - Integrate new Node.js applications with your existing RPG, Java, .Net, and PHP apps
    - Extend your IBM i capabilties to include Watson API, Cloud, and Internet of Things


    Read Node.js for Enterprise IBM i Modernization Now!

     

  • 2020 IBM i Marketplace Survey Results

    HelpSystems

    This year marks the sixth edition of the popular IBM i Marketplace Survey Results. Each year, HelpSystems sets out to gather data about how businesses use the IBM i platform and the IT initiatives it supports. Year over year, the survey has begun to reveal long-term trends that give insight into the future of this trusted technology.

    More than 500 IBM i users from around the globe participated in this year’s survey, and we’re so happy to share the results with you. We hope you’ll find the information interesting and useful as you evaluate your own IT projects.

  • AIX Security Basics eCourse

    Core Security

    With so many organizations depending on AIX day to day, ensuring proper security and configuration is critical to ensure the safety of your environment. Don’t let common threats put your critical AIX servers at risk. Avoid simple mistakes and start to build a long-term plan with this AIX Security eCourse. Enroll today to get easy to follow instructions on topics like:

    • Removing extraneous files
    • Patching systems efficiently
    • Setting and validating permissions
    • Managing service considerations
    • Getting overall visibility into your networks

     

  • Developer Kit: Making a Business Case for Modernization and Beyond

    Profound Logic Software, Inc.

    Having trouble getting management approval for modernization projects? The problem may be you're not speaking enough "business" to them.

    This Developer Kit provides you study-backed data and a ready-to-use business case template to help get your very next development project approved!

  • What to Do When Your AS/400 Talent Retires

    HelpSystemsIT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators is small.

    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:

    • Why IBM i skills depletion is a top concern
    • How leading organizations are coping
    • Where automation will make the biggest impact

     

  • IBM i Resources Retiring?

    SB HelpSystems WC GenericLet’s face it: IBM i experts and RPG programmers are retiring from the workforce. Are you prepared to handle their departure?
    Our panel of IBM i experts—Chuck Losinski, Robin Tatam, Richard Schoen, and Tom Huntington—will outline strategies that allow your company to cope with IBM i skills depletion by adopting these strategies that allow you to get the job done without deep expertise on the OS:
    - Automate IBM i processes
    - Use managed services to help fill the gaps
    - Secure the system against data loss and viruses
    The strategies you discover in this webinar will help you ensure that your system of record—your IBM i—continues to deliver a powerful business advantage, even as staff retires.

     

  • Backup and Recovery Considerations for Security Data and Encrypted Backups

    SB PowerTech WC GenericSecurity expert Carol Woodbury is joined by Debbie Saugen. Debbie is an expert on IBM i backup and recovery, disaster recovery, and high availability, helping IBM i shops build and implement effective business continuity plans.
    In today’s business climate, business continuity is more important than ever. But 83 percent of organizations are not totally confident in their backup strategy.
    During this webinar, Carol and Debbie discuss the importance of a good backup plan, how to ensure you’re backing up your security information, and your options for encrypted back-ups.

  • Profound.js: The Agile Approach to Legacy Modernization

    SB Profound WC GenericIn this presentation, Alex Roytman and Liam Allan will unveil a completely new and unique way to modernize your legacy applications. Learn how Agile Modernization:
    - Uses the power of Node.js in place of costly system re-writes and migrations
    - Enables you to modernize legacy systems in an iterative, low-risk manner
    - Makes it easier to hire developers for your modernization efforts
    - Integrates with Profound UI (GUI modernization) for a seamless, end-to-end legacy modernization solution

     

  • Data Breaches: Is IBM i Really at Risk?

    SB PowerTech WC GenericIBM i is known for its security, but this OS could be more vulnerable than you think.
    Although Power Servers often live inside the safety of the perimeter firewall, the risk of suffering a data leak or data corruption remains high.
    Watch noted IBM i security expert Robin Tatam as he discusses common ways that this supposedly “secure” operating system may actually be vulnerable and who the culprits might be.

    Watch the webinar today!

     

  • Easy Mobile Development

    SB Profound WC GenericWatch this on-demand webinar and learn how to rapidly and easily deploy mobile apps to your organization – even when working with legacy RPG code! IBM Champion Scott Klement will demonstrate how to:
    - Develop RPG applications without mobile development experience
    - Deploy secure applications for any mobile device
    - Build one application for all platforms, including Apple and Android
    - Extend the life and reach of your IBM i (aka iSeries, AS400) platform
    You’ll see examples from customers who have used our products and services to deliver the mobile applications of their dreams, faster and easier than they ever thought possible!

     

  • Profound UI: Unlock True Modernization from your IBM i Enterprise

    SB Profound PPL 5491Modern, web-based applications can make your Enterprise more efficient, connected and engaged. This session will demonstrate how the Profound UI framework is the best and most native way to convert your existing RPG applications and develop new modern applications for your business. Additionally, you will learn how you can address modernization across your Enterprise, including databases and legacy source code, with Profound Logic.

  • Node Webinar Series Pt. 1: The World of Node.js on IBM i

    Profound Logic Software, Inc.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.

    Part 1 will teach you what Node.js is, why it's a great option for IBM i shops, and how to take advantage of the ecosystem surrounding Node.

    In addition to background information, our Director of Product Development Scott Klement will demonstrate applications that take advantage of the Node Package Manager (npm).

  • 5 New and Unique Ways to Use the IBM i Audit Journal

    SB HelpSystems ROBOT GenericYou must be asking yourself: am I doing everything I can to protect my organization’s data? Tune in as our panel of IBM i high availability experts discuss:


    - Why companies don’t test role swaps when they know they should
    - Whether high availability in the cloud makes sense for IBM i users
    - Why some organizations don’t have high availability yet
    - How to get high availability up and running at your organization
    - High availability considerations for today’s security concerns

  • Profound.js 2.0: Extend the Power of Node to your IBM i Applications

    SB Profound WC 5541In this Webinar, we'll demonstrate how Profound.js 2.0 enables you to easily adopt Node.js in your business, and to take advantage of the many benefits of Node, including access to a much larger pool of developers for IBM i and access to countless reusable open source code packages on npm (Node Package Manager).
    You will see how Profound.js 2.0 allows you to:

    • Provide RPG-like capabilities for server-side JavaScript.
    • Easily create web and mobile application interfaces for Node on IBM i.
    • Let existing RPG programs call Node.js modules directly, and vice versa.
    • Automatically generate code for Node.js.
    • Automatically converts existing RPGLE code into clean, simplified Node.js code.

    Download and watch today!

     

  • Make Modern Apps You'll Love with Profound UI & Profound.js

    SB Profound WC 5541Whether you have green screens or a drab GUI, your outdated apps can benefit from modern source code, modern GUIs, and modern tools.
    Profound Logic's Alex Roytman and Liam Allan are here to show you how Free-format RPG and Node.js make it possible to deliver applications your whole business will love:

    • Transform legacy RPG code to modern free-format RPG and Node.js
    • Deliver truly modern application interfaces with Profound UI
    • Extend your RPG applications to include Web Services and NPM packages with Node.js

     

  • Accelerating Programmer Productivity with Sequel

    SB_HelpSystems_WC_Generic

    Most business intelligence tools are just that: tools, a means to an end but not an accelerator. Yours could even be slowing you down. But what if your BI tool didn't just give you a platform for query-writing but also improved programmer productivity?
    Watch the recorded webinar to see how Sequel:

    • Makes creating complex results simple
    • Eliminates barriers to data sources
    • Increases flexibility with data usage and distribution

    Accelerated productivity makes everyone happy, from programmer to business user.

  • Business Intelligence is Changing: Make Your Game Plan

    SB_HelpSystems_WC_GenericIt’s time to develop a strategy that will help you meet your informational challenges head-on. Watch the webinar to learn how to set your IT department up for business intelligence success. You’ll learn how the right data access tool will help you:

    • Access IBM i data faster
    • Deliver useful information to executives and business users
    • Empower users with secure data access

    Ready to make your game plan and finally keep up with your data access requests?

     

  • Controlling Insider Threats on IBM i

    SB_HelpSystems_WC_GenericLet’s face facts: servers don’t hack other servers. Despite the avalanche of regulations, news headlines remain chock full of stories about data breaches, all initiated by insiders or intruders masquerading as insiders.
    User profiles are often duplicated or restored and are rarely reviewed for the appropriateness of their current configuration. This increases the risk of the profile being able to access data without the intended authority or having privileges that should be reserved for administrators.
    Watch security expert Robin Tatam as he discusses a new approach for onboarding new users on IBM i and best-practices techniques for managing and monitoring activities after they sign on.

  • Don't Just Settle for Query/400...

    SB_HelpSystems_WC_GenericWhile introducing Sequel Data Access, we’ll address common frustrations with Query/400, discuss major data access, distribution trends, and more advanced query tools. Plus, you’ll learn how a tool like Sequel lightens IT’s load by:

    - Accessing real-time data, so you can make real-time decisions
    - Providing run-time prompts, so users can help themselves
    - Delivering instant results in Microsoft Excel and PDF, without the wait
    - Automating the query process with on-demand data, dashboards, and scheduled jobs

  • How to Manage Documents the Easy Way

    SB_HelpSystems_WC_GenericWhat happens when your company depends on an outdated document management strategy?
    Everything is harder.
    You don’t need to stick with status quo anymore.
    Watch the webinar to learn how to put effective document management into practice and:

    • Capture documents faster, instead of wasting everyone’s time
    • Manage documents easily, so you can always find them
    • Distribute documents automatically, and move on to the next task

     

  • Lessons Learned from the AS/400 Breach

    SB_PowerTech_WC_GenericGet actionable info to avoid becoming the next cyberattack victim.
    In “Data breach digest—Scenarios from the field,” Verizon documented an AS/400 security breach. Whether you call it AS/400, iSeries, or IBM i, you now have proof that the system has been breached.
    Watch IBM i security expert Robin Tatam give an insightful discussion of the issues surrounding this specific scenario.
    Robin will also draw on his extensive cybersecurity experience to discuss policies, processes, and configuration details that you can implement to help reduce the risk of your system being the next victim of an attack.

  • Overwhelmed by Operating Systems?

    SB_HelpSystems_WC_GenericIn this 30-minute recorded webinar, our experts demonstrate how you can:

    • Manage multiple platforms from a central location
    • View monitoring results in a single pane of glass on your desktop or mobile device
    • Take advantage of best practice, plug-and-play monitoring templates
    • Create rules to automate daily checks across your entire infrastructure
    • Receive notification if something is wrong or about to go wrong

    This presentation includes a live demo of Network Server Suite.

     

  • Real-Time Disk Monitoring with Robot Monitor

    SB_HelpSystems_WC_GenericYou need to know when IBM i disk space starts to disappear and where it has gone before system performance and productivity start to suffer. Our experts will show you how Robot Monitor can help you pinpoint exactly when your auxiliary storage starts to disappear and why, so you can start taking a proactive approach to disk monitoring and analysis. You’ll also get insight into:

    • The main sources of disk consumption
    • How to monitor temporary storage and QTEMP objects in real time
    • How to monitor objects and libraries in real time and near-real time
    • How to track long-term disk trends

     

     

  • Stop Re-keying Data Between IBM I and Other Applications

    SB_HelpSystems_WC_GenericMany business still depend on RPG for their daily business processes and report generation.Wouldn’t it be nice if you could stop re-keying data between IBM i and other applications? Or if you could stop replicating data and start processing orders faster? Or what if you could automatically extract data from existing reports instead of re-keying? It’s all possible. Watch this webinar to learn about:

    • The data dilemma
    • 3 ways to stop re-keying data
    • Data automation in practice

    Plus, see how HelpSystems data automation software will help you stop re-keying data.

     

  • The Top Five RPG Open Access Myths....BUSTED!

    SB_Profound_WC_GenericWhen it comes to IBM Rational Open Access: RPG Edition, there are still many misconceptions - especially where application modernization is concerned!

    In this Webinar, we'll address some of the biggest myths about RPG Open Access, including:

    • Modernizing with RPG OA requires significant changes to the source code
    • The RPG language is outdated and impractical for modernizing applications
    • Modernizing with RPG OA is the equivalent to "screen scraping"

     

  • Time to Remove the Paper from Your Desk and Become More Efficient

    SB_HelpSystems_WC_GenericToo much paper is wasted. Attempts to locate documents in endless filing cabinets.And distributing documents is expensive and takes up far too much time.
    These are just three common reasons why it might be time for your company to implement a paperless document management system.
    Watch the webinar to learn more and discover how easy it can be to:

    • Capture
    • Manage
    • And distribute documents digitally

     

  • IBM i: It’s Not Just AS/400

    SB_HelpSystems_WC_Generic

    IBM’s Steve Will talks AS/400, POWER9, cognitive systems, and everything in between

    Are there still companies that use AS400? Of course!

    IBM i was built on the same foundation.
    Watch this recorded webinar with IBM i Chief Architect Steve Will and IBM Power Champion Tom Huntington to gain a unique perspective on the direction of this platform, including:

    • IBM i development strategies in progress at IBM
    • Ways that Watson will shake hands with IBM i
    • Key takeaways from the AS/400 days

     

  • Ask the RDi Experts

    SB_HelpSystems_WC_GenericWatch this recording where Jim Buck, Susan Gantner, and Charlie Guarino answered your questions, including:

    • What are the “hidden gems” in RDi that can make me more productive?
    • What makes RDi Debug better than the STRDBG green screen debugger?
    • How can RDi help me find out if I’ve tested all lines of a program?
    • What’s the best way to transition from PDM to RDi?
    • How do I convince my long-term developers to use RDi?

    This is a unique, online opportunity to hear how you can get more out of RDi.

     

  • Node.js on IBM i Webinar Series Pt. 2: Setting Up Your Development Tools

    Profound Logic Software, Inc.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. In Part 2, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Attend this webinar to learn:

    • Different tools to develop Node.js applications on IBM i
    • Debugging Node.js
    • The basics of Git and tools to help those new to it
    • Using NodeRun.com as a pre-built development environment

     

     

  • Inside the Integrated File System (IFS)

    SB_HelpSystems_WC_GenericDuring this webinar, you’ll learn basic tips, helpful tools, and integrated file system commands—including WRKLNK—for managing your IFS directories and Access Client Solutions (ACS). We’ll answer your most pressing IFS questions, including:

    • What is stored inside my IFS directories?
    • How do I monitor the IFS?
    • How do I replicate the IFS or back it up?
    • How do I secure the IFS?

    Understanding what the integrated file system is and how to work with it must be a critical part of your systems management plans for IBM i.

     

  • Expert Tips for IBM i Security: Beyond the Basics

    SB PowerTech WC GenericIn this session, IBM i security expert Robin Tatam provides a quick recap of IBM i security basics and guides you through some advanced cybersecurity techniques that can help you take data protection to the next level. Robin will cover:

    • Reducing the risk posed by special authorities
    • Establishing object-level security
    • Overseeing user actions and data access

    Don't miss this chance to take your knowledge of IBM i security beyond the basics.

     

     

  • 5 IBM i Security Quick Wins

    SB PowerTech WC GenericIn today’s threat landscape, upper management is laser-focused on cybersecurity. You need to make progress in securing your systems—and make it fast.
    There’s no shortage of actions you could take, but what tactics will actually deliver the results you need? And how can you find a security strategy that fits your budget and time constraints?
    Join top IBM i security expert Robin Tatam as he outlines the five fastest and most impactful changes you can make to strengthen IBM i security this year.
    Your system didn’t become unsecure overnight and you won’t be able to turn it around overnight either. But quick wins are possible with IBM i security, and Robin Tatam will show you how to achieve them.

  • How to Meet the Newest Encryption Requirements on IBM i

    SB PowerTech WC GenericA growing number of compliance mandates require sensitive data to be encrypted. But what kind of encryption solution will satisfy an auditor and how can you implement encryption on IBM i? Watch this on-demand webinar to find out how to meet today’s most common encryption requirements on IBM i. You’ll also learn:

    • Why disk encryption isn’t enough
    • What sets strong encryption apart from other solutions
    • Important considerations before implementing encryption

     

     

  • Security Bulletin: Malware Infection Discovered on IBM i Server!

    SB PowerTech WC GenericMalicious programs can bring entire businesses to their knees—and IBM i shops are not immune. It’s critical to grasp the true impact malware can have on IBM i and the network that connects to it. Attend this webinar to gain a thorough understanding of the relationships between:

    • Viruses, native objects, and the integrated file system (IFS)
    • Power Systems and Windows-based viruses and malware
    • PC-based anti-virus scanning versus native IBM i scanning

    There are a number of ways you can minimize your exposure to viruses. IBM i security expert Sandi Moore explains the facts, including how to ensure you're fully protected and compliant with regulations such as PCI.

     

     

  • Fight Cyber Threats with IBM i Encryption

    SB PowerTech WC GenericCyber attacks often target mission-critical servers, and those attack strategies are constantly changing. To stay on top of these threats, your cybersecurity strategies must evolve, too. In this session, IBM i security expert Robin Tatam provides a quick recap of IBM i security basics and guides you through some advanced cybersecurity techniques that can help you take data protection to the next level. Robin will cover:

    • Reducing the risk posed by special authorities
    • Establishing object-level security
    • Overseeing user actions and data access

     

     

     

  • 10 Practical IBM i Security Tips for Surviving Covid-19 and Working From Home

    SB PowerTech WC GenericNow that many organizations have moved to a work from home model, security concerns have risen.

    During this session Carol Woodbury will discuss the issues that the world is currently seeing such as increased malware attacks and then provide practical actions you can take to both monitor and protect your IBM i during this challenging time.

     

  • How to Transfer IBM i Data to Microsoft Excel

    SB_HelpSystems_WC_Generic3 easy ways to get IBM i data into Excel every time
    There’s an easy, more reliable way to import your IBM i data to Excel? It’s called Sequel. During this webinar, our data access experts demonstrate how you can simplify the process of getting data from multiple sources—including Db2 for i—into Excel. Watch to learn how to:

    • Download your IBM i data to Excel in a single step
    • Deliver data to business users in Excel via email or a scheduled job
    • Access IBM i data directly using the Excel add-in in Sequel

    Make 2020 the year you finally see your data clearly, quickly, and securely. Start by giving business users the ability to access crucial business data from IBM i the way they want it—in Microsoft Excel.

     

     

  • HA Alternatives: MIMIX Is Not Your Only Option on IBM i

    SB_HelpSystems_WC_GenericIn this recorded webinar, our experts introduce you to the new HA transition technology available with our Robot HA software. You’ll learn how to:

    • Transition your rules from MIMIX (if you’re happy with them)
    • Simplify your day-to-day activities around high availability
    • Gain back time in your work week
    • Make your CEO happy about reducing IT costs

    Don’t stick with a legacy high availability solution that makes you uncomfortable when transitioning to something better can be simple, safe, and cost-effective.

     

     

  • Comply in 5! Well, actually UNDER 5 minutes!!

    SB CYBRA PPL 5382

    TRY 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.

    Request your trial now!

  • Backup and Recovery on IBM i: Your Strategy for the Unexpected

    SB HelpSystems SC 5413Robot automates the routine 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:
    - Simplified backup procedures
    - Easy data encryption
    - Save media management
    - Guided restoration
    - Seamless product integration
    Make sure your data survives when catastrophe hits. Try the Robot Backup and Recovery Solution FREE for 30 days.

  • Manage IBM i Messages by Exception with Robot

    SB HelpSystems SC 5413Managing messages on your IBM i can be more than a full-time job if you have to do it manually. 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:
    - Automated message management
    - Tailored notifications and automatic escalation
    - System-wide control of your IBM i partitions
    - Two-way system notifications from your mobile device
    - Seamless product integration
    Try the Robot Message Management Solution FREE for 30 days.

  • Easiest Way to Save Money? Stop Printing IBM i Reports

    SB HelpSystems SC 5413Robot 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:

    - Automated report distribution
    - View online without delay
    - Browser interface to make notes
    - Custom retention capabilities
    - Seamless product integration
    Rerun another report? Never again. Try the Robot Report Management Solution FREE for 30 days.

  • Hassle-Free IBM i Operations around the Clock

    SB HelpSystems SC 5413For over 30 years, Robot has been a leader in systems management for IBM i.
    Manage your job schedule with the Robot Job Scheduling Solution. Key features include:
    - Automated batch, interactive, and cross-platform scheduling
    - Event-driven dependency processing
    - Centralized monitoring and reporting
    - Audit log and ready-to-use reports
    - Seamless product integration
    Scale your software, not your staff. Try the Robot Job Scheduling Solution FREE for 30 days.

  • ACO MONITOR Manages your IBM i 24/7 and Notifies You When Your IBM i Needs Assistance!

    SB DDL Systems 5429More than a paging system - ACO MONITOR is a complete systems management solution for your Power Systems running IBM i. ACO MONITOR manages your Power System 24/7, uses advanced technology (like two-way messaging) to notify on-duty support personnel, and responds to complex problems before they reach critical status.

    ACO MONITOR is proven technology and is capable of processing thousands of mission-critical events daily. The software is pre-configured, easy to install, scalable, and greatly improves data center efficiency.