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.
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.
LATEST COMMENTS
MC Press Online