Sidebar

Patch Those Leaky Interfaces

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

In today's high-tech IT world, it's common for shops to share data on multiple platforms. For those trusted with the task of writing the interfaces to share the data, there are many annoyances. For example, who hasn't sent data from one platform to an export file, updated flags in the database to signal the data has been sent, and then discovered that the export file never made it to its final destination on the remote system? Worse, even when the data does make it to the remote system, it's common to encounter an error resulting in partial data updates, which often makes restarting the entire process a mess.

Fortunately, for those sharing data between Microsoft's SQL Server and the iSeries, there's a splendid aid at your disposal: distributed transactions (DTs). DTs are functionally similar to local database transactions in that they have a beginning boundary, data modification statements, and an ending boundary whereupon the data changes that occurred are either committed or rolled back. However, distributed transactions extend the concept further by allowing data modification statements to occur against databases on multiple platforms.

Think of how moving data between disparate systems would be simplified with distributed transactions:
1. A transaction boundary is created.
2. Data is moved from the source platform to the destination platform.
3. The source platform marks its data as sent.
4. If everything is successful, all of the changes are committed on both systems
5. If there is a failure, all of the changes are rolled back. When the error condition is fixed, the process can easily resume.

Since transactions involve the "all or nothing" concept, the programmer is assured the data is successfully changed on both platforms or on neither. Never again need we fuss over where to pick back up in the multiplatform processing cycle or reset flags to send data again!

The SQL Server documentation gives good a good introduction to DTs and explains how they work. This article covers the basics of performing a DT using SQL Server's Transact SQL (T-SQL).

Setup

To set up a SQL Server/iSeries environment capable of performing a DT, you need to configure the following items:

  • iSeries files to participate in a DT must be journaled.
  • The Client Access V5R1 ODBC driver must be installed on the SQL Server machine.
  • A linked server to the iSeries must be configured.
  • The SQL Server Distributed Transaction Coordinator (DTC) must be started.


The first requirement is that the iSeries physical files to be modified must be journaled. Tables created in a schema (library) created by the CREATE SCHEMA statement are automatically journaled. To verify if a physical file is journaled, use the Display File Description (DSPFD) command. If it is not journaled, use the Start Journal Physical File (STRJRNPF) command to start journaling. If you need help with iSeries journaling concepts (journals, receivers, etc.) see chapters 19 and 20 of the Backup and Recovery Guide.

The second requirement involves installing the Client Access ODBC Driver (V5R1 or higher with the latest service pack) on the SQL Server machine. OS/400 has to be at V5R1 or higher as well. (Starting with V5R2, Client Access has been renamed to iSeries Access, but I will refer to it as Client Access here.) In case you're wondering, the Client Access OLE DB provider IBMDA400 does not currently support distributed transaction processing and therefore cannot be used.

Once the Client Access ODBC Driver is installed, configure an ODBC data source to the iSeries under the System Data Source Name (DSN) tab. For this article, I named my DSN "ISERIES" and used the default options.

The third requirement is to configure a linked server (requires SQL Server 7.0 and above--SQL Server 2000 is used here). A linked server definition allows SQL Server to access tables from a remote database as though they were part of its own local database.

To configure the linked server, start the SQL Server Enterprise Manager. Navigate the tree hierarchy and select the server you want to work with. Expand the server and then expand the "Security" node. Right-click on "Linked Servers" and choose "New Linked Server." In the linked server name box, enter ISERIES again, for consistency with the ODBC DSN. This linked server name will be used to refer to iSeries tables when working with T-SQL.

Under server type, choose "Other Data Source" and select the "Microsoft OLE DB Provider for ODBC Drivers" in the provider name combo box. Under "Product Name" enter "DB2 for iSeries." In the "Data Source" box, enter a valid iSeries DSN (if following along with this example, enter ISERIES.) In the "Provider String" box, you may optionally enter any DSN overrides. For example, to make the iSeries library TESTDATA the default library, enter DBQ=TESTDATA, where DBQ is the Client Access ODBC Driver's keyword to override the library list.

Next, you need to establish the security credentials for the linked server. Click on the Security tab of the "Linked Server Properties" window. In this window, SQL Server gives the option to define a login cross-reference to link the credentials of a specific SQL Server user to a specific iSeries user, but for simplicity, I will not use this feature in this example. In the bottom half of the window, there are options for login definitions not specified in the cross-reference list. Choose the "Be made using this security context" option (SQL Server 7.0's option is "They will be mapped to") and enter a valid iSeries user name and password in the boxes below. Whenever SQL Server attempts to talk to the iSeries linked server, it will use the login information specified here. The linked server has now been configured. Click the OK button.

The last step involves starting the Microsoft SQL Server DTC service. The DTC, which can be started from the SQL Server Service Manager utility, is responsible for handling DT processing across multiple database servers.

Accessing Data on a Linked Server

To verify that the linked server is set up correctly, run a distributed query (DQ). A DQ is a T-SQL query that accesses data on a linked server. One way to run a DQ is to specify a four-part table name in the FROM clause of a SELECT. Specifically, for an iSeries-linked server, the four-part table name is specified as follows:

SELECT *
  FROM linked server.RDB name.schema name.table name


For example, if your linked server name is called "ISERIES," your iSeries' relational database (RDB) name is S1024000 (it's usually the same as your system name), your schema (library) is LIVEDATA, and your table is ORDERS, you would enter the following to retrieve the table's data:

SELECT *
  FROM ISERIES.S1024000.LIVEDATA.ORDERS


This will allow SQL Server to query the ORDERS table on your iSeries as though it were local to SQL Server. Start the Query Analyzer utility, and try it! In fact, using the four-part syntax shown above, you can place an iSeries table in the FROM, JOIN, subquery, or nested select portion of a SELECT statement. The better news is that linked server tables can also participate in UPDATE and DELETE statements (provided the linked server's ODBC or OLE DB drivers are capable, which is the case with the Client Access ODBC driver.)

Another way to run a DQ is to use the OPENQUERY function. OPENQUERY submits a passthrough query to the backend database engine for processing and returns the results as though it were a SQL Server table. OPENQUERY requires two parameters: a linked server name and an SQL statement. The following is an example of how to use OPENQUERY:

SELECT *
  FROM OPENQUERY(ISERIES,'Select * From LiveData.Orders')


The main difference between the two examples is that, with the four-part table name syntax, SQL Server queries less efficiently than with OPENQUERY. OPENQUERY avoids much of SQL Server's overhead by submitting a SQL statement directly to the linked server's database engine. To do this, however, the SQL statement supplied to OPENQUERY must conform to the linked server's SQL dialect. In other words, you can't submit a T-SQL statement to an iSeries linked server.

Many DQ performance considerations are beyond the scope of this article. For some of the iSeries-specific performance considerations, see "Running Distributed Queries with SQL/400 and SQL Server 7.0" in the September/October 2000 issue of AS/400 Network Expert. For more information on DQs, see the SQL Server T-SQL documentation on the OPENQUERY, OPENROWSET, and distributed query topics.

Running a Distributed Transaction

Now, we're at the heart of the topic. For this demonstration, on the SQL Server side, I'll be using the NORTHWINDCS sample database, which is included with Office XP (you could also use the sample database called NORTHWIND that comes with Office 2000). I'll focus on a particular table called Products, which is the Product Master table.

For this example, assume that an identical Products table exists on the iSeries and that these two tables need to be synchronized at five-minute intervals. The structure of the Products tables for each platform is shown in Figure 1.

CREATE TABLE dbo.Products (
ProductID int IDENTITY (1, 1) NOT NULL,
ProductName varchar (40) NOT NULL,
SupplierID int NULL,
CategoryID int NULL,
QuantityPerUnit varchar (20) NULL,
UnitPrice money NULL,
UnitsInStock smallint NULL,
UnitsOnOrder smallint NULL,
ReorderLevel smallint NULL,
Discontinued bit NOT NULL,

CREATE TABLE NORTHWIND.PRODUCTS (

PRODUCTID INTEGER DEFAULT NULL,

PRODUCTNAME FOR COLUMN PRODU00001
    VARCHAR(60) CCSID 37 DEFAULT NULL,

SUPPLIERID INTEGER DEFAULT NULL,

CATEGORYID INTEGER DEFAULT NULL,

QUANTITYPERUNIT FOR COLUMN QUANT00001
    VARCHAR(20) CCSID 37 DEFAULT NULL,

UNITPRICE DOUBLE PRECISION DEFAULT NULL,

UNITSINSTOCK FOR COLUMN UNITS00001 SMALLINT DEFAULT NULL,

UNITSONORDER FOR COLUMN UNITS00002 SMALLINT DEFAULT NULL,

REORDERLEVEL FOR COLUMN REORD00001 SMALLINT DEFAULT NULL,

DISCONTINUED FOR COLUMN DISCO00001 SMALLINT DEFAULT NULL,

SYNCHRONIZED FOR COLUMN SYNCHRONIZ 
    SMALLINT NOT NULL DEFAULT 0,

CONSTRAINT NORTHWIND.PRODUCTS_PRIKEY PRIMARY KEY(PRODUCTID))

Figure 1: These are the Products tables from the NORTHWIND database as they exist within SQL Server and the iSeries. The Synchronized column was added to both for tracking an item change.

For simplicity, assume that the synchronization will flow in only one direction. The Products table on the SQL Server side is the "master"--that is, changes to the Products table have to be done through a SQL Server application. Further, changes to the iSeries table will only be those resulting from the synchronization process.

To try this scenario, open Query Analyzer, select the NorthwindCS database, and issue the following SQL statement to add a "synchronized" flag to the Products table:

ALTER TABLE dbo.Products ADD Synchronized Bit Not Null Default 1


Next, create a schema (library) on your iSeries called NORTHWIND using the "CREATE SCHEMA NORTHWIND" SQL statement. Create the Products table in schema NORTHWIND using the second CREATE TABLE statement shown in Figure 1 (remember to use the appropriate SQL naming convention). This table will be journaled automatically. Finally, copy the Products table data from SQL Server to the iSeries using the distributed query shown in Figure 2.

Use NorthwindCS
Go
--
-- NOTE:
-- Replace S1024000 with your system's RDB name
-- 
Insert Into ISERIES.S1024000.NORTHWIND.PRODUCTS
Select *
  From Products A
 Where ProductID Not In
    (Select * 
       From OpenQuery(ISERIES,'SELECT PRODUCTID
                                 FROM NORTHWIND.PRODUCTS
                                 WITH NC'))

Go

Figure 2: This distributed query will insert data into the iSeries Products table from the SQL Server Products table.

Look at Figure 2's INSERT STATEMENT. The four-part table name syntax is specified as the table to receive the data. The SELECT portion consists of the SQL Server Products table with a subselect to the iSeries Products table again, to make sure a duplicate record isn't inserted (of course, all records will be inserted the first time through.)

In the subselect, though, the iSeries Products table is embedded in the OPENQUERY function instead of the four-part table name syntax. In this case, the reason for using OPENQUERY instead of the four-part table name has to do with performance.

Now that the tables are synchronized, subsequent inserts, changes, and deletes to the SQL Server table have to be tracked and moved to the iSeries table. Figure 3 shows a complete T-SQL stored procedure to do this.

Create Procedure spSynchronizeProductsTable
As
--
-- Synchronize iSeries and SQL Server Products 
-- Table for all records that have changed.
--
-- 
--
-- Procedure Status Returns:
--   0 - OK
--   1 - Failed Status
--
--
-- NOTE: Everywhere S1024000 occurs, replace
--       with your system's RDB name
--

-- Cursor Variables
Declare @ProductID  int
Declare @ProductName  varchar(40)
Declare @SupplierID  int
Declare @CategoryID  int
Declare @QuantityPerUnit varchar(20)
Declare @UnitPrice  money
Declare @UnitsInStock  smallint
Declare @UnitsOnOrder  smallint
Declare @ReorderLevel  smallint
Declare @Discontinued  bit
Declare @Syncrhonized  bit

Declare @Status  int

--
-- Turning on XACT_Abort alleviates the need for the 
-- OLE DB/ODBC connection to support nested
-- transactions
--
Set XAct_Abort On

Set NoCount On -- Turn this off during debugging
Set @Status=0


--***************************************************
--
-- SECTION 1
--
-- Insert all new records into the iSeries table
-- 
Insert Into ISERIES.S1024000.NORTHWIND.PRODUCTS
Select *
  From Products A
 Where ProductID Not In
    (Select * 
       From OpenQuery(ISERIES,'SELECT PRODUCTID
                                 FROM NORTHWIND.PRODUCTS
                                 WITH NC'))

--***************************************************
-- SECTION 2
--
-- Read all changed product records
--
Declare ProductSync Cursor For
 Select *
   From Products
  Where Synchronized=0 -- Changed Products
    For Update Of Synchronized


-- Open Cursor & Fetch First Record
Open ProductSync

Fetch ProductSync Into @ProductID,@ProductName,
                       @SupplierID,@CategoryID,
                       @QuantityPerUnit,@UnitPrice,
                       @UnitsInStock,@UnitsOnOrder,
                       @ReorderLevel,@Discontinued,
                       @Syncrhonized

While @@Fetch_Status=0
Begin
    Begin Distributed Transaction

    -- This example assumes the ProductID can't be changed!
    Update ISERIES.S1024000.NORTHWIND.PRODUCTS
       Set ProductName=@ProductName,
           SupplierID=@SupplierID,
           CategoryID=@CategoryID,
           QuantityPerUnit=@QuantityPerUnit,
           UnitPrice=@UnitPrice,
           UnitsInStock=@UnitsInStock,
           UnitsOnOrder=@UnitsOnOrder,
           ReorderLevel=@ReorderLevel,
           Discontinued=@Discontinued
     Where ProductID=@ProductID

    -- Set Local Products Table "Synchronized" Flag
    Update Products
       Set Synchronized=1
     Where Current Of ProductSync

    -- Commit Distributed Transaction
    If @@Error=0
    Begin
         Set @Status=1
        Commit
    End
    Else
        Rollback

    Fetch ProductSync Into @ProductID,@ProductName,
                           @SupplierID,@CategoryID,
                           @QuantityPerUnit,@UnitPrice,
                           @UnitsInStock,@UnitsOnOrder,
                           @ReorderLevel,@Discontinued,
                           @Syncrhonized
End
-- Close and deallocate cursor
Close ProductSync
Deallocate ProductSync


--***************************************************
-- SECTION 3
--
-- Delete all records in the iSeries table
-- that are no longer in SQL Server
--
Delete From ISERIES.S1024000.NORTHWIND.PRODUCTS
 Where ProductID Not In (
               Select ProductID 
                 From Products) 

Set XAct_Abort Off

Return @Status

Figure 3: This stored procedure will propagate adds, updates, and deletes from the SQL Server Products table to the iSeries Products table.

Notice that the XAct_Abort is set to On. This is done to prevent nested transactions, which the iSeries ODBC driver does not allow. By default, SQL Server processes all statements inside a default transaction so that partial rollbacks can occur. Starting another explicit transaction using BEGIN TRANSACTION actually starts a nested transaction, which will cause the CA ODBC driver to error out. Setting XAct_Abort to On turns off the default initial transaction boundary. By implication, this setting will also prevent SQL Server from doing partial rollbacks.

The first code section is a repeat of the code already shown in Figure 2. An INSERT statement is used to move all new records from the SQL Server Products table to the iSeries table.

The second section involves reflecting all changes to the products in the SQL Server table on the iSeries. A cursor is opened against the local Products table to select all products that have changed. Inside the loop, the BEGIN DISTRIBUTED TRANSACTION statement is executed to start a transaction for each item. In this case, each product update will be treated as a single transaction. If your situation requires either all or none of the Product updates to occur, you can specify the BEGIN and COMMIT transaction boundaries outside of the loop.

Inside the loop, an UPDATE is issued against the iSeries table for each field. After the update is completed, SQL Server's SYNCRHONIZED column is set to true to indicate that the two tables are in sync for the given ProductID. After the second update is completed, the transaction is committed or rolled back, depending on whether an error occurred. This is where the power of the DT shines: The SQL Server synchronized flag will not be set to True unless the data is successfully placed on the iSeries.

The third and final section deletes all products from the iSeries table that no longer exist in the SQL Server table. Again, the four-part table name is specified, and an EXISTS clause is used to see if the ProductID on the iSeries still exists in the SQL Server Products table. You probably realized that the INSERT and DELETE statements were not embedded inside of a BEGIN DISTRIBUTED TRANSACTION block. This is because DT processing isn't required here, since data is being updated on only one platform.

Writing that stored procedure was relatively painless--it's hardly different from a procedure written to synchronize two local tables! However, there are still two additional requirements to make the synchronization take place. The first requirement is to set the Synchronized flag to False (0) whenever a product is changed. You can do this through either the application program or an update trigger. The second necessity is to schedule this stored procedure to run at regular intervals using SQL Server Agent or some other scheduling mechanism.

Does It Really Work?

If you're still following along in this example, you can now see for yourself how this works. Open the NorthwindCS.ADP Client/Server sample database with Microsoft Access. Go to the database window, choose the Tables tab, and double-click on the Products table to open it. Delete a few records, insert a few new records, and change a few records. For the changed records, set the synchronized flag to False (0). (To delete existing records, you will have to remove the referential integrity constraint between the Order Details and Products table.) Issue the CREATE PROCEDURE statement shown in Figure 3, then execute it as follows:

Use NorthwindCS
Go

Exec spSynchronizeProductsTable


When you query the data on the iSeries, all of your modifications to the SQL Server table should be reflected.

iSeries-Side Cursors

In case you need to create a DT involving a cursor on the iSeries, Figure 4 shows how to do this.

Set Transaction Isolation Level Read Uncommitted
Go
Use NorthwindCS
Go   
-- 
--V5R1 CA SI06804 gives "invalid parameter marker message" 
--
--
-- NOTE: Everywhere S1024000 occurs, replace
--       with your system's RDB name
--


-- Cursor Variables 
Declare @ProductID  Int
Declare @ProductName  Varchar(40)
Declare @SupplierID  Int
Declare @CategoryID  Int
Declare @QuantityPerUnit Varchar(20)
Declare @UnitPrice  Money
Declare @UnitsInStock  Smallint
Declare @UnitsOnOrder  Smallint
Declare @ReorderLevel  Smallint
Declare @Discontinued  Smallint
Declare @Synchronized  Smallint


Set NoCount On
--
-- NOTE: iSeries Data Source should be set
--       to COMMIT=*NONE so that the 
--       isolation level can be set
--
Set XAct_Abort On
--
-- The repeatable read or serializable transaction 
-- isolation level is required for an updateable 
-- cursor on the linked server.
--
-- If this level is too restrictive, consider using
--  a READ ONLY cursor with UPDATE statements.
--
Set Transaction Isolation Level Repeatable Read

--
-- NOTE: The cursor is required to be opened inside
--       the transaction boundary
--
-- 
Begin Distributed Transaction
--
-- Updateable cursors in SQL Server require a
-- unique key on the linked server table.
--
-- If your cursor receives a fetch_status of -2,
-- check to make sure all column names are 
-- placed in upper case.
-- (i.e. "ProductID"<>"PRODUCTID")
--
Declare ProductSync Cursor For
 Select *
   From ISERIES.S1024000.NORTHWIND.PRODUCTS
  Where SYNCHRONIZED=0 
    For Update Of SYNCHRONIZED

Open ProductSync

Fetch ProductSync Into @ProductID,@ProductName,
                       @SupplierID,@CategoryID,
                       @QuantityPerUnit,@UnitPrice,
                       @UnitsInStock,@UnitsOnOrder,
                       @ReorderLevel,@Discontinued,
                       @Synchronized

While @@Fetch_Status=0
Begin
    Update Products
       Set ProductName=@ProductName,
           SupplierID=@SupplierID,
           CategoryID=@CategoryID,
           QuantityPerUnit=@QuantityPerUnit,
           UnitPrice=@UnitPrice,
           UnitsInStock=@UnitsInStock,
           UnitsOnOrder=@UnitsOnOrder,
           ReorderLevel=@ReorderLevel,
           Discontinued=@Discontinued
     Where ProductID=@ProductID


    Update ISERIES.S1024000.NORTHWIND.PRODUCTS
       Set SYNCHRONIZED=1
     Where Current Of ProductSync

    Fetch ProductSync Into @ProductID,@ProductName,
                           @SupplierID,@CategoryID,
                           @QuantityPerUnit,@UnitPrice,
                           @UnitsInStock,@UnitsOnOrder,
                           @ReorderLevel,@Discontinued,
                           @Synchronized
End

Close ProductSync
Deallocate ProductSync

If @@Error=0
    Commit
Else
    Rollback

Set Transaction Isolation Level Read Committed

Set XAct_Abort Off

Figure 4: This T-SQL shows how to use an updateable cursor on the iSeries within a distributed transaction.

The major difference between this code and the code in Figure 3 (other than the table reversal) is that the transaction boundary has to be placed before the cursor declaration. This means that all of the records will be involved within the transaction boundary. To have an updateable cursor on a linked server, SQL Server requires that the isolation level be set to repeatable read or serializable. These locking levels are restrictive in terms of record locking, so use updateable cursors sparingly.

The one other thing to be aware of is that I had to modify the ODBC DSN with a default commitment control level of *NONE. Without this setting, I would erratically get error messages stating that the required transaction isolation level could not be achieved.

Trials and Tribulations of New Technology

Even though DTs are extremely useful and will continue to grow in popularity, there are still pitfalls. While the end product looks easy enough, it takes quite a bit of fiddling to get everything to work correctly. Listed below are some of the major things I battled with:

Linked Server Errors Cause Processing to Halt

Even though the code shows a tidy Commit and Rollback, the fact is that, when a linked server error occurs, the entire procedure stops with an error severity of 16. As far as I can tell, there is no way to trap these errors. (If someone knows a way around this, please let me and everyone else know by posting a note to the forum associated with this article.) If, for example, a record on the iSeries is locked so that it can't be changed, the procedure will just stop instead of allowing a programmatic response to the condition. This is the worst drawback I encountered.

Case-Sensitive Names

Be careful when entering four-part table names because the RDB name, schema, and table names should be entered in uppercase. In a few cases, when I used an iSeries side cursor, column names seemed to be case-sensitive as well.

Unique Indexes

If you need an updateable iSeries side cursor, SQL Server requires that the table have a unique index. If for some reason your base table isn't able to have a unique index, you can use a read-only cursor with individual UPDATE statements to change the data.

Service Pack Levels

This is the real killer. I toyed around with various Client Access levels and service packs and received varied results. Here is the exact configuration I tested with:

  • OS/400 V5R1 with Group Database Fix SF99501-04
  • Windows XP Professional with Service Pack 1
  • SQL Server 2000 (with no service pack and Service Packs 1 and 3)
  • Client Access V5R1 SI05361 and SI06804
  • iSeries Access V5R2 SI07675, SI06631 (SI05853 didn't work)


Things are a little too fragile for my liking. Unfortunately, it seems that the CA ODBC driver's ability to work with DQs and DTs changes from service pack to service pack. For instance, I had complete success with everything shown in this article using CA V5R2 SI07675. However, SI05853 was a complete flop. The V5R1 SI06804 did everything except for the iSeries-side updateable cursor.

My only reason for sharing this information is that it was frustrating trying to find the right combination of software levels to make the thing work!

Ensuring the Veracity and Timeliness of Shared Data

As the requirements for sharing data between platforms in real time increases, so will the popularity of DTs. Their ease of use and ability to guarantee the "all or nothing" concept among multiple database servers make them an ideal candidate for fulfilling many of the cross-platform interface requirements.

Michael Sansoterra is a programmer/analyst at SilverLake Resources, an IT services firm based in Grand Rapids, Michigan. You can reach him at This email address is being protected from spambots. You need JavaScript enabled to view it..

Michael Sansoterra is a DBA for Broadway Systems in Grand Rapids, Michigan. He can be contacted at sqlsleuth@gmail.com.


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.