23
Mon, Dec
3 New Articles

Practical SQL: Field Reference Files in DDL

Joe Pluta

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

SQL does field reference files, too!

In a previous article, I discussed how naming conventions really help in database design and programming, and in so doing I touched upon the concept of the field reference file. Field reference files are an easy way to make sure your data elements are consistent, but I'll bet you didn't know you could use them in DDL as well. In this article, I'll show you how it's done.

Using a Field Reference File

If you're a DDS shop, I hope you're already using a field reference file. But let's review quickly how that works. First, I create a file with definition of all the basic data elements of my system. As always, naming is important, and when I create a field reference file, I use short names so that I can later put a prefix on them when defining my files. Using a prefix is a matter of preference; some people actually use the same field name in multiple files. I've never been a huge fan of that approach, but I don't argue when someone uses it. Like most programming architecture decisions, there are benefits and drawbacks to the technique. But let's move ahead with my normal approach. For this example, I define a reference file called REFFILPF, with the record format RREFFIL. Below is an excerpt:

R RREFFIL                                        

CUST        6S 0      TEXT('CUSTOMER NUMBER')

NAME        30      TEXT('NAME')          

ADDR        30        TEXT('ADDRESS')    

This reference file identifies a number of fields. Now I define my customer master file from that. Again, I present just a portion of the file:

                            REF(*LIBL/REFFILPF)

R RCUSMAS                                    

CMCUST    R             REFFLD('CUST')    

CMNAME   R             REFFLD('NAME')    

CMADDR1  R           REFFLD('ADDR')  

                           TEXT('ADDRESS 1')    

CMADDR2  R             REFFLD('ADDR')    

                           TEXT('ADDRESS 2')    

The attributes of the fields in the customer master depend on the attributes defined in the field reference file. What this allows me to do is to keep consistency among fields with common data. As an example, CMADDR1 and CMADDR2 share the same attributes: they're both 30-character fields. But I'd like to differentiate them both in field name and in their descriptive text. I can easily override the text from the field definition file by specifying a text keyword for each address field. If I didn't, both fields would get the same text of "ADDRESS".

References in DDL

To use reference fields in DDL, you start the same way, by creating the field reference file. Create it as shown below:

CREATE TABLE MYLIB.REFFILPF (

       CUST NUMERIC(6, 0) NOT NULL DEFAULT 0 ,

       NAME CHAR(30) CCSID 37 NOT NULL DEFAULT '' ,

       ADDR CHAR(30) CCSID 37 NOT NULL DEFAULT '' ,

)       RCDFMT REFFILR;

LABEL ON COLUMN MYLIB.REFFILPF (

       CUST TEXT IS 'Customer',

       NAME TEXT IS 'Name',

       ADDR TEXT IS 'Address'

);      

As you can see, I have to use separate statements in DDL to create the table and then to assign the text to the fields. I suppose the CREATE TABLE command is already pretty complicated and the DB2 powers that be just didn't want to add more DB2-specific extensions to it, so they just created the LABEL ON statement. I'm just glad that you're able to set the text for as many fields as you want in one LABEL ON statement; I'd hate to have to execute one LABEL ON for every field. Anyway, with these two statements, you've effectively duplicated the effort of the original REFFILPF DDS above. This creates the field reference file that other database files can use as a model. You may have noticed that I used uppercase and lowercase on the DDL; that just allows me to make sure that I ran the command successfully. If my file fields have uppercase text, then I know I didn't execute the DDL correctly. Also, please note that I used the dot notation (MYLIB.REFFILPF) rather than the more traditional slash syntax (MYLIB/REFFILPF). Either will work on the green-screen, but the dot syntax also works in GUI tools such as IBM i Navigator or any of the myriad SQL clients out there. Because of that, I've moved almost exclusively to the dot notation for qualifying files.

So now that I have a field reference file, it's time to use it to create a file that refers to it. Creating the file is simple:

CREATE TABLE MYLIB.CUSMASPF AS (

SELECT CUST AS CMCUST,

       NAME AS CMNAME,

       ADDR AS CMADDR1,

       ADDR AS CMADDR2

FROM MYLIB.REFFILPF

) DEFINITION ONLY RCDFMT CUSMASR;

This is a really powerful technique. Basically, I just build a SELECT statement that pulls in all the fields that I need from the reference file. In that SELECT, I use the AS clause to rename them in such a way that they fit the new table's naming convention. Then the only additional piece is to add the DEFINITION ONLY clause at the end just before I define the record format name; this lets the system know I'm creating an empty file. However, you may have noticed something missing; I haven't changed the descriptions of the two address fields. Without any additional intervention, the two fields would both have the same text of "Address". I can remedy that situation with a LABEL ON statement:

LABEL ON COLUMN JPLUTA.CUSMASPF (

       CMADDR1 TEXT IS 'Address 1',

       CMADDR2 TEXT IS 'Address 2'

);      

You'll note that, like DDS, I only have to specify overrides for the fields whose text I want to change. The other fields get their defaults from the field reference file. And in fact, if I bring the file up in ProData's popular DBU utility, I'd see something like this:

Practical SQL: Field Reference Files in DDL - Figure 1

Figure 1: My new file looks like this when adding records in DBU.

Text and Column Headings

You might have noticed that I only talked about field text in this discussion. As IBM i programmers, we know there are actually two descriptive attributes associated with every field: the text and the column heading. The default is for both to be the same, but they don't have to be. If you're someone who relies on the column heading to be different from the text for some or all of your fields, rest assured that IBM i DDL has you covered. You specify the column heading using the same LABEL command, except that you leave off the keyword TEXT. Here is an example:

LABEL ON COLUMN MYLIB.REFFILPF (

       CUST IS 'CustNo'

);      

By not specifying the keyword TEXT, the label value is applied to the column heading. This particular statement overrides the column heading on the CUST field only. To get a little more detail on text and column headings, you can refer an article I wrote a while back.

There are some other minor differences. DDL is not quite a complete replacement for DDS. As an example, I haven't found a way to specify an edit code for a numeric field in DDL. This is more of a convenience feature; it's nice to be able to look at numeric fields in a query without the commas. But if you can live without that capability, you can make the move entirely from DDS to DDL yet still retain your field reference file capabilities. And that's worth the effort for me.

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: