IBM i Services can help you do much more than just retrieve data. Use the SYSTOOLS.GENERATE_SPREADSHEET and SYSTOOLS.SEND_EMAIL IBM i Services to generate a spreadsheet from a query or a database table and then send the spreadsheet as an email attachment.
With every Technology Refresh (TR), many new IBM i Services are delivered and even more existing IBM i Services are updated. IBM i Services help users replace complex and difficult CL commands and APIs with easy-to-use SQL functions and procedures. Additionally, IBM i Services can be used to help automate many processes that were previously done manually. When you combine the power of SQL with the operating system, you can accomplish many amazing things.
There are hundreds of IBM i Services that allow you to find a vast array of information about your system, objects, user profiles, journals, security settings, and much more. However, IBM i Services are not just for retrieving data. There are also services that help you to complete a task using SQL.
Two new services were released in November 2023 to do just that:
- GENERATE_SPREADSHEET
- SEND_EMAIL
These services are complementary, allowing you to use SQL to create a spreadsheet from information in a database file and then email that spreadsheet.
GENERATE_SPREADSHEET Scalar Function
SYSTOOLS.GENERATE_SPREADSHEET is a new SQL scalar function that is used to create a spreadsheet either from the results of a query or from a database file. Additionally, you can choose the type of spreadsheet you want to create: .csv, .ods, or .xlsx.
The following is an example of how to use the GENERATE_SPREADSHEET scalar function to create a comma-separated values (.csv) spreadsheet. In this example, we will use the EMPLOYEE table from the MY_STORE sample database.
-- Create a sample database called MY_STORE
CALL QSYS.CREATE_SQL_SAMPLE('MY_STORE');
-- Create the IFS directory to store the spreadsheet
CL: MKDIR DIR('/usr/spreadsheets');
-- Generate a .csv spreadsheet for all employees in my store
-- Use the rows and columns in the MYSTORE/EMPLOYEE table
-- Write the .csv file to the '/usr/spreadsheet' directory
-- Include the column headings as the first row in the spreadsheet
VALUES SYSTOOLS.GENERATE_SPREADSHEET(
PATH_NAME => '/usr/spreadsheets/employee_spreadsheet',
FILE_NAME => 'EMPLOYEE',
LIBRARY_NAME => 'MY_STORE',
SPREADSHEET_TYPE => 'csv',
COLUMN_HEADINGS => 'COLUMN');
When the above GENERATE_SPREADSHEET statement is run, the employee_spreadsheet.csv file is created into the /usr/spreadsheets IFS directory. You can see the spreadsheet in IBM i Access Client Solutions (ACS) by going to the Integrated File System and navigating to the directory specified on the PATH_NAME.
Figure 1: The generated spreadsheet is saved in the ACS IFS directory.
Using ACS, download the .csv file and open it using your favorite spreadsheet editor.
Figure 2: Download and open the saved file.
Alternatively, you can create a spreadsheet from a query. For example, let’s create a spreadsheet that contains data about only the managers from the EMPLOYEE table. Instead of specifying the FILE_NAME and LIBRARY_NAME, we will specify a SPREADSHEET_QUERY. The query we will use is this:
SELECT * FROM MY_STORE.EMPLOYEE WHERE JOB = 'MANAGER'
In order to create the .csv file, the following statement is executed.
-- Generate a .csv spreadsheet with info about managers in my store
VALUES SYSTOOLS.GENERATE_SPREADSHEET(
PATH_NAME => '/usr/spreadsheets/manager_spreadsheet',
SPREADSHEET_QUERY =>
'select * from my_store.employee where job = ''MANAGER''',
SPREADSHEET_TYPE => 'csv',
COLUMN_HEADINGS => 'COLUMN');
The spreadsheet can be downloaded and opened in your spreadsheet editor.
Figure 3: Here’s the new spreadsheet showing only managers.
SEND_EMAIL Scalar Function
SYSTOOLS.SEND_EMAIL is a new SQL scalar function that makes it easier to send an email using SQL. The SEND_EMAIL service uses the SNDSMTPEMM (Send SMTP E-mail Message) CL command; therefore, you must add the user profile that is calling the function to the system distribution directory and register the user profile with the SMTP server. In the following example, this is done for the SAMACKEN user profile using the ADDDIRE CL command and the ADDUSRSMTP CL command.
-- Add the user profile to the system distribution directory
-- Replace DBXXX with the name of your system
-- Replace SAMACKEN with your user name
CL: ADDDIRE USRID(SAMACKEN DBXXX) USRD('Sarah email') USER(SAMACKEN);
-- Register the user profile with the SMTP server
-- Replace SAMACKEN with your user name
CL: ADDUSRSMTP USRPRF(SAMACKEN);
Once this is done, call the SEND_EMAIL service. The SEND_EMAIL service takes as parameters the to-email address, the subject of the email, the body of the email, and optionally any attachments. For example, let’s send an email to
-- Send an email with an attachment.
-- Change the TO_EMAIL to your recipient.
VALUES SYSTOOLS.SEND_EMAIL(
TO_EMAIL =>
SUBJECT => 'Manager information',
BODY => 'Attached is a spreadsheet containing information about the managers at my store.',
ATTACHMENT => '/usr/spreadsheets/manager_spreadsheet.csv');
The following email is then sent.
Figure 4: IBM Services allows you to easily email your generated spreadsheet.
The SEND_EMAIL service can be used for more than just sending a spreadsheet. This service can also be leveraged for automating communication of other critical information by changing the text of the body of the email to contain whatever information you want to send.
SYSTOOLS Functions
One of the main goals of the IBM i Services in SYSTOOLS is to provide useful examples and models that can be modified to meet your individual needs. The SQL source for these functions can be generated and then used as a model to create your own customized function. For example, you may want to create your own version of SEND_EMAIL that always sends an email to a specific email address.
There are several ways to generate the SQL source. One method is to use the ACS Generate SQL tool. Open ACS and then click on Schemas. Open your database, right-click on Schemas, and click Include. Include the SYSTOOLS schema. Next, open the SYSTOOLS schemas, click on FUNCTIONS, and find the SEND_EMAIL function in the list. Then right-click on SEND_EMAIL and choose Generate SQL. This will open a window where you can customize how the SQL source script is generated. If you take the default values, it will open the generated SQL source script in a Run SQL scripts window.
Figure 5: This is one way to generate the SQL source.
Alternatively, you can call the GENERATE_SQL procedure directly to generate the SQL.
CALL QSYS2.GENERATE_SQL(DATABASE_OBJECT_NAME=>'SEND_EMAIL',
DATABASE_OBJECT_LIBRARY_NAME=>'SYSTOOLS',
DATABASE_OBJECT_TYPE=>'FUNCTION');
Either method will generate the CREATE FUNCTION source statement for SEND_EMAIL. Once the CREATE FUNCTION source is generated, change the library on the CREATE statement to your own user library and then adapt the function for your own purpose. Once you’ve made your changes, simply run the new CREATE FUNCTION statement to create your own version of the function in your library that can now be called from your applications.
More Information
The GENERATE_SPREADSHEET and SEND_EMAIL functions were delivered to IBM i 7.5 by Db2 for i PTF Group SF99950 Level 5 and to IBM i 7.4 by Db2 for i PTF Group SF99704 Level 26. For more information about the GENERATE_SPREADSHEET function see https://www.ibm.com/docs/en/i/7.5?topic=services-generate-spreadsheet-scalar-function. For more information about the SEND_EMAIL function, see https://www.ibm.com/docs/en/i/7.5?topic=services-send-email-scalar-function.
LATEST COMMENTS
MC Press Online