Sidebar

Examining Business Rules in DB2

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

This article focuses on the constraint rules as, in most businesses, data often must adhere to a certain set of rules and restrictions.

 

Editor's note: This article is an excerpt from the book DB2 10.1/10.5 for Linux, UNIX, and Windows Database Administration (Exams 611 and 311): Certification Study Guide.

 

A business rule is a statement that defines or constrains some characteristics of the business. According to the Business Rules Group (www.businessrulesgroup.org) organization, a business rule can belong to one of the following:

  • Definitions of business terms (entity rules). An entity is a collection of information about things that are important to the business and worthy of capture. A business term has a specific meaning for a business in some designated context. This describes how people think about things and categorizes them based on behavior and dependency.
  • Facts that relate terms to each other (relationship and cardinality rules). These express relationships between terms and define behaviors in specific situations.
  • Constraints. Every organization constrains behavior in one way or another to prevent an action from taking place.
  • Derivations. These define how organizations can transform knowledge in one form into another to derive facts or inferences.

This section focuses on the constraint rules as, in most businesses, data often must adhere to a certain set of rules and restrictions. For example, companies typically have a specific format and numbering sequence they use when generating purchase orders. Constraints allow you to place the logic needed to enforce such business rules directly in the database, rather than in applications that work with the database. Essentially, constraints are rules that govern how data values can be added to a table, as well as how those values can be modified once they have been added.

 

The following types of constraints are:

  • NOT NULL
  • DEFAULT
  • CHECK
  • UNIQUE
  • Referential integrity
  • Informational

 

Constraints are usually defined during table creation; however, constraints can also be added to existing tables by using the ALTER TABLE SQL statement.

 

Not Null Constraints

With DB2, you use NULL values (not to be confused with empty strings) to represent missing or unknown data or states. And by default, every column in a table will accept a NULL value. This allows you to add records to a table when not all the values that pertain to the record are known. However, at times, this behavior might be unacceptable (for example, a tax identification number might be required for every employee who works for a company). When such a situation arises, using the NOT NULL constraint can ensure that a particular column in a base table is never assigned a NULL value; once you have defined the NOT NULL constraint for a column, any operation that attempts to place a NULL value in that column will fail. Figure 4.1 illustrates how to use the NOT NULL constraint to avoid inserting a NULL value.

 

101415MohanFigure4.1 

Figure 4.1: How the NOT NULL constraint prevents NULL values

 

Because NOT NULL constraints are associated with a specific column in a base table, they are usually defined during the table creation process or during the table alter process. The DB2 commands and the results for the above scenario are as follows:

 

CREATE TABLE employee

     (      EMPID    CHAR(3),

            NAME      VARCHAR(25),

            TAX_ID     INTEGER NOT NULL)

DB20000I The SQL command completed successfully.

 

INSERT INTO employee VALUES

     (001,'JAGGER, MICK', 591075),

     (002,'RICHARDS, KEITH', 234667),

     (003,'WOOD, RONNIE', 257423),

     (004,'WATTS, CHARLIE', 194894),

     (005,'WYMAN, BILL', 691647);

DB20000I The SQL command completed successfully.

 

INSERT INTO employee VALUES (006,'JONES, BRIAN', NULL)

DB21034E The command was processed as an SQL statement because it was not a valid Command Line Processor command. During SQL processing it returned: SQL0407N Assignment of a NULL value to a NOT NULL column "TBSPACEID=2, TABLEID=258, COLNO=2" is not allowed. SQLSTATE=23502

 

If you are wondering what the TBSPACEID=2, TABLEID=258, and COLNO=2 are, they are all the metadata information about the table and the column in the system catalog table. You can query the system catalog tables or views by using a command something like:

 

SELECT

     VARCHAR (A.TABNAME, 10) TABNAME,

     VARCHAR (A.COLNAME, 10) COLNAME,

     A.COLNO, A.NULLS, B.TABLEID, B.TBSPACEID,

     VARCHAR (B.TBSPACE, 12) TBSPACE

   FROM SYSCAT.COLUMNS A, SYSCAT.TABLES B

   WHERE A.TABNAME=B.TABNAME AND A.COLNO=2 AND A.TABNAME='EMPLOYEE';

 

TABNAME   COLNAME   COLNO NULLS TABLEID TBSPACEID TBSPACE

---------- ---------- ------ ----- ------- --------- ------------

EMPLOYEE   TAX_ID         2 N         258         2 USERSPACE1

 

Default Constraints

Just as there are times when it is objectionable to accept a NULL value, there may be times when it is desirable to have the system provide a specific value for you (for example, you might want to automatically assign the current date to a particular column whenever a new record is added to a table). In these situations, you can use the DEFAULT constraint to ensure that a particular column in a base table is assigned a predefined value (unless that value is overridden) each time a record is added to the table. The predefined value provided can be NULL (if the NOT NULL constraint has not been defined for the column), a user-supplied value compatible with the column’s data type, or a value furnished by the DB2 database manager. Table 4.1 shows the default values that the DB2 database manager can provide for the various DB2 data types.

 

Table 4.1: DB2 default values

Column Data Type

Default Value Provided

Small integer

(SMALLINT)

0

Integer

(INTEGER or INT)

0

Decimal

(DECIMAL, DEC, NUMERIC, or NUM)

0

Single-precision floating-point

(REAL or FLOAT)

0

Double-precision floating-point

(DOUBLE, DOUBLE PRECISION, or FLOAT)

0

Fixed-length character string

(CHARACTER or CHAR)

A string of blank characters

Varying-length character string

(CHARACTER VARYING, CHAR VARYING, or VARCHAR)

A zero-length string

Long varying-length character string

(LONG VARCHAR)

A zero-length string

Fixed-length double-byte character string

(GRAPHIC)

A string of blank characters

Varying-length double-byte character string

(VARGRAPHIC)

A zero-length string

Long varying-length double-byte character string

(LONG VARGRAPHIC)

A zero-length string

Date

(DATE)

The system date at the time the record is added to the table (when a date column is added to an existing table, existing rows are assigned the date January 01, 0001)

Time

(TIME)

The system time at the time the record is added to the table (when a time column is added to an existing table, existing rows are assigned the time 00:00:00)

Timestamp

(TIMESTAMP)

The system date and time (including microseconds) at the time the record is added to the table (when a timestamp column is added to an existing table, existing rows are assigned a timestamp that corresponds to January 01, 0001 – 00:00:00.000000)

Binary large object

(BLOB)

A zero-length string

Character large object

(CLOB)

A zero-length string

Double-byte character large object

(DBCLOB)

A zero-length string

XML document

(XML)

Not applicable

Any distinct user-defined data type

The default value provided for the built-in data type that the distinct user-defined data type is based on (typecast to the distinct user-defined data type)

Adapted from Table 13 on page 140 of the DB2 SQL Reference, Volume 2 manual

 

Figure 4.2 illustrates how to use the DEFAULT constraint to insert a default value when no data is supplied for the default column.

 

101415MohanFigure4.2

Figure 4.2: How to use the DEFAULT constraint to provide default data values

 

Like NOT NULL constraints, the DEFAULT constraints are associated with a specific column in a base table and are usually defined during the table creation process or changed during the table alter process. The DB2 commands and the results for the above scenario are something like the following:

 

CREATE TABLE employee

     (    EMPID      CHAR(3),

          NAME        VARCHAR(25),

          TAX_ID     INTEGER WITH DEFAULT 999999)

DB20000I The SQL command completed successfully.

 

INSERT INTO employee VALUES

     (001,'JAGGER, MICK', 591075),

     (002,'RICHARDS, KEITH', 234667),

     (003,'WOOD, RONNIE', 257423),

     (004,'WATTS, CHARLIE', 194894),

     (005,'WYMAN, BILL', 691647);

DB20000I The SQL command completed successfully.

 

INSERT INTO employee (EMPID, NAME) VALUES (006,'JONES, BRIAN')

DB20000I The SQL command completed successfully.

 

SELECT * FROM employee

 

EMPID NAME                     TAX_ID

----- ------------------------- -----------

1     JAGGER, MICK                   591075

2     RICHARDS, KEITH               234667

3     WOOD, RONNIE                  257423

4     WATTS, CHARLIE                 194894

5     WYMAN, BILL                   691647

6     JONES, BRIAN                   999999

 

Check Constraints

Sometimes, it is desirable to control which values will be accepted for a particular item and which values will not (for example, a company might decide that all nonexempt employees must be paid, at a minimum, the federal minimum wage). When this is the case, you can directly incorporate the logic needed to determine whether a value is acceptable into the data-entry program used to collect the data.

 

A better way to achieve the same objective is by defining a CHECK constraint for the column in the base table that is to receive the data value. You can use a CHECK constraint (also known as a table check constraint) to ensure that a particular column in a base table is never assigned an unacceptable value—once you have defined a CHECK constraint for a column, any operation that attempts to place a value in that column that does not meet specific criteria will fail.

 

CHECK constraints consist of one or more predicates (which are connected by the keywords AND or OR) collectively known as the check condition. This check condition is compared with the data values you provide, and the result of this comparison is returned as the value TRUE, FALSE, or Unknown. If the CHECK constraint returns the value TRUE, the value is acceptable, so it is added to the column. If, however, the CHECK constraint returns the value FALSE or Unknown, the operation attempting to place the value in the column fails, and all changes made by that operation are backed out. However, it is important to note that when the results of a particular operation are rolled back because of a CHECK constraint violation, the transaction that invoked that operation is not terminated, and other operations within that transaction are unaffected. Figure 4.3 illustrates how to use a simple CHECK constraint to control which data values are acceptable by a column.

 

101415MohanFigure4.3

Figure 4.3: How to use the CHECK constraint to control what data values are acceptable

 

Like NOT NULL constraints and DEFAULT constraints, CHECK constraints are associated with a specific column in a base table and are usually defined during the table creation process or during the table alter process. The DB2 commands and the results for the above said scenario look something like this:

 

CREATE TABLE employee

     (     EMPID      CHAR(3),

          NAME        VARCHAR(25),

          TAX_ID     INTEGER CHECK (TAX_ID > 1000))

DB20000I The SQL command completed successfully.

 

INSERT INTO employee VALUES

     (001,'JAGGER, MICK', 591075),

     (002,'RICHARDS, KEITH', 234667),

     (003,'WOOD, RONNIE', 257423),

     (004,'WATTS, CHARLIE', 194894),

     (005,'WYMAN, BILL', 691647);

DB20000I The SQL command completed successfully.

 

INSERT INTO employee (EMPID, NAME, TAX_ID) VALUES (006,'JONES, BRIAN', 90)

DB21034E The command was processed as an SQL statement because it was not a valid Command Line Processor command. During SQL processing it returned: SQL0545N The requested operation is not allowed because a row does not satisfy the check constraint "DATAMARTS.EMPLOYEE.SQL140717193343960". SQLSTATE=23513

 

You can query the SYSIBM.CHECK_CONSTRAINTS system catalog table to capture the CHECK constraint information, as follows:

 

SELECT

     VARCHAR(CONSTRAINT_CATALOG,10)   CONSTRAINT_CATALOG,

     VARCHAR(CONSTRAINT_NAME,30)       CONSTRAINT_NAME,

     VARCHAR(CHECK_CLAUSE,40)         CHECK_CLAUSE

   FROM SYSIBM.CHECK_CONSTRAINTS

   WHERE

   CONSTRAINT_NAME='SQL140717193343960';

 

CONSTRAINT_CATALOG CONSTRAINT_NAME               CHECK_CLAUSE

------------------ ------------------------------ --------------------

SAMPLE             SQL140717193343960             TAX_ID > 1000

 

Unique Constraints

By default, records added to a base table can have the same values assigned to any of the columns any number of times. As long as the records stored in the table do not contain information that is not be duplicated, this kind of behavior is acceptable. However, sometimes certain pieces of information that make up a record must be unique (for example, if an employee identification number is assigned to each individual that works for a particular company, each number must be unique—two employees must never have the same employee identification number).

 

In these situations, you can use the UNIQUE constraint to ensure that the values you assign to one or more columns when a record is added to a base table are always unique. Once you have defined a UNIQUE constraint for one or more columns, any operation that attempts to place duplicate values in those columns will fail. Figure 4.4 illustrates how to use the UNIQUE constraint.

 

101415MohanFigure4.4

Figure 4.4: How to use the UNIQUE constraint to control the duplication of data values

 

Unlike NOT NULL constraints, DEFAULT constraints, and CHECK constraints, which can be associated with only a single column in a base table, UNIQUE constraints can be associated with either an individual column or a group of columns. However, each column in a base table can participate in only one UNIQUE constraint, regardless of how you group the columns. Like the other constraints, UNIQUE constraints are usually defined during the table creation process or during the table alter process. The DB2 commands and the results for the above scenario look something like this:

 

CREATE TABLE employee

     (     EMPID      CHAR(3)     NOT NULL UNIQUE,

           NAME        VARCHAR(25),

           TAX_ID     INTEGER)

DB20000I The SQL command completed successfully.

 

INSERT INTO employee VALUES

     (001,'JAGGER, MICK', 591075),

     (002,'RICHARDS, KEITH', 234667),

     (003,'WOOD, RONNIE', 257423),

     (004,'WATTS, CHARLIE', 194894),

     (005,'WYMAN, BILL', 691647);

DB20000I The SQL command completed successfully.

 

INSERT INTO employee

     (EMPID, NAME, TAX_ID) VALUES (005,'JONES, BRIAN', 463642)

DB21034E The command was processed as an SQL statement because it was not a valid Command Line Processor command. During SQL processing it returned: SQL0803N One or more values in the INSERT statement, UPDATE statement, or foreign key update caused by a DELETE statement are not valid because the primary key, unique constraint or unique index identified by "1" constrains table "DATAMARTS.EMPLOYEE" from having duplicate values for the index key. SQLSTATE=23505

 

Regardless of when you define a UNIQUE constraint, when you create it, the DB2 database manager checks to determine whether an index for the columns that the UNIQUE constraint refers to already exists. If so, that index is marked as unique and system required (when an index is marked as system required, it cannot be dropped without dropping the constraint on the base table). If not, an appropriate index is created and marked as unique and system required. This index will then enforce uniqueness whenever new records are added to the columns for which the unique constraint was defined. As with other constraints, you can verify the unique rule by querying the system catalog views:

 

SELECT

     VARCHAR (INDSCHEMA, 8)        INDSCHEMA,

     VARCHAR (INDNAME, 20)         INDNAME,

     VARCHAR (TABNAME, 10)        TABNAME,

     UNIQUERULE,

     SYSTEM_REQUIRED

   FROM SYSCAT.INDEXES

   WHERE

   TABNAME='EMPLOYEE';

 

INDSCHEMA INDNAME             TABNAME   UNIQUERULE SYSTEM_REQUIRED

--------- -------------------- ---------- ---------- ---------------

SYSIBM   SQL140717202520710   EMPLOYEE   U                       1

Because no valid index was present on the EMPLOYEE table for the EMPID column, the DB2 database manager created the index SQL140717202520710 and marked it as system required. To provide a better naming convention, it is advisable to create an index and associate the UNIQUE constraint with the earlier created index, something like this:

CREATE TABLE employee

     (     EMPID      CHAR(3)     NOT NULL,

           NAME        VARCHAR(25),

           TAX_ID     INTEGER)

DB20000I The SQL command completed successfully.

 

INSERT INTO employee VALUES

     (001,'JAGGER, MICK', 591075),

     (002,'RICHARDS, KEITH', 234667),

     (003, 'WOOD, RONNIE', 257423),

     (004,'WATTS, CHARLIE', 194894),

     (005,'WYMAN, BILL', 691647);

DB20000I The SQL command completed successfully.

 

CREATE INDEX ix1_employee ON employee

           (EMPID ASC) ALLOW REVERSE SCANS

DB20000I The SQL command completed successfully.

 

ALTER TABLE employee ADD CONSTRAINT U1_EMPLOYEE UNIQUE (EMPID)

SQL0598W Existing index "DATAMARTS.IX1_EMPLOYEE" is used as the index for the primary key or a unique key. SQLSTATE=01550

 

The DB2 database manager is using the DATAMARTS.IX1_EMPLOYEE index to build the UNIQUE constraint on the table. You can also verify the unique rule in the system catalog view, as follows:

 

SELECT

    VARCHAR (INDSCHEMA, 8)   INDSCHEMA,

     VARCHAR (INDNAME, 20)     INDNAME,

     VARCHAR (TABNAME, 10)    TABNAME,

     UNIQUERULE,

     SYSTEM_REQUIRED

FROM SYSCAT.INDEXES

   WHERE TABNAME='EMPLOYEE';

 

INDSCHEMA INDNAME             TABNAME   UNIQUERULE SYSTEM_REQUIRED

--------- -------------------- ---------- ---------- ---------------

DATAMARTS IX1_EMPLOYEE         EMPLOYEE  U                       1

 

A primary key, which we will look at next, is a special form of a UNIQUE constraint. Each table can contain only one primary key, and every column that defines a primary key must be assigned the NOT NULL constraint. In addition to ensuring that every record added to a table has some unique characteristic, primary keys allow tables to participate in referential constraints.

 

A table can have any number of UNIQUE constraints; however, a table cannot have more than one UNIQUE constraint defined on the same set of columns. Because UNIQUE constraints are enforced by indexes, all the limitations that apply to indexes (for example, a maximum of 64 columns with a combined length of 8,192 bytes is allowable; no column can have a large object, long character string data type) also apply to UNIQUE constraints.

 

Although a unique, system-required index can enforce a UNIQUE constraint, there is a distinction between defining a UNIQUE constraint and creating a unique index. Both enforce uniqueness, but a unique index allows NULL values and generally cannot be used in a referential constraint. A UNIQUE constraint, however, does not allow NULL values and can be referenced in a foreign key specification. (The value NULL means a column’s value is undefined and distinct from any other value, including other NULL values.)

 

Learn more with the book DB2 10.1/10.5 for Linux, UNIX, and Windows Database Administration (Exams 611 and 311): Certification Study Guide.

 

Mohankumar Saraswatipura

Mohankumar (Mohan) Saraswatipura works as a database solutions architect at Kronsys, Inc., focusing on IBM DB2, Linux, UNIX, and Windows solutions. Prior to his current position, he worked as a database solutions architect at Reckitt Benckiser Group, plc (UK), focusing on IBM Smart Analytics System 5600, Siebel, SQL Server, and SAP HANA solutions. 

Mohan is an IBM Champion (2010–2015) and a DB2’s Got Talent 2013 winner. He has written dozens of technical papers for IBM developerWorks and IBM Data magazine. He is an IBM-Certified DB2 Advanced Database Administrator, DB2 Application Developer, and DB2 Problem Determination Master. Mohan holds a Master’s of Technology (M Tech) degree in computer science and an Executive MBA (IT).


MC Press books written by Mohankumar Saraswatipura available now on the MC Press Bookstore.

DB2 10.1/10.5 for Linux, UNIX, and Windows Database Administration (Exams 611 and 311) DB2 10.1/10.5 for Linux, UNIX, and Windows Database Administration (Exams 611 and 311)
Master DB2 database administration and prepare for IBM's Exams 611 and 311: Certified Database Administrator.
List Price $134.95

Now On Sale

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.