24
Tue, Dec
0 New Articles

OmniFind, Part I: Add Sizzle to Your SQL with OmniFind Text Search Server for DB2 for i

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

With this text search server, you can locate documents that contain specific search strings in Excel, Word, PDF, PowerPoint, etc.

 

V6R1 of the IBM i operating system introduced many exciting new features, including numerous DB2 for i enhancements. One such enhancement that has flown somewhat under the radar is the IBM OmniFind Text Search Server for DB2 for i. This new product gives you the power to perform both basic and sophisticated text searching against data that is stored in your DB2 for i database tables. This article introduces this new technology and shows you how to set it up and use it in your environment.

 

Most companies have important business information stored in a variety of ways. Certainly, a good portion of this information is (or at least should be!) stored in your relational DB2 for i database. However, a wealth of vital data is often stored in other non-relational formats as well. Sales figures and charts in Excel spreadsheets, technical specifications in PDF files, job applicant resumes in Word documents, and strategic initiatives defined in PowerPoint presentations are all good examples of this. Wouldn't it be nice if all of this important, non-relational information could be consolidated in a single relational database? Well, actually it can. Ever since V4R4, you have had the ability to store these types of documents in Large Object Binary (LOB) columns in your database tables.

 

Hopefully, you're thinking that this notion of storing documents in your DB2 for i tables is a sound one. But in case you aren't yet convinced, consider the following advantages:

  • Organization: As mentioned previously, it is very common to have key business information stored in various non-database file formats, such as PDF documents. Rather than have this vital information strewn about various servers, file systems, and/or repositories, you can keep everything organized and centralized in one place.
  • Easy retrieval: When these data sources are stored in your database, you can leverage the power of SQL to quickly and easily retrieve the rows the documents are in. For example, use the product number to access both product inventory levels and the product specification PDF document.
  • Security: If your documents are scattered throughout your network, you may be exposing sensitive data to those who should not be accessing it. Lock down these documents by using the security features of both the IBM i operating system and DB2 for i. If this is a sensitive part number and access needs to be restricted to a privileged few, you can leverage object-level security and even row-level security (using SQL views) to lock it down.
  • A single version of the truth: A common problem in many companies is multiple versions of "the truth." That is, many versions of the same document can exist in various locations throughout your organization. Which version is the master? Because of its ability to centralize and provide easy yet secure access, the database is a logical choice for storing the master copy of your documents. It may not always be possible to enforce a single version of truth, but at the very least, you can establish company policies that require the master version be stored in the database. 
  • IBM OmniFind for searching: You can now use this text search server to quickly locate documents that contain specific search strings using advanced, linguistic search techniques.

Introducing OmniFind

The OmniFind Text Search Server is a new licensed program product (5733-OMF) that supports rapid text searches on data stored in DB2 text columns or in documents such as  PDF files. This provides the same advanced technology previously available on other DB2 family products. OmniFind provides a set of stored procedures to administer the environment, as well as two new integrated SQL functions (SCORE and CONTAINS) that can be used in your SQL statements to specify and execute text-based searches. This all means that OmniFind can be used to find text strings located both in your traditional character fields as well as in documents stored in columns with data types such as LOB. What's more, there's no additional cost for the OmniFind Text Search Server: The product can be ordered at no charge, and support for the product is part of your IBM i Software Maintenance agreement.

 

For example, let's say you have a DB2 for i table called INVENTORY that contains information about the all products you sell. Columns in the table include product_number, product_category, and product_name. In addition, for each product, you also have a PDF file stored in a LOB column named tech_spec_doc. Each PDF file contains all of the technical specification information for that particular product. Now, let's say that you have a requirement to find all products containing the string "headphones" in the PDF document. The "OmniFind-infused" SQL statement would look something like this:

 

SELECT product_number, product_name

FROM inventory

WHERE CONTAINS(tech_spec_doc, 'headphones') = 1

 

With this type of database design and integrated search capability, your DB2 for i database just became even more powerful!

OmniFind Text Indexes

The foundation of the OmniFind technology is the text indexes that are built over the data in the column. These text indexes can be created over a variety of data types that contain plain text, HTML, XML, or many different rich document types. A list of supported data types and rich document types is shown in the table below:

 

 

Supported DB2 Data Types and Document Format Types

Supported Column Data Types

Supported Document Format Types

•·         BINARY

•·         VARBINARY

•·         BLOB

•·         CHAR

•·         VARCHAR

•·         CLOB

•·         DBCLOB

•·         GRAPHIC

•·         VARGRAPHIC

 

•·         Plain text

•·         XML

•·         HTML

 

INSO Document Formats

•·         Adobe PDF

•·         Rich-Text Format (RTF)

•·         JustSystems Ichitaro

•·         Microsoft Excel

•·         Microsoft PowerPoint

•·         Microsoft Word

•·         Lotus 123

•·         Lotus Freelance

•·         Lotus WordPro

•·         OpenOffice 1.1 and 2.0

•·         OpenOffice Calc

•·         Quattro Pro

•·         StarOffice Calc

 

 

If you have experience with DB2 for i or any other relational database, you are probably well acquainted with database indexes and their many benefits. The traditional indexes by DB2 for i are binary radix and encoded vector index (EVI). They are used by the database engine for statistical information when formulating an optimal access plan and during the data access implementation. You have probably created many keyed logical files over your physical files and used these indexes in your RPG and COBOL programs. However, the text indexes used by OmniFind are not to be confused with these traditional database indexes. For starters, they are not part of the DB2 for i database. The text indexes actually reside on the text search server within the Integrated File System (IFS). This text search server is created during the product installation process and runs locally in the PASE environment. Once up and running, it communicates with the database via TCP/IP sockets. This environment is shown in Figure 1.

031109CobbFigure1.gif 

Figure 1: This is the text index architecture. (Click images to enlarge.)

 

Another key difference from their DB2 for i counterparts is that the text indexes are not automatically maintained. This is for performance reasons: updating a text-search index can be an extensive process, and keeping it synchronized with table changes automatically could have adverse effects on database performance. Consequently, different approaches to text-index maintenance can be implemented. I'll discuss these later in the article.

 

Lastly, these indexes cannot be journaled, are not protected by IBM i system-managed access-path protection (SMAPP), and are not backed up using the traditional object-level save commands, such as SAVOBJ and SAVLIB.

Administrative Stored Procedures

The administrative stored procedures are used to enable and disable text searching and to create, update, and drop text indexes. In this section, I will cover each of these stored procedures.

 

SYSTS_START: Start Text Search Support

Call the SYSTS_START stored procedure to start the text server and enable text search support. The text search server must be enabled for any OmniFind searches to complete successfully.

 

SYSTS_CREATE: Create a Text Index

The SYSTS_CREATE stored procedure creates a text index for the specified text column, thereby enabling text search indexing for that column. A call to this procedure results in the creation of an object in the IFS text server directory. It also performs the following tasks:

  • Creates a view with the same name as the text search index
  • Creates a staging table in the QSYS2 schema
  • Adds After-Insert, After-Update, and After-Delete triggers to the base table. (I'll explain the roles of these triggers later.)
  • Updates the system catalogs with information about the new index

 

Be aware that calling SYSTS_CREATE does not populate the text index.

 

An example of calling the SYSTS_CREATE procedure is shown below:

 

CALL SYSPROC.SYSTS_CREATE(
      'myschema',
      'resumes_indx',
      'myschema.resumes(applicant_resume)',
      'FORMAT INSO
       UPDATE FREQUENCY D(*) H(0) M(0)')

These are the parameters for this stored procedure:

  1. The schema of the text search index
  2. The name of the text search index
  3. The table and column specification for the document text source (the table schema, table name, and column name)
  4. Options


In our example, I specified a couple of values in the Options parameter. The first one is the format. This specifies the content type of the text documents that you intend to index and search. Possible values for this setting are these:

  • TEXT
  • HTML
  • XML
  • INSO: This value instructs the OmniFind Text Search Server to determine the format. The format can be any of the supported INSO document formats listed in the table shown at the beginning of this article.

 

Note: All of the documents in an indexed text column must be of the same format (TEXT, HTML, XML, or INSO). However, if you specify INSO format, the index column can contain multiple document formats (DOC, PDF, XLS, etc.).

 

Also notice the specification of the "Update Frequency" clause in the above example. This is a purely optional setting that can be used to schedule index updates on the IBM i Job Scheduler. If specified, an entry is placed in the Job Scheduler using the ADDJOBSCDE command. In the above example, the asterisk specified in the Day (D) parameter indicates that the index will be updated every day. If you do not want to schedule your index updates, the alternative would be manual updates by calling the SYSTS_UPDATE procedure.

 

SYSTS_UPDATE: Update a Text Index

As mentioned, creating the index does not populate it with data. For that, the stored procedure SYSTS_UPDATE must be called. The first time this stored procedure is called for a specific text index, all of the documents (or text strings) from the indexed column are processed and added to the text search index. This initial update requires a full scan of the base table and is depicted in Figure 2.  

 

031109CobbFigure2.gif

Figure 2: The initial update scans the base table.

 

While this technique is acceptable for the initial population of the index, a more efficient method is employed to synchronize the index with future document changes to the base table. Recall that when a text index is created, database triggers are added to the base table and a staging table is created. These triggers fire whenever a change occurs over the indexed column in the base table, and they log the information about this incremental update to the staging table.

 

Because all of these incremental updates are sent to the staging table, subsequent calls to SYSTS_UPDATE result in the processing of the staging table. This is more efficient because it eliminates the need for a full scan of the base table. Instead, only the rows in the staging table are read. The staging table contains the base table key, so each row is joined back to the base table and the text index is updated. This more-resourceful technique is show in Figure 3.

 

031109CobbFigure3.gif

Figure 3: In an incremental update, only the rows in the staging table are read.

 

If the index was created with the UPDATE FREQUENCY clause, incremental updates will be performed via an IBM i job scheduler entry.

 

SYSTS_DROP: Drop a Text Index

If you need to drop the text index, the SYSTS_DROP stored procedure will do the trick. This procedure has two parameters: text index name and schema.

 

If a job scheduler entry was added via the UPDATE FREQUENCY clause, calling this procedure will remove that job scheduler entry for the specified index.

 

SYSTS_STOP: Stop Text Search Support

As you might have guessed, calling the SYSTS_STOP procedure disables the text search support. While the text search server is down, all SQL requests that include OmniFind built-in functions will fail. However, because database triggers are handling changes to the base tables, all changes continue to be logged to the staging tables. 

Searching Using the Built-In Functions

The OmniFind product provides two easy-to-use, integrated built-in functions to help you locate the search strings buried in documents and text fields: CONTAINS and SCORE.

 

Note: The CONTAINS and SCORE functions are supported only by the SQL Query Engine (SQE).

 

The CONTAINS function is pretty simple: It accepts (as input parameters) the name of the column, a search argument, and an optional parameter for advanced search options. It searches a text index for the search argument and returns a 1 if a match was found for that row. Otherwise, a 0 is returned.

 

The following example returns all rows in the INVENTORY_TECH_DOCS table that contain the search argument 'Turntable' in the document stored in the tech_spec_doc column:

 

SELECT productnumber, productname                                                           

FROM inventory_tech_docs

WHERE CONTAINS(tech_spec_doc, 'Turntable')=1                           

 

The SCORE function is similar to CONTAINS, but it actually returns a relevance score that is based on how well a document matches the search argument. A higher score would indicate that more matches were found. The result of SCORE is always a floating decimal value between 0 and 1.

 

Just like CONTAINS, its input parameters are the name of the column, a search argument, and options. SCORE is often specified as the first ORDER BY column (in descending order) so that the result set shows the top matching rows first. It can also be used in the WHERE clause of a SELECT statement to show only the matches that are higher than a specified minimum value. Because the score is returned as a floating decimal between 0 and 1, you can improve the readability by multiplying the value by 100 and converting it to an integer. An example of this is shown below:

 

SELECT INTEGER(SCORE(tech_spec_doc,'Turntable')*100)

       productnumber, productname                                                       

FROM inventory_tech_docs                                                   

WHERE SCORE(tech_spec_doc,'Turntable') > .25                      

ORDER BY SCORE(tech_spec_doc,'Turntable') DESC

 

Once the SQL statement with CONTAINS and/or SCORE is submitted, the search key and options are sent to the Text Search Server. The results are returned to the invoking SQL function. This process is shown in Figure 4.

 

031109CobbFigure4.gif

Figure 4: This is how OmniFind search processing works.

Advanced Searching

The above examples are ways you can perform simple searching. In addition, OmniFind allows you to perform more-sophisticated types of text searching:

  • AND
  • OR
  • NOT
  • Exact Match
  • Wildcard
  • Score Boosting
  • Includes
  • Excludes
  • Escape Characters

These operators allow you to extend your searching capabilities and provide your users with ways to find exactly what they are looking for. Some complex query examples are shown in the table below:

 

Advanced Searching Examples

Operators

Examples

Query Results

" "

(Exact Match)

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: