21
Sat, Dec
3 New Articles

Examining Business Rules in 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.

 

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  • SB Profound WC 5536 Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation. Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects. The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY the one package that solves all your document design and printing challenges on all your platforms. Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. How can you be sure you won’t miss important system events? Automate your message center with the Robot Message Management Solution. Key features include:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing. Manage your reports with the Robot Report Management Solution. Key features include:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed. Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • Profound Logic Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: