02
Sat, Nov
2 New Articles

Use SQL to Export and Delimit Files on the IBM i

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

Create CSV files from multiple physical files.

 

In a previous article, I discussed how to "Delimit Data on the IBM i the Easy Way." In this article, we'll take it a step further and discuss alternate methods of exporting data from multiple physical files and delimited text files using comma-separated values (CSV).

 

The CPYF command gives you some pretty powerful capabilities when copying files. But you can do even more with SQL. There are many ways to perform the same task with the resources available on the IBM i. You just have to decide how much code you want to write and be aware of the resources that are available.

Starting the Interactive SQL Tool

Throughout most of this article, we will be using the interactive SQL tool available from the IBM i command line. To start the interactive SQL tool, type STRSQL on the command line. For more detailed information on the interactive SQL tool, refer to one of my previous articles, "Use Interactive SQL from the IBM i Command Line."

Creating a Copy of an Existing File

Let's start off simple. To begin using the SQL commands, create a copy of an existing physical file as is. This can easily be done with other commands, such as CPYF, but this will be a good start for our SQL endeavors.

 

We will be using the MC_PHONE file for our example, which has the following DDS:

 

A R MCFMT

A MCACCT 6S 0 COLHDG('ACCOUNT NUMBER')

A MCAREA 3A COLHDG('AREA CODE')

A MCPHONE 7A COLHDG('PHONE NBR')

A MCDATE 8S 0 COLHDG('CHANGE DATE')

 

We will be copying our mc_phone file into a new file named mc_phone1.

 

create table mylib/mc_phone1

as (select * from mylib/mc_phone)

with data

 

Here is a quick breakdown of what the command is doing:

 

Statement

Description

create table mylib/mc_phone1

This statement creates the table, which is specified with the library followed by the new file name with a forward slash separator.

 

as (select * from mylib/mc_phone)

"As" indicates that the file should be created by the source file, which will be using all of the fields from the mc_phone file.

 

with data

"With data" indicates that the data needs to be copied into the target file. Otherwise, the target file will be created, but it will not contain any data.

 

If you execute the DSPFFD command on the resulting mc_phone1 file, you will see that the field definitions are the same as those in the original mc_phone file.

 

012010TomSnyder_Figure1
Figure 1: Running DSPFFD on the mc_phone1 file shows that the field definitions are the same as those in the original mc_phone file. (Click images to enlarge.)

 

And to verify that the data was copied into our new mc_phone1 file, we can run the following statement on the mc_phone1 table.

 

select * from mc_phone1

 

And here you have the results of the query to show the data that we will be working with:

 

012010TomSnyder_Figure1B
Figure 2: The results of the query show the data we will be working with.

Filter Data While Dropping and Mixing Field Positions

CPYF does the job of filtering the data, and you can use the CRTFILE(*YES) option to automatically create the target file. But if you need to change the field positions, you will need to create the target file first and use the FMTOPT(*MAP) option. And if you want to drop fields between the source and the target file, you will need to also use the FMTOPT(*DROP) option.

 

You can easily support this in SQL without the preexisting file by specifying which fields will be in your output file and which order to put them in.

 

For this example, we will only copy the records that were created in 2010, and we will drop the date table from the results. And just for good measure, we will also move the account number to be the third field instead of the first.

 

create table mylib/mc_phone2

as (select mcarea, mcphone, mcacct from mylib/mc_phone

where mcdate > 20091231)

with data

 

Instead of using the asterisks in the SELECT statement, we specified which fields to use and which order to put them in in the target file.

 

If you execute the DSPFFD command on the resulting mc_phone2 file, you will see that the mcdate field does not exist. You can also see that the field order has been changed to be as expected.

 

012010TomSnyder_Figure2
Figure 3: Running DSPFFD on the resulting mc_phone2 file shows that the mcdate field does not exist.

Delimiting and Filtering the Data with SQL

CPYF can be used to delimit the data by setting defaults in the delimiter fields of the target file, as discussed in my previous article. But with SQL, you can add the delimiters to the target file while you are creating it by concatenating the delimiter characters to the fields.

 

TABS are common delimiters, and you can use them by specifying the Hex EBCDIC Tab value of X'05'. But let's make it a little more interesting this time by creating a CSV file that we can easily download and use with Excel.

 

Using SQL, we also have the ability to filter the data, and to top it all off, we don't need the additional DDS! All we have to do is insert the constant values to be used with our source data to create the delimiters. When the new fields are created, we need to specify the field name immediately after the constant value is specified to be used.

 

create table mylib/mc_phone3

as (select '"' delimit1, mcarea,

'","' delimit2, mcphone,

'","' delimit3, mcacct,

'"' delimit4

from mylib/mc_phone where mcdate > 20091231)

with data

 

In theory, this statement should generate the results that we're looking for. And if you're using the data transfer utility with iSeries Access, it probably will. But if you download the file using FTP, you may find some additional and undesirable characters included with your delimiters.

 

No problem. We can get around that by encoding our fields to the EBCDIC CCSID of 37 or whatever CCSID you prefer.

 

create table mylib/mc_phone3

as (select cast('"' as char(1) ccsid 37) delimit1, mcarea,

cast('","' as char(3) ccsid 37) delimit2, mcphone,

cast('","' as char(3) ccsid 37) delimit3, mcacct,

cast('"' as char(1) ccsid 37) delimit4

from mylib/mc_phone where mcdate > 20091231)

with data

 

If you execute DSPFFD on mc_phone3, you will see that the new delimited fields are included in the data. And if you view the data using a SELECT statement, you can see that the new data is delimited.

 

012010TomSnyder_Figure3

Figure 4: Running DSPFFD on mc_phone3 shows that the new delimited fields are included in the data.

 

Now if we download the file, providing a .csv extension to the file, we can easily open the file in a spreadsheet. The .csv extension will help the application identify the expected format of the data as CSV.

Retrieving the Data from Multiple Source Files

Now that we know how to insert delimiters, let's really explore the reason that you would use SQL by retrieving the data from multiple source files.

 

For this example, we will be using an additional file called MC_ACCT, which contains only the account number, first name, and last name. Here is the DDS for the MC_ACCT file:

 

A R MAFMT

A MAACCT 6S 0 COLHDG('ACCOUNT NUMBER')

A MAFNAME 32A COLHDG('FIRST NAME')

A MALNAME 32A COLHDG('LAST NAME')

A K MAACCT

 

Suppose you already have 100 things on your plate and a request comes through for a new process that requires critical business information (simply a list of records from a few files) to be sent to an external system—and the boss needs it yesterday! Sure, you could write an RPG program to do it, or you could do it in SQL using a single statement!

 

create table mylib/mc_phone4

as (select cast('"' as char(1) ccsid 37) delimit1, a.maacct,

cast('","' as char(3) ccsid 37) delimit2, a.mafname,

cast('","' as char(3) ccsid 37) delimit3, a.malname,

cast('","' as char(3) ccsid 37) delimit4, p.mcarea,

cast('","' as char(3) ccsid 37) delimit5, p.mcphone,

cast('"' as char(1) ccsid 37) delimit6

from mylib/mc_acct a, mylib/mc_phone p

where a.maacct = p.mcacct)

with data

 

The single letters a and p are references to the mc_acct and mc_phone files, respectively, and are assigned in the from portion of the command. The link to the tables is specified in the where portion, which identifies the account number fields maacct and mcacct.

 

And there you have it: a quick data export comprised of multiple files in CSV format using a single line of code!

The Right Tools for Any Job

As you can see, there are different ways to perform different tasks, based upon the level of complexity of the goal that you are trying to reach. There are different commands available, such as CPYFRMIMPF and CPYF, or you can simply use SQL and do it all. But then again, RPG can do everything here and more. Again, my point is that there are different tools for different tasks. If you know what they are, you can use them where most appropriate.

 

Thomas Snyder

Thomas Snyder has a diverse spectrum of programming experience encompassing IBM technologies, open source, Apple, and Microsoft and using these technologies with applications on the server, on the web, or on mobile devices.

Tom has more than 20 years' experience as a software developer in various environments, primarily in RPG, Java, C#, and PHP. He holds certifications in Java from Sun and PHP from Zend. Prior to software development, Tom worked as a hardware engineer at Intel. He is a proud United States Naval Veteran Submariner who served aboard the USS Whale SSN638 submarine.

Tom is the bestselling author of Advanced, Integrated RPG, which covers the latest programming techniques for RPG ILE and Java to use open-source technologies. His latest book, co-written with Vedish Shah, is Extract, Transform, and Load with SQL Server Integration Services.

Originally from and currently residing in Scranton, Pennsylvania, Tom is currently involved in a mobile application startup company, JoltRabbit LLC.


MC Press books written by Thomas Snyder available now on the MC Press Bookstore.

Advanced, Integrated RPG Advanced, Integrated RPG
See how to take advantage of the latest technologies from within existing RPG applications.
List Price $79.95

Now On Sale

Extract, Transform, and Load with SQL Server Integration Services Extract, Transform, and Load with SQL Server Integration Services
Learn how to implement Microsoft’s SQL Server Integration Services for business applications.
List Price $79.95

Now On Sale

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: