Sidebar

DB2 Integration with SQL Server 2005, Part 2: CLR Integration

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

The introduction of SQL Server 2005 has brought some exciting new features for developers. For instance, the ability to integrate heterogeneous systems with SQL Server in real time keeps getting easier. Part I of this series covered the power and ease of using linked servers as a means of programmatically providing real-time linkage to a remote database via ODBC or OLE DB. Although the options are limitless, this article demonstrates the power of using the .NET Common Language Runtime (CLR) as a means of integrating with remote databases (in particular, DB2 UDB for the iSeries).

What Is CLR?

CLR is the controlled environment used to execute code written in a .NET-compatible language such as C#, VB.NET, or COBOL.NET. All .NET programs—regardless of language—are compiled into something called the Microsoft Intermediate Language (MSIL). It is this intermediate language code that is actually run in the CLR. The concept employed is similar to the byte code that is run by the Java Virtual Machine (JVM).

How Does SQL Server 2005 Use the CLR?

Simply put, SQL Server 2005 (SQL Server hereafter) has the ability to execute compiled code written in any .NET language. This means SQL routines (usually written in T-SQL) such as stored procedures, scalar user-defined functions, and table-valued user-defined functions can be written in a .NET language.

Writing database server code in a .NET language has the following advantages:

  • Allows code reuse—The database logic and application logic now have access to the exact same code. In the past, an application would have code written in a high-level language, and the database server would often have duplicated code written in SQL.
  • Removes SQL limitations—SQL dialects work well with structured database data within the confines of its own server. However, database logic often demands data from other sources, such as external databases on other platforms, various text files, LDAP queries, etc. Allowing the use of .NET code gives the database developer the ability to overcome traditional SQL limitations.

Many of you by now realize that Microsoft is playing catch-up to something DB2 on the iSeries has been able to do for a long time creating additional database routines using high-level language logic written in RPG, COBOL, C, Java, and others. Nevertheless, this is a welcome addition to SQL Server's capabilities.

The Need for CLR

Recall that linked servers blur the dividing line between SQL Server and other databases by allowing SQL Server to issue Data Definition Language (DDL) and Data Manipulation Language (DML) statements against remote database tables as though they were part of SQL Server. All of this can be done within the comfort of easy-to-understand T-SQL statements.

With linked servers offering flexibility and ease of programming, why would we need to write a CLR routine? The answer lies where linked server capabilities have a few shortcomings:

  • Error-handling tasks, such as writing detailed info to a log, can be done more gracefully and thoroughly using .NET routines.
  • Dynamically changing remote database environments can be a chore with linked servers. For instance, to point a linked server to a different DB2 database or different machine altogether requires writing ugly dynamic SQL, using synonyms or dropping the linked server and creating it with different attributes. On the other hand, connection strings can be changed easily in .NET.
  • Caching the results of parameterized queries or stored procedures often requires using the somewhat clumsy Insert-Exec T-SQL construct in order to save results from the remote database in a table (usually temporary) that T-SQL can use. This step is unnecessary with .NET routines.
  • Linked servers do not offer the versatility of massaging data from a remote data source before handing it to SQL Server as compared to a CLR routine.
  • Remote data access routines may need the benefit of business logic or other routines only available within the .NET realm.

To demonstrate CLR integration to a remote database, I'll create a table-valued user-defined function and a stored procedure written in VB.NET. These routines will call a DB2 query and return the results to SQL Server as though the data came from a local SQL Server table. (Note that both of these concepts can be accomplished similarly in DB2 on the iSeries using Java as demonstrated in "Query Remote Database Tables from the iSeries Using SQL and Java" and "Execute Remote Stored Procedures from the iSeries").

Software Requirements

The examples require iSeries Access V5R3 (or higher with the latest service pack) to be installed along with the DB2 UDB for iSeries .NET managed provider component (the appropriate ODBC or OLE DB providers can be substituted as well). This must be installed on the same machine as SQL Server.

Visual Studio 2005 (hereafter VS) is also required (not necessarily on the same machine) along with the SQL Server client tools (which will provide VS the templates for creating SQL Server routines and deploying them automatically). Understand that these procedures can be created outside of VS using Notepad, but the deployment and compilation instructions would be a chore to describe!

Setting Up SQL Server 2005

Since .NET code can do just about anything, including destructive tasks, for security reasons you must flip a switch in order to enable SQL Server 2005 to run .NET code. This feature can be enabled by starting the SQL Server Surface Area Configuration utility. Click on Surface Area Configuration for Features, expand the database engine node, click on CLR Integration, and then check the Enable CLR Integration box.

Alternatively, you can execute the following T-SQL code:

EXEC sp_configure 'show advanced options', 1
GO
RECONFIGURE
GO
sp_configure 'clr enabled', 1
GO
RECONFIGURE
GO

Next, you'll need to choose an existing database or create a new database to use for this exercise. I simply used the AdventureWorks sample database. Start a SQL Server management studio session (this is a unified replacement for the old Enterprise Manager and Query Analyzer tools) and start a new query session that is configured to use the database you've chosen.

Once you've decided on a database, mark it as "trustworthy" using the ALTER DATABASE statement so that it can reference "unsafe" .NET code (more on this in a minute):

Alter Database AdventureWorks
Set TRUSTWORTHY On

To do these examples, we'll use the DB2 UDB for iSeries .NET managed provider, so we'll need to add a reference to this assembly. The references to code in external assemblies for a SQL Server CLR project are really enabled by the assemblies referenced within SQL Server. Therefore, you may not add a reference to an assembly from Visual Studio within a SQL Server project as you would in other projects. To register an assembly that SQL Server can use, you must issue the CREATE ASSEMBLY SQL statement (this is done in SQL Server management studio within the database you've chosen).

In case you're new to .NET, an "assembly" refers to executable .NET code stored as a DLL file (somewhat similar to the concept of an ILEservice program). In the example below, IBM.Data.DB2.iSeries.dll is a reusable .NET assembly distributed by IBM.

CREATE ASSEMBLY IBMDataDB2iSeries
FROM 'C:Program FilesIBMClient AccessIBM.Data.DB2.iSeries.dll'
WITH PERMISSION_SET = unsafe;

This misleading SQL doesn't really create or compile any code; it only registers existing code for use by SQL Server. The CREATE/DROP ASSEMBLY syntax was implemented for consistency with other SQL statements. The FROM clause contains the path to the qualified path name to the actual assembly (which may vary on your computer, depending on your iSeries Access installation directory).

Finally, the PERMISSION_SET allows three values: SAFE, EXTERNAL ACCESS, and UNSAFE. SAFE indicates that the code requires no access outside of SQL Server. EXTERNAL ACCESS allows the code to access resources such as files, networks, environment variables, and the registry. The UNSAFE setting allows calls to unmanaged code (e.g., COM objects) and other code that is outside the control of the .NET framework. The current DB2 provider assembly requires this setting. As the Microsoft documentation notes, grant the UNSAFE setting only to highly trusted assemblies; otherwise, your system security may be compromised or your system may become unstable. After executing this statement, SQL Server will issue a warning about relative .NET framework levels (because the IBM DB2 for iSeries assembly was written for V1.0 of the framework). You can ignore this error.

Fire Up Visual Studio 2005

After starting a new VS session, create a new project. Select VB.NET as the language (expand this node) and choose the Database project type. Click on SQL Server Project in the templates window and assign a project name (such as MCPressDemo) and a solution name. The Add Database Reference window will appear. Select your database from the list or click the Add New Reference button to select your SQL Server and database name (again, I used AdventureWorks). If you're prompted with a message about debugging CLR code, choose Yes if this is a server you can tinker with (as debugging can impact performance).

If you don't have the SQL Server template available in Visual Studio, that could indicate an issue with having the SQL Server client components installed incorrectly.

Once the project is open, choose Properties from the Project menu and then the Database tab. Set the permission level setting to Unsafe because the project will contain a reference to the IBM DB2 assembly. Next, choose Add Reference from the Project menu. The list of references will be limited to some default .NET framework assemblies and any assemblies registered to the database with the CREATE ASSEMBLY command. If you successfully ran the above CREATE ASSEMBLY statement, IBMDataDB2iSeries should appear in the list. Select this assembly and click OK. Your project code can now reference this library.

Stored Procedure Example

To create a .NET stored procedure, choose Add Stored Procedure from the Project menu and assign a name. VS will create stub code for the stored procedure including default framework references, an attribute indicating that the code will be used as a stored procedure, and a shared (aka static) method with the same name as the stored procedure. Simply fill in .NET logic in the stub code and then build and deploy the project. VS will take care of registering the stored procedure in SQL Server!

Stored procedures can do many things: execute logic, accept and return parameters, and return one or more result sets. Figure 1 shows sample stored procedure spDB2Demo that demonstrates these features. This procedure issues a basic SELECT query to DB2 and passes the DB2 result set back to SQL Server (the caller will not know that .NET code is actually going to DB2 to get the results). It also features an output parameter that returns the number of rows retrieved from DB2.

Imports System
Imports System.Data
Imports System.Data.Sql
Imports System.Data.SqlClient
Imports System.Data.SqlTypes
Imports Microsoft.SqlServer.Server
'
' NOTES:
'
' This project's assembly (because it uses the "UNSAFE"
' DB2 for iSeries assembly) must also be declared as unsafe
'
' You must register the DB2 UDB for iSeries .NET managed
' provider with the CREATE ASSEMBLY command
'
' CREATE ASSEMBLY IBMDataDB2
' FROM 'C:Program FilesIBMClient AccessIBM.Data.DB2.iSeries.dll'
' WITH PERMISSION_SET = unsafe;
'
' Further, once the assembly is available, you must add a
' reference to it in the .NET project so that it can be
' used in the code.
'
Imports IBM.Data.DB2.iSeries
'
' CLR Stored Procedure example that returns a resultset
' and an output parameter.
'
Partial Public Class StoredProcedures
    <Microsoft.SqlServer.Server.SqlProcedure()> _
    Public Shared Sub SPDB2Demo(ByRef parmRowCount As SqlInt32)
        '
        ' Number of rows returned
        '
        Dim intRowCount As Integer = 0
        '
        ' The SQL MetaData objects are used to define the attributes
        ' of the columns being returned in the result set.  In this
        ' example, the column definitions here match the column
        ' definitions in the DB2 QCUSTCDT table.
        '
        Dim sqlMd(10) As SqlMetaData
        sqlMd(0) = New SqlMetaData("CUSNUM", SqlDbType.Decimal, 6, 0)
        sqlMd(1) = New SqlMetaData("LSTNAM", SqlDbType.Char, 8)
        sqlMd(2) = New SqlMetaData("INIT", SqlDbType.Char, 3)
        sqlMd(3) = New SqlMetaData("STREET", SqlDbType.Char, 13)
        sqlMd(4) = New SqlMetaData("CITY", SqlDbType.Char, 6)
        sqlMd(5) = New SqlMetaData("STATE", SqlDbType.Char, 2)
        sqlMd(6) = New SqlMetaData("ZIPCOD", SqlDbType.Decimal, 5, 0)
        sqlMd(7) = New SqlMetaData("CDTLMT", SqlDbType.Decimal, 4, 0)
        sqlMd(8) = New SqlMetaData("CHGCOD", SqlDbType.Decimal, 1, 0)
        sqlMd(9) = New SqlMetaData("BALDUE", SqlDbType.Decimal, 6, 2)
        sqlMd(10) = New SqlMetaData("CDTDUE", SqlDbType.Decimal, 6, 2)
        '
        ' The column information is passed to an SQLDataRecord
        ' which will define the result set as a whole
        '
        Dim sqlR As SqlDataRecord = New SqlDataRecord(sqlMd)
        '
        ' The SqlContext object is used to identify the caller's
        ' context (or connection.)
        '
        ' Result sets are passed back to SQL Server via a 
        ' database connection.  Since this code will run
        ' in the context of an existing SQL Server connection
        ' we'll just use the existing connection.
        '
        ' Pass the result set structure to SQL Server
        '
        SqlContext.Pipe.SendResultsStart(sqlR)
        '
        ' Load the result set with DB2 data
        '
        Try
            '
            ' Connect to the iSeries, System i5, AS/400
            '
            Dim connDB2 As iDB2Connection = New 

iDB2Connection("DATASOURCE=MyAS400;USERID=userid;PASSWORD=password")
            connDB2.Open()
            '
            ' Execute a SELECT statement and retrieve the results
            ' in a data reader
            '
            Dim cmdDB2 As iDB2Command = connDB2.CreateCommand()
            cmdDB2.CommandText = "Select * From QIWS.QCUSTCDT"
            Dim drDB2 As iDB2DataReader = cmdDB2.ExecuteReader()
            '
            ' Populate result set rows (in this example, the
            ' stored procedure result sets is a representation
            ' of the data in the QIWS/QCUSTCDT sample table
            ' on the iSeries.)
            '
            While drDB2.Read
                sqlR.SetDecimal(0, drDB2.GetiDB2Decimal(0))
                sqlR.SetString(1, drDB2.GetString(1))
                sqlR.SetString(2, drDB2.GetString(2))
                sqlR.SetString(3, drDB2.GetString(3))
                sqlR.SetString(4, drDB2.GetString(4))
                sqlR.SetString(5, drDB2.GetString(5))
                sqlR.SetDecimal(6, drDB2.GetiDB2Decimal(6))
                sqlR.SetDecimal(7, drDB2.GetiDB2Decimal(7))
                sqlR.SetDecimal(8, drDB2.GetiDB2Decimal(8))
                sqlR.SetDecimal(9, drDB2.GetiDB2Decimal(9))
                sqlR.SetDecimal(10, drDB2.GetiDB2Decimal(10))
                SqlContext.Pipe.SendResultsRow(sqlR)
                intRowCount += 1
            End While
            '
            ' Close the DB2 Connection and pass the number 
            ' of rows retrieved as an output variable
            '
            drDB2.Close()
            parmRowCount = intRowCount

#If SendSecondResult Then
            '
            ' Signal end of the result set
            '
            SqlContext.Pipe.SendResultsEnd()
            '
            ' Theoretically, we can create a second result set
            ' and return it
            '
            Dim sqlResultSet2(2) As SqlMetaData
            sqlResultSet2(0) = New SqlMetaData("Field1", SqlDbType.Char, 10)
            sqlResultSet2(1) = New SqlMetaData("Field2", SqlDbType.Char, 50)
            sqlResultSet2(2) = New SqlMetaData("Field3", SqlDbType.Char, 20)
            sqlR = New SqlDataRecord(sqlResultSet2)

            SqlContext.Pipe.SendResultsStart(sqlR)
            drDB2 = cmdDB2.ExecuteReader()
            '
            ' Populate result set rows
            '
            While drDB2.Read
                sqlR.SetString(0, drDB2.GetString(0))
                sqlR.SetString(1, drDB2.GetString(1))
                sqlR.SetString(2, drDB2.GetString(2))
                SqlContext.Pipe.SendResultsRow(sqlR)
            End While
            drDB2.Close()
#End If
            cmdDB2.Dispose()
            connDB2.Close()
            connDB2.Dispose()
        Catch ex As iDB2Exception

            '
            ' Execptions can be handled in almost any way
            ' For simpilicty, the error message is sent 
            ' back through a character variable for ease
            ' of debugging.
            '
            sqlR.SetString(1, ex.Message)
            SqlContext.Pipe.SendResultsRow(sqlR)
        End Try
        '
        ' Signal end of the result set
        '
        SqlContext.Pipe.SendResultsEnd()

    End Sub
End Class

Figure 1: Stored procedures can execute logic, accept and return parameters, and return one or more result sets.

Adding parameters to a .NET stored procedure is as easy as adding parameters to the method's signature. Passing parameters by value (ByVal keyword) causes SQL Server to recognize these parameters as input-only. Passing parameters by reference causes SQL Server to treat them as input/output. When you change your method's parameter signature, the stored procedure signature registered in the database will change as well when the latest project changes are deployed to SQL Server. Parameters passed between SQL Server and .NET code should use data types available in the System.Data.SqlTypes library to allow for things like null compatibility.

Our next task is making the .NET code return a result set to SQL Server. Passing back information as a result set involves three main steps: opening a SQL Server connection, defining the result set's metadata, and writing the data one row at a time. (Incidentally, there are more ways to pass back information.)

Generally, since this CLR code is running in the context of a database connection, the existing connection is used as the pipe for returning results to SQL Server. Access to the existing connection's context is provided by the SqlContext object.

To indicate the structure of the result set, create an array of SqlMetaData objects. Each element of the array corresponds to a column name and its attributes in the result set. Next, create a variable with the type of Microsoft.SqlServer.Server.SqlDataRecord and pass the SqlMetaData array to its constructor. This record object will be passed to SQL Server via the SqlContext.Pipe.SendResultsStart and indicates to SQL Server that result set data will be coming in the specified format.

At this point in the sample, a DB2 data reader object is opened and iterated. Each row from DB2 is copied column by column into the data record object and then sent to SQL Server using the SqlContext.Pipe.SendResultsRow method. Oddly enough, this is very similar to how external DB2 user-defined table functions work. After all the rows are processed, the SqlContext.Pipe.SendResultsEnd method is called to let SQL Server know the end of the result set has come.

As illustrated in the sample code, additional result sets can be returned by repeating the process with a new or existing data record definition and executing the SqlContext.Pipe.SendResultsStart method.

When finished, sample T-SQL code to run the stored procedure will look like this:

Declare @NoRows Int
Exec SPDB2Demo @NoRows OUTPUT
Print @NoRows

While this stored procedure is a somewhat trivial example of getting data from DB2, the point is that coding a stored procedure in a .NET language allows almost any conceivable programming function to be done through SQL Server, including the most difficult data integration tasks.

Table-Valued User-Defined Function Example

A table-valued user-defined function can be thought of as a "virtual table." Instead of querying data from a database table, table function code supplies the database server data in a tabular format. Similar to stored procedures, table functions can receive input parameters and perform logic, but they return only a single result set and have no output parameter capability.

In the next example, we'll code a CLR table function to get its data from DB2. When finished, the following T-SQL statement will get its data from the DB2 QIWS/QCUSTCDT table on the iSeries:

select * from dbo.DB2QCustCdt()

Didn't we already do this with the stored procedure? Yes, but it's important to realize that table functions have advantages over stored procedures. In particular, if a result set needs to participate in a join to another table or be sorted dynamically with an Order By, then a table function is usually a better tool. In other words, the result set of a stored procedure can't be modified or easily used in a subsequent query, but the result of a table function can.

To create your own .NET coded table function in Visual Studio, choose Add User-Defined Function from the Project menu. Unfortunately, the supplied template code is for a scalar (single-value) user-defined function, and many modifications have to be done to convert it to a table function. Notice that stub code is generated and that the defined method name matches the object name of the table function in SQL Server (once it's deployed). Additionally, adding ByVal parameter references to the method signature equates to adding input parameters in the table function.

Figure 2 contains function DB2QCustCdt. The SqlFunction attribute is specified along with several properties needed to inform SQL Server of how the table function will be implemented. The table definition property, for instance, consists of the column names and SQL Server data types that the table function will return when executed. See the SQL Server help for a list of all the available properties and their roles.

Imports System
Imports System.Data
Imports System.Data.Sql
Imports System.Data.SqlTypes
Imports Microsoft.SqlServer.Server
Imports IBM.Data.DB2.iSeries            
'.NET Managed Provider for iSeries
Partial Public Class UserDefinedFunctions
    '
    ' A shared method with the same name as the 
    ' table valued function is required as an
    ' entry point to the SQL routine.  This
    ' method must return an IEnumerable
    ' object.
    '
    ' The SqlFunction attribute is used to define the
    ' characteristics of the function. This information
    ' allows Visual Studio to issue the appropriate
    ' CREATE FUNCTION or ALTER FUNCTION statement to 
    ' SQL Server when the project is deployed.
    '
    '
    ' The FillRowMethodName must be unique within the class
    '
    <SqlFunction(FillRowMethodName:="FillRowQCustCdt", _
                 IsDeterministic:=False, _
                 IsPrecise:=True, _
                 TableDefinition:="CUSNUM NUMERIC(6, 0), " + _
                                  "LSTNAM NCHAR(8), " + _
                                  "INIT   NCHAR(3), " + _
                                  "STREET NCHAR(13), " + _
                                  "CITY   NCHAR(6), " + _
                                  "STATE  NCHAR(2), " + _
                                  "ZIPCOD NUMERIC(5, 0), " + _
                                  "CDTLMT NUMERIC(4, 0), " + _
                                  "CHGCOD NUMERIC(1, 0), " + _
                                  "BALDUE NUMERIC(6, 2), " + _
                                  "CDTDUE NUMERIC(6, 2)")> _
    Public Shared Function DB2QCustCdt() As IEnumerable
        '
        ' Don't forget to add error checking
        ' 
        ' Fill in your system name, user id & password
        ' (of course you normally wouldn't store hard coded
        '  credentials in this manner)
        '
        ' This sample requires the DB2 for iSeries .NET managed provider
        ' (available with iSeries Access V5R3)
        '
        ' 1) Connect to the iSeries, System i5, AS/400
        '
        Dim connDB2 As iDB2Connection = New 

iDB2Connection("DATASOURCE=My_iSeries;USERID=userid;PASSWORD=password")
        connDB2.Open()
        '
        ' 2) Execute an SQL command and return the results as a data reader
        '
        Dim cmdDB2 As iDB2Command = connDB2.CreateCommand()
        cmdDB2.CommandText = "Select * From QIWS.QCUSTCDT"
        Dim drDB2 As iDB2DataReader = 

cmdDB2.ExecuteReader(CommandBehavior.CloseConnection)
        Return drDB2

    End Function
    '
    ' This method is called frequently as the IEnumerable object
    ' returned from DB2QCustCdt is enumerated. Each enumeration
    ' represents a row to be returned to SQL Server.
    '
    Public Shared Sub FillRowQCustCdt( _
                       ByVal row As Object, _
                       ByRef CUSNUM As SqlDecimal, _
                       ByRef LSTNAM As SqlString, _
                       ByRef INIT As SqlString, _
                       ByRef STREET As SqlString, _
                       ByRef CITY As SqlString, _
                       ByRef STATE As SqlString, _
                       ByRef ZIPCOD As SqlDecimal, _
                       ByRef CDTLMT As SqlDecimal, _
                       ByRef CHGCOD As SqlDecimal, _
                       ByRef BALDUE As SqlDecimal, _
                       ByRef CDTDUE As SqlDecimal)
        '
        ' SQL Reader objects pass type System.Data.Common.DbDataRecord
        ' in the row object
        '
        Dim columns As Common.DbDataRecord = CType(row, Common.DbDataRecord)
        CUSNUM = columns.GetDecimal(0)
        LSTNAM = columns.GetString(1)
        INIT = columns.GetString(2)
        STREET = columns.GetString(3)
        CITY = columns.GetString(4)
        STATE = columns.GetString(5)
        ZIPCOD = columns.GetDecimal(6)
        CDTLMT = columns.GetDecimal(7)
        CHGCOD = columns.GetDecimal(8)
        BALDUE = columns.GetDecimal(9)
        CDTDUE = columns.GetDecimal(10)
    End Sub
End Class

Figure 2: In function DB2QCustCdt, the SqlFunction attribute is specified along with several properties needed to inform SQL Server of how the table function will be implemented.

Notice that method DB2QCustCdt returns an object that implements the IEnumerable interface. This is a requirement for all table functions written in .NET code. Many .NET classes use this important interface, including arrays, collections, and data readers. When SQL Server gets a request to run the DB2QCustCdt table function, it will call the DB2QCustCdt method and expect to retrieve an "enumerable" object. Each enumerated object represents a row to be returned in the result set. In this case, the sample code will return an iDB2DataReader.

When SQL Server enumerates (i.e., processes item by item) each row returned by the data reader, it will need a little more help to map data from the IEnumerable object to parameters that represent the table function's columns. The FillRowMethodName property of the SqlFunction attribute defines the method SQL Server will call when breaking up each enumerated row object into distinct data columns. The signature of the method will be a row object (as an input parameter) followed by an output parameter for each column in the table function. Please note that the project will not deploy if the signature for this FillRowMethodName method does not match the table columns defined in the TableDefinition property.

In this example, method FillRowQCustCdt will be called for each row returned by the data reader. In the case of the data reader class, the row parameter will be an object of type System.Data.Common.DbDataRecord, which is fortunate, because it offers methods to extract individual data columns from the DataReader. Each output parameter is filled in from the data reader before the method ends. Each call to FillRowQCustCdt represents one row being parsed and returned to SQL Server.

A Step Further

Figure 3 shows an enhanced example of the table function. It calls a DB2 stored procedure with a criteria parameter instead of a simple Select. This figure contains the DB2 stored procedure, the .NET code, and T-SQL usage examples.

-- Enhanced CLR UDTF example using
-- DB2 stored procedure and
-- parameterized criteria
--
--
-- Here is how the CLR function is
-- used in T-SQL to return DB2
-- data.
--
select * from dbo.DB2QCustCdt('BALDUE>0')


--
-- DB2 Stored Procedure Definition
-- 
-- Build the SQL statement dynamically
--
Create Procedure xxxxx/spCustList(parmWhere In VarChar(512))  
Language SQL                                               
Dynamic Result Sets 1                                      
Set Option Commit=*None,DynUsrPrf=*Owner
Begin                                                      
    Declare SQLText VarChar(1024) Default '' Not Null;     
    Declare CustomerList Cursor With Return to Client      
        For CustomerListStmt;                              
                                                           
    Set SQLText='Select * From QIWS/QCustCdt ';            
    If parmWhere>'' Then                                   
        If UCase(Left(LTrim(parmWhere),5))='WHERE' Then    
            Set SQLText=SQLText||parmWhere;                
        Else                                               
            Set SQLText=SQLText||' Where '||parmWhere;     
        End If;                                            
    End If;                                                
                                                 
    Prepare CustomerListStmt From SQLText;       
                                                 
    Open CustomerList;                           
End            


--
-- Modified CLR Code for stored procedure 
-- access instead of simple SELECT
--
Imports System
Imports System.Data
Imports System.Data.Sql
Imports System.Data.SqlTypes
Imports Microsoft.SqlServer.Server
Imports IBM.Data.DB2.iSeries

Partial Public Class UserDefinedFunctions
    '
    ' The FillRowMethodName must be unique within the assembly
    '
    <SqlFunction(FillRowMethodName:="FillRowQCustCdtSP", _
                 IsDeterministic:=False, _
                 IsPrecise:=True, _
                 TableDefinition:="CUSNUM NUMERIC(6, 0), " + _
                                  "LSTNAM NCHAR(8), " + _
                                  "INIT   NCHAR(3), " + _
                                  "STREET NCHAR(13), " + _
                                  "CITY   NCHAR(6), " + _
                                  "STATE  NCHAR(2), " + _
                                  "ZIPCOD NUMERIC(5, 0), " + _
                                  "CDTLMT NUMERIC(4, 0), " + _
                                  "CHGCOD NUMERIC(1, 0), " + _
                                  "BALDUE NUMERIC(6, 2), " + _
                                  "CDTDUE NUMERIC(6, 2)")> _
    Public Shared Function DB2QCustCdtSP(ByVal parmWhere As SqlString) As IEnumerable
        '
        ' Add error checking
        ' 
        ' Fill in your system name, user id & password
        '
        ' This sample requires the DB2 for iSeries .NET managed provider
        ' (available with iSeries Access V5R3)
        '
        Dim connDB2 As iDB2Connection = New 

iDB2Connection("DATASOURCE=My_AS400;USERID=user;PASSWORD=password")
        Dim cmdDB2 As iDB2Command = connDB2.CreateCommand()
        connDB2.Open()
        ' 
        ' Replace your schema name in the stored procedure call
        '
        cmdDB2.CommandText = "Call xxxxx.spCustList('" + parmWhere.ToString() + "')"
        cmdDB2.CommandType = CommandType.Text

        Dim drDB2 As iDB2DataReader = 

cmdDB2.ExecuteReader(CommandBehavior.CloseConnection)
        Return drDB2
    End Function

    Public Shared Sub FillRowQCustCdtSP( _
                       ByVal row As Object, _
                       ByRef CUSNUM As SqlDecimal, _
                       ByRef LSTNAM As SqlString, _
                       ByRef INIT As SqlString, _
                       ByRef STREET As SqlString, _
                       ByRef CITY As SqlString, _
                       ByRef STATE As SqlString, _
                       ByRef ZIPCOD As SqlDecimal, _
                       ByRef CDTLMT As SqlDecimal, _
                       ByRef CHGCOD As SqlDecimal, _
                       ByRef BALDUE As SqlDecimal, _
                       ByRef CDTDUE As SqlDecimal)
        '
        ' SQL Reader objects return a type of System.Data.Common.DbDataRecord
        ' 
        Dim columns As Common.DbDataRecord = CType(row, Common.DbDataRecord)
        CUSNUM = columns.GetDecimal(0)          'CType(columns(0), SqlDecimal)
        LSTNAM = columns.GetString(1)           'CType(columns(1), SqlString)
        INIT = columns.GetString(2)             'CType(columns(2), SqlString)
        STREET = columns.GetString(3)           'CType(columns(3), SqlString)
        CITY = columns.GetString(4)             'CType(columns(4), SqlString)
        STATE = columns.GetString(5)            'CType(columns(5), SqlString)
        ZIPCOD = columns.GetDecimal(6)          'CType(columns(6), SqlDecimal)
        CDTLMT = columns.GetDecimal(7)          'CType(columns(7), SqlDecimal)
        CHGCOD = columns.GetDecimal(8)          'CType(columns(8), SqlDecimal)
        BALDUE = columns.GetDecimal(9)          'CType(columns(9), SqlDecimal)
        CDTDUE = columns.GetDecimal(10)         'CType(columns(10), SqlDecimal)
    End Sub
End Class

Figure 3: This enhanced example of the table function calls a DB2 stored procedure with a criteria parameter instead of a simple Select.

Data Type Cross- Reference

One thing to be aware of is the need for data type compatibility between .NET, DB2, and SQL Server. table below shows how to map DB2 data types to the equivalent .NET types and the resulting SQL Server type:

Data Type Compatibility Between .NET, DB2, and SQL Server
DB2 Data Type
.NET SQL Data Type
SQL Server data type
CHAR
SqlString
NCHAR
VARCHAR
SqlString
NVARCHAR
INTEGER
SqlInt32
INTEGER
SMALLINT
SqlInt16
SMALLINT
BIGINT
SqlInt64
BIGINT
DECIMAL
SqlDecimal
DECIMAL
NUMERIC
SqlDecimal
DECIMAL (or NUMERIC)
DATE
SqlDateTime
DATETIME
TIMESTAMP
SqlDateTime
DATETIME
DOUBLE
SqlDouble
FLOAT(53)


Notice that the DB2 FLOAT and TIME types are missing. I found DB2 Float to be problematic unless I mapped it to SqlDouble and then to Float(53) in SQL Server (although the expected type to use is REAL). Also, I had problems with the DB2 TIME data type. Mapping the TIME type to SqlDateTime implicitly converts to a time stamp without a date portion (which means the date portion is '01/01/0001'). An error occurs because, unlike DB2 time stamps, SQL Server's DATETIME cannot store this date value. It would probably be best to bring the TIME type into .NET as a string and then cast it back to a DATETIME value later.

Deploying the Project

When your .NET routines have been written, press F5 to deploy the project to SQL Server (or choose Build and then Deploy from the VS Build menu). The deployment will register the project's assembly with SQL Server. Also, the appropriate stored procedure and table function definitions based on the method signatures in the code will be registered in the database. If signatures change, VS will alter the SQL routines appropriately! With all the .NET coding required, at least we don't have to manually write CREATE PROCEDURE and CREATE FUNCTION statements!

.NET Routines or Linked Server Access?

Writing .NET routines requires more work than writing linked server routines. When deciding to use .NET code vs. a linked server, consider whether .NET offers a function (custom business logic, etc.) that is not accessible to the linked server. For instance, you may need to join data from a remote Web service with DB2 data before passing it to SQL Server—something that .NET will allow you to do.

However, this article just touches on the capabilities of CLR routines with respect to real-time DB2 integration. Aggregates and triggers can also be written in .NET code. The granularity and flexibility afforded to the programmer when writing .NET routines is unsurpassed. If your company uses any of the myriad of products that will run on SQL Server 2005, you now have additional tools to create real-time, seamless integration routines with your flagship iSeries applications...and all with standard tools!

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.