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