23
Mon, Dec
3 New Articles

Practical SQL: Defining Your Data: TEXT and LABEL

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

Using DDL to define your data has a lot of benefits, but you still need to know a few tricks to get all of the features we enjoy in DDS. Read on for the secrets!

 

Today's article is my first dedicated to Data Definition Language (DDL), the specific SQL syntax used to define tables. It's counterpart in the green-screen world is Data Description Specifications (DDS), the simple data definition language we've used forever.

In with the Old

Before we can get rid of the old code, we first have to have old code. Let's take a look at a very simple table defined in DDS:

 

R CUSMASR                                         

  CMCUST         6S 0       COLHDG('CustNo')      

                            TEXT('Customer Number')

  CMNAME        50          COLHDG('Customer Name')

  CMENUS        10          COLHDG('Entered By')  

  CMENTS          Z         COLHDG('Entered At')  

  CMCHUS        10          COLHDG('Changed By')     

  CMCHTS          Z         COLHDG('Changed At')     

K CMCUST                                          

Listing 1: This DDS creates a very simple customer master file.

 

See? Very simple. Trivial, even. The file consists of only two real data points: the customer number and the customer name. The other five fields are really record meta-data fields: who entered the record and when, and what the last change was along with when and by whom it was executed. I happen to like these fields, and I now add them to all my files. I can't tell you the number of times it's come in handy to know who added a record or who changed it (or, if you soft-delete your records with a status code, you can even see who deleted it). It's not as exhaustive as an audit file, but it's relatively easy to implement.

 

You may have noticed something. Every field has a column heading specified with the COLHDG keyword, but only certain fields have the TEXT keyword. That's because the default for the TEXT keyword is to copy whatever is in the COLHDG; if they're the same, you only need to specify COLHDG. Note that this doesn't work the other way: if you specify only the TEXT keyword, then the default for COLDHG is the field name, not the text. It seemed a bit odd to me when I first found this out, especially since I'd spent most of my career defining only the TEXT keyword, but you're never too old to learn something new!

From DDS to DDL

Changing this to DDL is straightforward. You need to know how to map DDS data types to the corresponding SQL data types, but that's pretty simple. Here's the equivalent command in SQL using the CREATE TABLE statement in DDL.

 

CREATE TABLE MCP/CUSMAS (

    CMCUST NUMERIC(6) NOT NULL,

    CMNAME CHAR(50) NOT NULL,

    CMENUS CHAR(10) NOT NULL,

    CMENTS TIMESTAMP NOT NULL,

    CMCHUS CHAR(10) NOT NULL,

    CMCHTS TIMESTAMP NOT NULL

  );

Listing 2: This shows the SQL DDL required to create the same table.

 

As I said, it's not particularly difficult. NUMERIC is the DDL equivalent for zoned data (also known as signed numeric). DECIMAL corresponds to packed decimal. Note that on some databases the two terms are synonymous; on the IBM i the type determines whether the data is stored as packed or zoned. CHAR is character data. DDS dates are type DATE, times are type TIME, and timestamps (type Z) are defined as TIMESTAMP in DDL. I've specified the NOT NULL keyword on every line because I didn't specify ALWNULL in the DDS. This SQL statement creates a table with the same field names and types as my original DDS but with no textual meta-data of any kind; I need to do that in a separate step.

 

But before I move on to labels, I need to address one additional bit of syntax completely unique to DB2 for the IBM i—namely, the RCDFMT syntax. The reason for this keyword is simple: if you create a table using DDL, then by default the table has as its record format the name of the table. This is unacceptable in the RPG world (you need to rename the format in your F-spec in order to even compile a program with that file), and we get around it by specifying a record format name in the first line of the DDS. If you look at the code in Listing 1, you'll see that the first line of the DDS has an R record type and the name of the record format, CUSMASR. You accomplish this in SQL by using the special RCDFMT keyword at the end of your definition:

 

    CMCHTS TIMESTAMP NOT NULL

  ) RCDFMT CUSMASR;

 

Specifying the Text

We need to set three different pieces of textual metadata. The field text and column headings should come immediately to mind as the first two pieces, since they've been the focus of this article. The third is the object text for the file itself, which isn't in the DDS but is instead usually the member text of the DDS source member. Not to worry! SQL can still handle the file object text. In fact, all three text values can be set using the LABEL ON command. The first syntax is for the file itself and is very simple:

 

LABEL ON TABLE MCP/CUSMAS IS 'Customer Master';

 

As usual, SQL refers to files as tables, but other than that, the syntax is pretty self-evident. The next syntax allows you to change either the column heading or the field text (but not both). Here's how we handle the customer number:

 

LABEL ON COLUMN MCP/CUSMAS (CMCUST IS 'CustNo');

LABEL ON COLUMN MCP/CUSMAS (CMCUST TEXT IS 'Customer Number');

 

This will set the column heading to "CustNo" and the field text to "Customer Number," mirroring the DDS in Listing 1. Note that the only difference is the word TEXT in the second LABEL ON command. You could then execute those same statements over and over again for each of the fields in question.

 

The last thing I'll leave you with, though, is a syntax that allows you to update the text values for multiple fields in a single SQL statement:

 

LABEL ON COLUMN MCP/CUSMAS

(CMCUST IS 'CustNo',

 CMNAME IS 'Customer Name',

 CMENUS IS 'Entered By',

 CMENTS IS 'Entered At',

 CMCHUS IS 'Changed By',

 CMCHTS IS 'Changed At'

);

Listing 3: This SQL sets the column headings for every field in my CUSMAS file.

 

The default action for the LABEL ON COLUMN syntax is to update the column heading. With my revised understanding of the relationship between column heading and field text, I will put my default text on the column heading, and specify field text only when it's different. In this case, the only different field is customer name, so I can simply execute my earlier LABEL ON COLUMN for that field:

 

LABEL ON COLUMN MCP/CUSMAS (CMCUST TEXT IS 'Customer Number');

 

That does it. With the SQL in this article, you can completely duplicate the result of the DDS. Well, with one exception: there's no equivalent for the last line of the DDS that defines the key sequence. Interestingly enough, had we specified one additional keyword (UNIQUE), then we could have mimicked that by using a constraint. But that and so much more will have to wait for the next article. Until then, enjoy your DDL!

 

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: