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!
LATEST COMMENTS
MC Press Online