In this article, we'll building the SQL request dynamically.
In the January 2015 CL Corner, Enhancing WRKQRY Reports the Easy Way, we saw how to create an SQL view for use by WRKQRY using the Run SQL (RUNSQL) CL command. I received quite a few notes asking, among other things, for an example of how to build the RUNSQL SQL parameter using variables rather than the static approach taken in the previous article. So today we'll look at what's required to build the SQL parameter using variables/parameters. For demonstration purposes, we'll continue to use the PROJECTS file that was introduced in the previous article.
To get started, we'll create the command Create SQL View (CRTSQLVIEW), which will allow you to specify what you want included in the view. The command source is shown below.
Cmd Prompt('Create SQL View')
Parm Kwd(View) Type(QFile1) Min(1) +
Prompt('View')
Parm Kwd(Table) Type(QFile2) Min(1) +
Prompt('Table')
Parm Kwd(Columns) Type(ColDefn) Min(1) Max(300) +
ListDspl(*Int4) +
Prompt('Columns')
Parm Kwd(Replace) Type(*Char) Len(10) +
Rstd(*Yes) Values(*Yes *No) +
Dft(*Yes) +
Prompt('Replace view')
QFile1: Qual Type(*Name) Len(10) Min(1)
Qual Type(*Name) Len(10) +
SpcVal((*CurLib)) Dft(*CurLib) +
Prompt('Library')
QFile2: Qual Type(*Name) Len(10) Min(1)
Qual Type(*Name) Len(10) +
SpcVal((*Libl) (*CurLib)) Dft(*Libl) +
Prompt('Library')
ColDefn: Elem Type(*Name) Len(10) Min(1) +
Prompt('To column')
Elem Type(*Char) Len(256) InlPmtLen(25) +
SpcVal((*Same)) Dft(*Same) +
Prompt('From')
The CRTSQLVIEW command defines four parameters. The first three parameters are required, with the fourth parameter being optional.
The first parameter, View, is the library qualified name of the SQL view to be created (or, as you will see, replaced). The special value *CURLIB is supported for the library name and is the default.
The second parameter, Table, is the library qualified name of the file that the view will be based on. The special values *LIBL and *CURLIB are supported for the library name, with *LIBL being the default.
The third parameter, Columns, is a list with two elements. The first element is the name we want to associate with the column of data in the view, and the second element is where the column data is to come from. For example, in January we created a column named TskStrDoW (Task start day of week) using the DayName function. That column will be defined later in this article with the CRTSQLVIEW command and a list entry, where the first element is 'TskStrDoW' and the second element is 'Varchar(DayName(TskStrDat), 10)'. And in case you're wondering, no, you won't have to worry about the single quotes around the second element; the command will take care of that in this specific case. The second element, From, supports the special value *SAME, with *SAME being the default. *SAME can be used when the name specified for the first element is the same name we want to use for the second element. For instance, in January we created the column Project and in the Select also used the name Project. *SAME simply avoids having to specify the name a second time. The List Displacement ListDspl) default of *INT2 is also overridden to *INT4 in order to support up to 300 list entries of 268 bytes each. A signed integer (*INT2) can only represent a displacement of up to 32K, which would only support about 120 list entries.
The fourth parameter, Replace, allows you to specify whether an existing view is replaced if a file with the same name exists in the library specified by the View parameter. The supported special values are *YES and *NO, with the default being *YES.
Assuming you have stored the previous command source in member CRTSQLVIEW of source file QCMDSRC, you can create CRTSQLVIEW with the Create Command (CRTCMD) command:
CRTCMD CMD(CRTSQLVIEW) PGM(CRTSQLVIEW)
The previous CRTCMD specified that the Command Processing Program (CPP) for the CRTSQLVIEW command is also named CRTSQLVIEW. Below is the source for this program.
Pgm Parm(&QualView &QualTable &NbrCols &Replace)
Dcl Var(&QualView) Type(*Char) Len(20)
Dcl Var(&View) Type(*Char) Len(10) +
Stg(*Defined) DefVar(&QualView 1)
Dcl Var(&ViewLib) Type(*Char) Len(10) +
Stg(*Defined) DefVar(&QualView 11)
Dcl Var(&QualTable) Type(*Char) Len(20)
Dcl Var(&Table) Type(*Char) Len(10) +
Stg(*Defined) DefVar(&QualTable 1)
Dcl Var(&TableLib) Type(*Char) Len(10) +
Stg(*Defined) DefVar(&QualTable 11)
Dcl Var(&NbrCols) Type(*Int) Len(2)
Dcl Var(&Replace) Type(*Char) Len(10)
Dcl Var(&LstEnt_Ptr) Type(*Ptr)
Dcl Var(&LstEntOfs) Type(*Int) Len(4) +
Stg(*Based) BasPtr(&LstEnt_Ptr)
Dcl Var(&Col_Ptr) Type(*Ptr)
Dcl Var(&Columns) Type(*Char) Len(268) +
Stg(*Based) BasPtr(&Col_Ptr)
Dcl Var(&NbrElems) Type(*Int) Len(2) +
Stg(*Defined) DefVar(&Columns 1)
Dcl Var(&ToCol) Type(*Char) Len(10) +
Stg(*Defined) DefVar(&Columns 3)
Dcl Var(&FromCol) Type(*Char) Len(256) +
Stg(*Defined) DefVar(&Columns 13)
Dcl Var(&CurLib) Type(*Char) Len(10)
Dcl Var(&SQLStmt) Type(*Char) Len(5000)
Dcl Var(&SQLFrom) Type(*Char) Len(4000)
Dcl Var(&X) Type(*Int)
If Cond((&ViewLib *EQ '*CURLIB') *Or +
(&TableLib *EQ '*CURLIB')) Then(Do)
RtvJobA CurLib(&CurLib)
If Cond(&CurLib *EQ '*NONE') Then( +
ChgVar Var(&CurLib) Value('QGPL'))
EndDo
If Cond(&Replace *EQ '*YES') Then( +
ChgVar Var(&SQLStmt) +
Value('Create or Replace View'))
Else Cmd(ChgVar Var(&SQLStmt) +
Value('Create View'))
If Cond(&ViewLib *EQ '*CURLIB') Then( +
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *BCat &CurLib))
Else Cmd(ChgVar Var(&SQLStmt) +
Value(&SQLStmt *BCat &ViewLib))
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *TCat '/' *TCat +
&View *TCat ' (')
ChgVar Var(&SQLFrom) +
Value(') as Select')
DoFor Var(&X) From(1) To(&NbrCols)
If Cond(&X *EQ 1) Then(Do)
ChgVar Var(&LstEnt_Ptr) +
Value(%addr(&NbrCols))
ChgVar Var(%ofs(&LstEnt_Ptr)) +
Value(%ofs(&LstEnt_Ptr) + 2)
EndDo
Else Cmd(Do)
ChgVar Var(%ofs(&LstEnt_Ptr)) +
Value(%ofs(&LstEnt_Ptr) + 4)
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *TCat ',')
ChgVar Var(&SQLFrom) +
Value(&SQLFrom *TCat ',')
EndDo
ChgVar Var(&Col_Ptr) +
Value(%addr(&NbrCols))
ChgVar Var(%ofs(&Col_Ptr)) +
Value(%ofs(&Col_Ptr) + &LstEntOfs)
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *BCat &ToCol)
If Cond(&FromCol *EQ '*SAME') Then( +
ChgVar Var(&SQLFrom) +
Value(&SQLFrom *BCat &ToCol))
Else Cmd( +
ChgVar Var(&SQLFrom) +
Value(&SQLFrom *BCat &FromCol))
EndDo
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *TCat &SQLFrom *BCat +
'from')
Select
When Cond(&TableLib *EQ '*CURLIB') Then( +
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *BCat +
&CurLib *TCat +
'/' *TCat &Table))
When Cond(&TableLib *EQ '*LIBL') Then( +
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *BCat &Table))
Otherwise Cmd( +
ChgVar Var(&SQLStmt) +
Value(&SQLStmt *BCat +
&TableLib *TCat +
'/' *TCat &Table))
EndSelect
RunSQL SQL(&SQLStmt) Commit(*None) Naming(*Sys)
EndPgm
Before getting into the processing of the CRTSQLVIEW program, I would like to make a side note. I was very tempted to use some of the 7.2 CL features mentioned in the previous articles More Tools for the CL Developer and Still More Tools for the CL Developer when writing the program, but I realize that many of you may still be on 6.1 or 7.1. So I resisted the temptation in order that you can utilize this program on any of the currently supported releases of the IBM i.
The program defines four parameters (&QualView, &QualTable, &NbrCols, and &Replace) to match the four parameters defined by the CRTSQLVIEW command.
&QualView and &QualTable are declared as *CHAR values with lengths of 20 bytes. Using *Defined storage, they are then further subset into the distinct 10-byte *CHAR variables &View, &ViewLib, &Table, and &TableLib. This is done to avoid having to substring out the object and library names later in the program.
&NbrCols is declared as a 2-byte integer value. While this parameter when passed is actually much, much larger (it represents the entire list of columns we'll be working with), what we will initially need is the number of column list entries being passed, which is what &NbrCols represents. The remainder of this parameter will be accessed using pointers.
&Replace is declared as a *Char value with a length of 10 bytes.
Following these parameter declares the program and then declares additional *Ptr and *Based variables, which will be used to process the column list entries found in the third parameter.
When a command list defined using ELEM, as was done in the CRTSQLVIEW command, is passed to the CPP, the first 2-bytes of the parameter hold the number of list entries in integer form. As mentioned before, this is represented by variable &NbrCols. Immediately following this number of list entries is that number (the value of &NbrCols) of 4-byte integer values (due to our use of ListDispl(*Int4) in the command definition) providing offsets from the start of the parameter to where the values of the "next" list entry can be found. To process this "array" of offsets, the program declares the pointer &LstEnt_Ptr (List entry pointer) and the based 4-byte integer &LstEntOfs (List entry offset).
Each list entry accessed using &LstEntOfs is itself further defined by the number of elements in the entry and then that number of element values. To process these elements, the program declares the pointer &Col_Ptr (Column pointer) and then, using *Defined storage, three subfields of the list entry. These subfields are &NbrElems, a 2-byte *INT representing the number of elements passed in this entry; &ToCol, a 10-byte *CHAR representing the value provided for the 'To column' element of this entry; and &FromCol, a 256-byte *CHAR representing the value provided for the 'From' element of this entry.
If the previous two paragraphs leave you a bit confused, don't worry. How these things work should become clearer soon. As a note, the previous two paragraphs could also have been avoided by simply defining two separate lists in the CRTSQLVIEW command—one list for the 'To column' values, one list for the 'From' values. My thinking, though, is that using a two-list approach would have definite usability problems—for instance matching up the 26th 'To column' value with the 26th 'From' value. I chose to make the processing a bit more complex over making the user interface more cumbersome.
The program then declares the four additional variables &CurLib, &SQLStmt, &SQLFrom, and &X.
Upon entry to the CRTSQLVIEW program, a check is made to see if the special value *CURLIB was specified for the library to be used with either the View or Table parameter. If so, then the current library is accessed one time and stored in the variable &CurLib. A check is also made for the current job not having a current library (RTVJOBA setting &CurLib to *NONE) and, if so, the library QGPL is used.
The program now starts building the SQL statement that will be run later by the RUNSQL command. The variable &SQLStmt is used to construct part of this statement. If the user specified REPLACE(*YES) when running the CRTSQLVIEW command, then the value 'Create or Replace View' is written to &SQLStmt; otherwise, the value 'Create View' is written.
Having processed the REPLACE parameter, the CRTSQLVIEW program then constructs the name of the view to be created by concatenating the library and view name, followed by a blank and a '(' to start the definition of the columns to be included in the view.
At this point, I had to make a decision in the implementation of the CRTSQLVIEW program. As any programmer knows, there are many ways to implement a given function. I could, for instance, process only the &ToCol values of the Column parameter to construct the columns being defined, followed by then reprocessing the Column parameter to construct the Select phrase of the Create View statement utilizing &FromCol, or I could build both the ToCol list and the FromCol list concurrently. I elected to build the two lists concurrently, so I use a second variable, &SQLFrom, to contain the FromCol values. As my intention is to concatenate &SQLFrom to &SQLStmt, the program initializes the &SQLFrom variable with the value ') as Select' in anticipation of this later concatenation of the FromCol list.
A DOFOR is then entered to process all of the ToCol and FromCol list values specified on the CRTSQLVIEW command. For the first list entry (&X *EQ 1), the pointer variable &LstEnt_Ptr is set to the address of variable &NbrCols and then the size of &NbrCols (2 bytes) is added to the offset value of the &LstEnt_Ptr variable. This sets the based variable &LstEntOfs to the offset value to the first list entry. For subsequent list entries (&X *NE 1), the offset value of the pointer variable &LstEnt_Ptr is increased by 4, the size in bytes of one &LstEntOfs occurrence. This sets the based variable &LstEntOfs to the offset value of the next entry to be processed. In the case of "next," processing the program also concatenates a comma (',') to the previous value of both &SQLStmt and &SQLFrom. This is to provide a separator between the previous column definition and the "next" entry definition.
Having set &LstEntOfs to the correct list entry offset value, CRTSQLVIEW then sets the pointer variable &Col_Ptr to the starting address of &NbrCols and adds the &LstEntOfs value. This sets the based variable &Columns (and more importantly, the &Columns *Defined subfields of &ToCol and &FromCol) to the appropriate values. The program then concatenates the value of &ToCol to &SQLStmt and, after checking for the special value *SAME, the value of &FromCol to &SQLFrom.
The DOFOR group is then rerun until all list entries have been processed.
After all list entries have been added to &SQLStmt and &SQLFrom, the two variables are concatenated along with the constant 'from'. CRTSQLVIEW then constructs the table name to be used when selecting data (in a manner similar to how the qualified view name was created earlier), adds this to the variable &SQLStmt, and runs the RUNSQL command using &SQLStmt for the SQL parameter. The program then ends.
Assuming you have stored the previous CL source in member CRTSQLVIEW of source file QCLSRC, you can create CRTSQLVIEW with the Create Bound CL Program (CRTBNDCL) command:
CRTBNDCL PGM(CRTSQLVIEW)
Testing CRTSQLVIEW
To test the CRTSQLVIEW command and program, we'll use the same scenario used in the initial testing of the January article. Prompt the CRTSQLVIEW command and fill in the various screens as shown below.
Create SQL View (CRTSQLVIEW)
Type choices, press Enter.
View . . . . . . . . . . . . . . > PROJVIEW Name
Library . . . . . . . . . . . > BVINING Name, *CURLIB
Table . . . . . . . . . . . . . > PROJECTS Name
Library . . . . . . . . . . . > BVINING Name, *LIBL, *CURLIB
Columns:
To column . . . . . . . . . . > PROJECT Name
From . . . . . . . . . . . . . *SAME
To column . . . . . . . . . . > TASK Name
From . . . . . . . . . . . . . *SAME
To column . . . . . . . . . . > CONTACT Name
From . . . . . . . . . . . . . *SAME
To column . . . . . . . . . . > TSKSTRDAT Name
From . . . . . . . . . . . . . *SAME
To column . . . . . . . . . . > TSKSTRDOW Name
From . . . . . . . . . . . . . > Varchar(DayName(TskStrDat), 10)
To column . . . . . . . . . . > TSKENDDAT Name
From . . . . . . . . . . . . . *SAME
To column . . . . . . . . . . > TSKENDDOW Name
From . . . . . . . . . . . . . > Varchar(DayName(TskEndDat), 10)
+ for more values
Replace view . . . . . . . . . . *YES *YES, *NO
You should end up with the same initial view as you did in January.
A Few Notes
You may have noticed that in the CRTSQLVIEW program, an additional parameter was added when running the RUNSQL command. The parameter is Naming(*Sys). I mentioned earlier that I had received several notes concerning the January article, a few of which had to do with the program not working as expected. The reason was that "someone" on their systems had changed the command default value for NAMING from *SYS to *SQL. Explicitly adding the NAMING parameter to the RUNSQL command takes care of this problem (as the CRTSQLVIEW program is definitely construction variable &SQLStmt using the system naming convention of library-name/file-name).
You may also wonder why the DCL for variable &SQLStmt specified a size of 5000 bytes when a CL *CHAR variable can be up to 32K-bytes in size. The reason is that 5000 bytes is the maximum size supported by the SQL parameter of the RUNSQL command. So while the definition of the CRTSQLVIEW command allows up to 300 list entries to be specified, you may or may not be able to actually create a view with that many columns. If, for example, you have 300 'To column' names, each using 10-byte names, then you've already used up more than half of the length of the SQL parameter without even getting to the 'From' values. If this limit of 5000 bytes is a problem, feel free to send me a note. By replacing the RUNSQL command with an API call, we can easily support a Create View statement of up to 32K bytes or, with some additional work, a statement up to 2MB in size. For now though, as this is the "CL Corner," I'm just using the CL RUNQRY command.
In the next article, I hope to answer a few other of the emails related to the January article—namely, what other functions, like DayName, are available to you when creating SQL views.
More CL Questions?
Wondering how to accomplish a function in CL? Send your CL-related questions to me at
LATEST COMMENTS
MC Press Online