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

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

Today I’ll be talking about views. Not grandiose landscapes, but SQL views. If you think they’re just another name for logical files, you’re wrong. Keep reading to find out more!

Last time around, I talked about tables and how they are, at the same time, similar to and (very) different from physical files. Now I’ll discuss how views are also similar to and (very) different from logical files. If you haven’t read the previous articles (here and here), please do so, because the tables described there are the basis for the code in this article. As promised in the last TechTip, here’s the structure for the warehouse shelf master table:

CREATE TABLE MYSCHEMA.TBL_WAREHOUSE_SHELF_MASTER

FOR SYSTEM NAME WSMST

(WAREHOUSE_ID           FOR COLUMN WHID

DEC ( 8, 0)            NOT NULL WITH DEFAULT,

SHELF_ID               FOR COLUMN SHELFID

DEC ( 12, 0)           NOT NULL WITH DEFAULT,

SHELF_HEIGHT           FOR COLUMN SHLHEIGHT

DEC ( 4, 2)            NOT NULL WITH DEFAULT,

SHELF_WIDTH            FOR COLUMN SHLWIDTH

DEC ( 4, 2)            NOT NULL WITH DEFAULT,

SHELF_DEPTH            FOR COLUMN SHLDEPTH

DEC ( 4, 2)            NOT NULL WITH DEFAULT,

SHELF_REMARKS    FOR COLUMN SHL_RMK

VARCHAR ( 120)   NOT NULL WITH DEFAULT,

PRIMARY KEY (WAREHOUSE_ID, SHELF_ID))

RCDFMT WSMSTR

With that, you should have all the tables described in the previous TechTips (tables TBL_WAREHOUSE_MASTER, TBL_WAREHOUSE_SHELF_MASTER, TBL_ITEM_MASTER, and TBL_INVENTORY_MASTER). Now I can insert a couple of items, warehouses, and warehouse shelf definitions in the respective master tables so that I can finally add an item to my inventory. If I want to list that inventory item, however, InvMst is not enough. The item and warehouse descriptions are not shown because they’re in separate tables. You already know how to solve this, right? Just write a SELECT statement with an inner join, and you’re done—but you’ll need to add that inner join to all the SELECT statements that need the item and warehouse descriptions, which is not very friendly. That’s where the view concept comes into play. You already know that a view is similar to a non-keyed logical file; now let’s see how to create one. SQL’s VIEW syntax is the following:

CREATE VIEW <view name> FOR SYSTEM NAME <view system name>

(<list of the view’s column names separated by commas>)

AS

<valid Select statement, containing the same number of columns as specified in the view’s column names list>

RCDFMT <record format name>

I know it looks a bit messy, but it’s actually simple. Here’s an example of a view containing the data from the inventory master table, plus the item and warehouse descriptions:

CREATE VIEW VIEW_ITEMS_IN_INVENTORY FOR SYSTEM NAME V_INVMST01

(ITEM_ID, ITEM_DESCRIPTION, LOT_NUMBER, EXPIRATION_DATE, WAREHOUSE_ID, WAREHOUSE_NAME, SHELF_ID, ITEM_IN_UNITS, ITEM_QUANTITY)

AS

SELECT      INV.ITEM_ID

            , ITM.ITEM_DESC

            , INV.LOTNBR

            , INV.EXPDATE

            , INV.WHID

            , WH.WAREHOUSE_NAME

            , INV.SHELF_ID

            , INV.ITEMUN

            , INV.ITEMQTY

FROM        MYSCHEMA.INVMST

INNER JOIN  ITMMST ITM ON INV.ITEM_ID = ITM.ITEM_ID

INNER JOIN  WHMST WH ON INV.WHID = WH.WHID

RCDFMT INVMST01R

This statement has three parts:

  • The VIEW identification
  • The list of column names, which can be different from the “original” column names that come from the third part of the VIEW statement
  • A valid SELECT statement, as simple or complex as you’d like, that supplies a number of columns equal to that in the view’s column names

The SELECT statement looks a bit complex because of the inner joins, but it doesn’t include a WHERE clause, so every item in inventory is accessible using this view. You’d use it as you’d use a logical file, in the SQL or RPG environments. Note that I didn’t specify “system names” for the view’s columns, so in an RPG context, the column names would appear a bit garbled, with the first four characters and a 00001 suffix, instead of the full name of the column. I can create a simpler view containing all the columns of a certain table, but not all the records. For instance, if I want a view over the InvMst table that includes inventory items from warehouse 333 and don’t want to rename the “original” columns, I can simply write this:

CREATE VIEW VIEW_WAREHOUSE_333_INVENTORY FOR SYSTEM NAME V_INVMST02

AS

SELECT      *

FROM        MYSCHEMA.INVMST

WHERE       WHID = 333

RCDFMT INVMST02R

As you can see, this is a much shorter view definition. It contains the bare minimums (the view SQL name and a SELECT statement), plus the view’s system name and an alternate record format name. From these two examples, you’ve seen that views are similar to logical files. In fact, this last one is similar to a logical file with a (S)elect option over InvMst. However, unlike a logical file, an SQL VIEW doesn’t provide a built-in index; you need to create your own. That’s what we’ll be talking about in the next TechTip.

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: