SQL 101: A Data Definition Language Hands-on Tour, Part 3

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

It’s time to finish the discussion about SQL’s CREATE TABLE instruction and provide a few more examples of what you can do with it!

I mentioned in previous TechTips that there were some additional tables in this imaginary database scenario. These tables provided definitions for the inventory master’s item, shelf, and warehouse ID columns. Let’s create these tables and introduce some additional features in the process. I’m going to start with the item master table:

CREATE TABLE MYSCHEMA.TBL_ITEM_MASTER

FOR SYSTEM NAME ITMMST

(ITEM_ID    CHAR ( 15) NOT NULL WITH DEFAULT

PRIMARY KEY,

ITEM_DESCRIPTION FOR COLUMN ITEM_DESC

VARCHAR ( 120),

ITEM_PICTURE           FOR COLUMN ITEMPIC

BLOB ( 500K ))

RCDFMT ITMMSTR

So, what’s new here? I’m specifying the primary key directly in the ITEM_ID’s column definition. This is an alternative way of specifying a primary key, but you can use it only if your table has a single column as the primary key. The table’s next column is the item’s description, which is a VARCHAR data type with a length of 120 bytes. Note that this is only the maximum length, because the column might be left empty, in which case it will occupy zero bytes (null value) because I didn’t specify the NOT NULL option that you’ve seen in other columns—or have a description shorter than 120 characters.

Finally, the ITEM_PICTURE column is a Binary Large OBject (BLOB) occupying 500 Kb. The idea is providing a “storage area” for the item’s photo, directly in the database, thus facilitating the access to all item-related data when the table is accessed by an external application, like a web server. Even though this column’s content is not directly accessible in RPG, it can be manipulated in SQL, which you can encapsulate in an RPG procedure, as I explained in an earlier TechTip. Also, keep in mind that the BLOB column will occupy 500 Kb per row, regardless of the size of the file it contains. This behavior is the opposite of the ITEM_DESCRIPTION column’s, which will grow as needed up to a maximum of 120 bytes. This represents a slight deviation from the DDS Physical File to DDL Table conversion discussed in the previous TechTip, but it serves as a showcase of some of the features that SQL tables can provide. If I were going to use this table on an RPG program, I’d have to take into account the special characteristics of these two columns.

Having said that, we can move on to the juicy part! Now let’s create the warehouse master table:

CREATE TABLE MYSCHEMA.TBL_WAREHOUSE_MASTER

FOR SYSTEM NAME WHMST

(WAREHOUSE_ID           FOR COLUMN WHID

DEC ( 8, 0)            NOT NULL WITH DEFAULT

PRIMARY KEY,

WAREHOUSE_NAME   FOR COLUMN WHNAME

VARCHAR ( 80)    NOT NULL WITH DEFAULT,

WAREHOUSE_ADDRESS      FOR COLUMN WHADDR

VARCHAR ( 120)   NOT NULL WITH DEFAULT,

WAREHOUSE_LATITUDE     FOR COLUMN WHLAT

CHAR ( 15)             NOT NULL WITH DEFAULT,

WAREHOUSE_LONGITUDE FOR COLUMN WHLON

CHAR ( 15)             NOT NULL WITH DEFAULT,

CONSTRAINT MAND_COL_WAREHOUSE_ADDRESS

     CHECK (WAREHOUSE_ADDRESS <> ‘’))

RCDFMT WHMSTR

This table’s definition is similar to the previously presented ones, but it includes a new concept: a constraint. Similar to its plain English meaning, an SQL constraint limits a column, in this particular case, the WAREHOUSE_ADDRESS column. The constraint defined here forces every insert and/or update to this table to provide a value, even if it’s just a blank space, to column WAREHOUSE_ADDRESS. You can create different types of constraints, such as forcing a column value to be unique in the table, which has a similar behavior to the DDS UNIQUE keyword, or the type of check you see in this example: allowing a change in a given column’s value if and only if a certain condition or set of conditions is met.

Now that I have created the item and warehouse master tables, I can complete my inventory master table definition. I know that the inventory master table depends on the former two tables, because any given item in the inventory master table must have valid item and warehouse IDs. If the inventory master table were a DDS-defined file, I’d probably write RPG code to enforce this relation, but InvMst is an SQL table, so there are other tools at my disposal. In the next TechTips I’ll introduce these tools, always building upon these tables, to keep a logical path for you to follow. In the meantime, explore and experiment with the CREATE TABLE statement and its potential. Share your doubts and ideas in the Comments section below!

Rafael Victoria-Pereira

Rafael Victória-Pereira has more than 20 years of IBM i experience as a programmer, analyst, and manager. Over that period, he has been an active voice in the IBM i community, encouraging and helping programmers transition to ILE and free-format RPG. Rafael has written more than 100 technical articles about topics ranging from interfaces (the topic for his first book, Flexible Input, Dazzling Output with IBM i) to modern RPG and SQL in his popular RPG Academy and SQL 101 series on mcpressonline.com and in his books Evolve Your RPG Coding and SQL for IBM i: A Database Modernization Guide. Rafael writes in an easy-to-read, practical style that is highly popular with his audience of IBM technology professionals.

Rafael is the Deputy IT Director - Infrastructures and Services at the Luis Simões Group in Portugal. His areas of expertise include programming in the IBM i native languages (RPG, CL, and DB2 SQL) and in "modern" programming languages, such as Java, C#, and Python, as well as project management and consultancy.


MC Press books written by Rafael Victória-Pereira available now on the MC Press Bookstore.

Evolve Your RPG Coding: Move from OPM to ILE...and Beyond Evolve Your RPG Coding: Move from OPM to ILE...and Beyond
Transition to modern RPG programming with this step-by-step guide through ILE and free-format RPG, SQL, and modernization techniques.
List Price $79.95

Now On Sale

Flexible Input, Dazzling Output with IBM i Flexible Input, Dazzling Output with IBM i
Uncover easier, more flexible ways to get data into your system, plus some methods for exporting and presenting the vital business data it contains.
List Price $79.95

Now On Sale

SQL for IBM i: A Database Modernization Guide SQL for IBM i: A Database Modernization Guide
Learn how to use SQL’s capabilities to modernize and enhance your IBM i database.
List Price $79.95

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  •  

  • 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.

  • 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

  • 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: