22
Sun, Dec
3 New Articles

TechTip: Generate and Email a Spreadsheet with SQL

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

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:

  1. GENERATE_SPREADSHEET
  2. 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.

TechTip: Generate and and Email a Spreadsheet with SQL - Figure1 

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.

TechTip: Generate and and Email a Spreadsheet with SQL - Figure2 

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.

TechTip: Generate and and Email a Spreadsheet with SQL - Figure 3 

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 This email address is being protected from spambots. You need JavaScript enabled to view it., attaching the manager spreadsheet that we generated in the last example.

-- Send an email with an attachment.

-- Change the TO_EMAIL to your recipient.

VALUES SYSTOOLS.SEND_EMAIL(

TO_EMAIL   => This email address is being protected from spambots. You need JavaScript enabled to view it.'
  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.

TechTip: Generate and and Email a Spreadsheet with SQL - Figure 4 

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.

TechTip: Generate and and Email a Spreadsheet with SQL - Figure 5 

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.

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: