21
Thu, Nov
1 New Articles

TechTip: Read from and Write to an IFS File Using SQL

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

In many IBM i environments, data is stored in both the database and the Integrated File System (IFS). The IFS_READ and IFS_WRITE IBM i Services provide new ways of accessing the data in an IFS stream file using SQL.

The IFS_READ and IFS_WRITE functions allow us to use the power of SQL to gain insight into the data in the IFS. In the following examples, we will start by simply seeing how to use SQL to both read from and write to an IFS stream file. Then, in the more advanced examples, we will see first how to write multiple lines to an IFS stream file from an SQL query of a database table and then how to search an IFS stream file for a string, returning the results in a database table.

Writing Data to an IFS Stream File

We can use three procedures to write data to an IFS stream file. These three procedures are used to write character data, binary data, or UTF-8 data, respectively:

  • IFS_WRITE
  • IFS_WRITE_BINARY
  • IFS_WRITE_BINARY_UTF8

The parameters for all three procedures are the same:

  • PATH_NAME

The path name of the stream file that is written to

  • LINE

The data that will be written to the stream file

  • FILE_CCSID

The CCSID used if a new stream file is created

  • OVERWRITE
    An indicator of whether the data being written should be appended to the stream file, replace the stream file, or fail if the stream file already exists
  • END_OF_LINE

The end-of-line character to append to the end of the line. The options are a carriage return, a line feed, a carriage return and line feed, a line feed and carriage return, or none.

If the stream file specified by the path name does not exist, it will be created. The following is an example that will create a stream file and write one line of data to the stream file.

-- Create the directory the stream file will be created into
CL: MKDIR DIR('/home/TestDirectory');

-- Create a stream file at the path /home/TestDirectory/test.txt

CALL IFS_WRITE(PATH_NAME => '/home/TestDirectory/test.txt',

               LINE     => 'My test data',

               OVERWRITE => 'NONE',

               FILE_CCSID => 37,

               END_OF_LINE => 'CRLF');

From the Access Client Solutions (ACS) Integrated File Systems GUI interface, we can see that the file has been created.

TechTip: Read from and Write to an IFS File Using SQL - Figure 1 

Figure 1: The IFS stream file created using the IFS_WRITE command

Now that we’ve written data to a stream file, we can use SQL to read the data we’ve just written into the test.txt file.

Reading Data from an IFS Stream File

A table function is a user-defined function (UDF) that returns a table. A table function can be used wherever you would normally use a table—for example, in the FROM clause of a SELECT statement.

We can use three table functions to read an IFS stream file as either character data, binary data, or UTF-8 data. The three table functions are:

  • IFS_READ
  • IFS_READ_BINARY
  • IFS_READ_UTF8

The parameters for all three table functions are the same:

  • PATH_NAME
    The path name of the stream file being read
  • MAXIMUM_LINE_LENGTH
    The maximum number of characters returned for each line
  • END_OF_LINE
    An indicator of what the end-of-line character is. The options are a carriage return, a line feed, a carriage return and line feed, a line feed and carriage return, or none.
  • IGNORE_ERRORS
    Indicates whether a warning should be returned if an error occurs or if no row is returned when an error occurs

The table function returns two columns:

  • LINE_NUMBER
    The line number in the IFS file
  • LINE

The data for that line

To read the data that we wrote in the test.txt file created in the above example, we will use the IFS_READ table function.

-- Read from the stream file at the path /home/TestDirectory/test.txt

SELECT * FROM

TABLE(QSYS2.IFS_READ(PATH_NAME => '/home/TestDirectory/test.txt',

                       END_OF_LINE => 'CRLF'));

LINE_NUMBER

LINE

1

My test data

Table 1: Results of the query using IFS_READ

More Examples of IFS_WRITE and IFS_READ

You can write multiple lines to the stream file using APPEND and CRLF options. In the following example, we will write one line of data to the test2.txt file, specifying that we want to write a carriage return and line feed (CRLF) after the line is written. Then, we will append a second line of data on the new line.

-- Write the first line of data using CRLF to add a carriage

-- return and line feed after the line is written

CALL IFS_WRITE(PATH_NAME => '/home/TestDirectory/test2.txt',

               LINE     => 'First line of data',

               OVERWRITE => 'APPEND',

               END_OF_LINE => 'CRLF');

-- Append a second line of data to the stream file

CALL IFS_WRITE(PATH_NAME => '/home/TestDirectory/test2.txt',

               LINE     => 'Second line of data',

               OVERWRITE  => 'APPEND',

               END_OF_LINE => 'CRLF');

-- Read from the stream file

SELECT * FROM

TABLE(QSYS2.IFS_READ(PATH_NAME => '/home/TestDirectory/test2.txt',

                       END_OF_LINE => 'CRLF'));

LINE_NUMBER

LINE

1

First line of data

2

Second line of data

Table 2: Results after writing two lines of data

Alternatively, we can replace data in the stream file using the REPLACE option. In the following example, the existing stream file is deleted, a new stream file is created, and the line is written to the new file. If no stream file exists already, then a new one is created and the line is written to it.

-- Replace the existing test2.txt stream file and write

-- a line of data using the REPLACE option

CALL IFS_WRITE(PATH_NAME => '/home/TestDirectory/test2.txt',

               LINE      => 'New line of data',

               OVERWRITE => 'REPLACE',

               END_OF_LINE => 'CRLF');

-- Read from the stream file

SELECT * FROM

TABLE(QSYS2.IFS_READ(PATH_NAME => '/home/TestDirectory/test2.txt',

                       END_OF_LINE => 'CRLF'));

LINE_NUMBER

LINE

1

New line of data

Table 3: Results after replacing an existing stream file

The REPLACE option can also be used to clear a stream file. In the following example, we replace our test2.txt file by writing an empty line to that file with no end-of-line character.

CALL QSYS2.IFS_WRITE(PATH_NAME=>'/home/TestDirectory/test2.txt',

                     LINE => '',

                     OVERWRITE => 'REPLACE',

                     END_OF_LINE => 'NONE');

Using IFS_WRITE and IFS_READ with Database Tables

You can write multiple lines of data to an IFS stream file from a query of a database table. In the following example, we will write all of the employee names from a sample employee table to an IFS stream file.

-- Create the sample database

CALL QSYS.CREATE_SQL_SAMPLE('MY_STORE');

-- Clear the IFS file that we will write too

CALL QSYS2.IFS_WRITE(PATH_NAME=>'/home/TestDirectory/test2.txt',

                     LINE => '',

                     OVERWRITE => 'REPLACE',

                     END_OF_LINE => 'NONE');

-- For each record in the employee table, write each employee name

-- on a new line to the test2.txt stream file

-- Use APPEND and CRLF

BEGIN

FOR SELECT FIRSTNME, LASTNAME FROM MY_STORE.EMPLOYEE

DO CALL IFS_WRITE(PATH_NAME => '/home/TestDirectory/test2.txt',

                   LINE       => (FIRSTNME || ' ' || LASTNAME),

                   OVERWRITE => 'APPEND',

                   END_OF_LINE => 'CRLF');

END FOR;

END;

-- Read from the IFS file

SELECT * FROM

TABLE(QSYS2.IFS_READ(PATH_NAME => '/home/TestDirectory/text2.txt',

             END_OF_LINE => 'CRLF'));

LINE_NUMBER

LINE

1

CHRISTINE HAAS

2

MICHAEL THOMPSON

3

SALLY KWAN

4

JOHN GEYER

continued…

Table 4: Results after writing multiple lines from a database table to a stream file

The SELECT statement used in this example is a simple SELECT; however, by adding, for example, a WHERE clause or a JOIN with another table, we can begin to really use the power of SQL to create even more advanced IFS stream files using the data stored in our database.

Similarly, we can use IFS_READ to read lines of data from an IFS stream file and insert the data into a database table. By using the power of SQL, we can begin to gain more insight into our IFS data by, for example, searching our IFS stream file for a specific string. In the following example, we will insert a row into a database table for every line in the IFS stream file that we just created that contains the characters JOHN. In order to do this, we can use the LIKE predicate in our WHERE clause to search for strings with a certain pattern. When using the LIKE predicate, the percent sign (%) acts as a special character that represents a string of zero of more characters. By placing a % sign both in front of and after the expression JOHN, we will search for the string JOHN appearing anywhere in each LINE we read from the IFS stream file.

-- Create a database table that we will insert the lines of data into

CREATE TABLE MY_STORE.CONTAINS_JOHN (NAME VARCHAR(100));

-- Insert into the database table a line of data where the line

-- contains the string 'JOHN'

INSERT INTO MY_STORE.CONTAINS_JOHN

SELECT LINE FROM

   TABLE(QSYS2.IFS_READ(PATH_NAME => '/home/TestDirectory/test2.txt',

                       END_OF_LINE => 'CRLF'))

   WHERE LINE LIKE '%JOHN%';

-- Get the results

SELECT * FROM MY_STORE.CONTAINS_JOHN;

Name

JOHN GEYER

SYBIL JOHNSON

JOHN PARKER

REBA JOHN

Table 5: Results after inserting rows using IFS stream file data

By changing the WHERE clause, we can adjust our query to search the IFS file in whatever way we might want.

More Information

For more information about the IFS_WRITE functions, see https://www.ibm.com/docs/en/i/7.5?topic=is-ifs-write-ifs-write-binary-ifs-write-utf8-procedures.

For more information about the IFS_READ functions, see https://www.ibm.com/docs/en/i/7.5?topic=is-ifs-read-ifs-read-binary-ifs-read-utf8-table-functions.

Sarah Mackenzie is a Db2 for i Senior Software Engineer. She has worked on the IBM i development team since she joined IBM in 2012. During that time, she has focused on both database and query and has worked on the design, development, and support of new enhancements for IBM i such as Temporal Tables, Db2 Mirror, and Geospatial Analytics with Watson. Sarah is also a speaker at many industry events.

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: