AS400 Query Syntax Help Needed

rhunt

Well Known Member
I am trying to update a custom table we use to store some custom lease information for OneWorld. We need to change some lease numbers to a new number. Using a translation table I am trying a syntax that will work on SQL server...but the AS400 is giving me some trouble. It keeps saying "Inner Join unexpected" Anyone know what is wrong?

UPDATE DEVDTA.F5503

INNER JOIN DEVDTA.TBL_LEASECOPY ON DEVDTA.F5503.CODOCO = DEVDTA.TBL_LEASECOPY.OLDDOCO

SET DEVDTA.F5503.CODOCO = DEVDTA.TBL_LEASECOPY.NEWDOCO;

Thanks

Ryan Hunt
 
UPDATE DEVDTA.F5503 AS A SET A.CODOCO = (
SELECT B.NEWDOCO FROM DEVDTA.TBL_LEASECOPY.OLDOCOSET AS B WHERE
A.CODOCO = B.OLDDOCOSET;

This will update the CODOCO field for ALL records in the F5503 so columns that
don't have a matching OLDDOCOSET in TBL_LEASECOPY will be set to NULL. If you
don't want this behavior, just add a WHERE clause to the end of the statement
which only includes the F5503 records you do wish to update. The only other
thing that gives me pause is that you are joining on the column you are also
updating in the F5503. I'm gonna say this will work but could say for sure
without a little testing (i.e. make backups ;)

BG
 
BG,

Thanks much. I added the WHERE clause you suggested and it worked just fine.

UPDATE PRODDTA.F5503 AS A SET A.CODOCO = (

SELECT B.NEWDOCO FROM PRODDTA.TBL_LEASECOPY AS B WHERE

A.CODOCO = B.OLDDOCO)
WHERE A.CODOCO IN (SELECT B.OLDDOCO FROM PRODDTA.TBL_LEASECOPY AS B);

Thanks!

Ryan
 
Let's see if this comes through. From the As/400 tech tips:

If you use SQL on the iSeries--either interactively using the Start SQL Interactive Session (STRSQL) command or embedded within other programming languages (/EXEC SQL /END-EXEC)--you already know how powerful this language is. One of the most powerful features of SQL is the ability to update a set of records within a table with a single statement. The shortcoming of the UPDATE statement is that it must be based on a single file, meaning that you can't use a JOIN clause to read data from multiple files to define the conditions or values for the fields to be updated. There is a workaround, however, and this TechTip explains it.
Single File Update
Before I describe how to perform updates using multiple files, take a look at the standard format of the SQL UPDATE statement, as shown in Figure 1.
UPDATE filename SET field1 = value1, field2 = value2 ... WHERE condition_field1 = criteria1 AND condition_field2 = criteria2

Figure 1: The SQL UPDATE statement is used to modify file data.

Within this statement, filename indicates the file name. This value can be specified as the fully qualified library/filename or library.filename, depending on whether you are using the *SYS or the *SQL naming format. The field1 and field2 values represent the names of fields within your file to be updated. Value1 and value2 indicate the values to be assigned to the respective fields. The condition_fieldx and criteriax values define the criteria used to select the records to be updated.

You'd use the SQL statement shown in Figure 2 to set the value of the field PURGE to 'YES' for all records in which the value of the field ORDATE is less than or equal to 20030101 within the file MYLIB.ORDERS.
UPDATE MYLIB.ORDERS SET PURGE = 'YES' WHERE ORDATE <= 20030101

Figure 2: This simple update statement updates a single field.

This example will update any records matching your defined criteria with the specified constant value. Many times, however, the criteria cannot be found in the table to be updated. But you can achieve that by using SUB-SELECT.
Criteria Using SUB-SELECT
In cases where the criteria or a portion of the criteria for records to be updated exists within another table, the solution is to replace the criteria value with an SQL SELECT statement. A good example would be when you want to update a value in an order line detail file based on a value from the order header, as shown in Figure 3.
UPDATE MYLIB.ORDLINS SET ODPURG = 'YES' WHERE ODORDR = (SELECT OHORDR FROM MYLIB.ORDHEAD WHERE OHORDR=ODORDR AND OHODAT<20030101)

Figure 3: This example uses an embedded SQL statement as part of the criteria.

In this example, the SUB-SELECT will return only records in which the order number field from the two files match and the order date from the header is less than 20030101. The WHERE clause from the UPDATE statement will find a match only for those records returned by the SUB-SELECT shown. The WHERE clause in the SUB-SELECT is able to use values from the file you are updating--in this case, the field ODORDR comes from the file MYLIB.ORDLINS, which is what you're updating. The result is that your update is based on criteria contained in a file other than the file to be updated.
Update Values from a SUB-SELECT
When performing an SQL UPDATE, there are often times when not only a criterion is based on values from another file, but also the value of the field to be updated. A good example would be updating a total quantity on a header record by summarizing the values from the line details. You can do this by using SUB-SELECT in a method similar to that used earlier. Figure 4 shows an example of this type of SQL UPDATE.
UPDATE MYLIB.ORDHEAD SET OHOTOT = (SELECT SUM(ODOQTY) FROM MYLIB.ORDLINS WHERE ODORDR=OHORDR) WHERE OHODAT<20030101

Figure 4: This example uses a SUB-SELECT to calculate a field value.

This example uses the SUB-SELECT as the target for the SET clause. When the statement is run, the value of the field ODOQTY in the file ORDLINS will be summarized for all records where the value of ODORDR is equal to the field OHORDR from ORDHEAD (the file to be updated). Again, you use a value from the "primary" file, ORDHEAD, within the WHERE clause of the SUB-SELECT.

It's important to remember that the SUB-SELECT used must return only one value for each record in the file to be updated, meaning that there must be a one-to-one relationship between each record in the file to be updated and the value returned by the SUB-SELECT. If not, you'll get an SQL0811 error stating that the result of the select is more than one row. The same would be true when using the SUB-SELECT as part of the WHERE clause. This is not a problem in this example because the SUM() function summarizes all records within the ODORDR file that match the criteria.
Using Both Methods
My final example combines both methods to use the SUB-SELECT as part of the SET clause and the WHERE clause. This method can be useful when, for example, you want to recalculate an order total in an order header file by summarizing the line details from the order detail file for customers in a specific region based on a value from a customer master file. Figure 5, a modified version of an earlier example, performs this task.
UPDATE MYLIB.ORDHEAD SET OHOTOT = (SELECT SUM(ODOQTY) FROM MYLIB.ORDLINS WHERE ODORDR=OHORDR) WHERE OHCUSN=(SELECT CMCUSN FROM MYLIB.CUSTMAST WHERE CMREGN='NE' AND CMCUSN=OHCUSN)

Figure 5: This example uses SUB-SELECT for both the criteria and the value.

The WHERE clause used in this SQL statement may be a bit confusing at first. The SUB-SELECT statement will return the customer number from the file CUSTMAST for the record where CMCUSN is equal to OHCUSN, only if the value of CMREGN is 'NE'. If this condition is not true, the SUB-SELECT returns a null value, and as a result, the condition WHERE clause will be false. The SUB-SELECT used with the SET clause summarizes the value of the field ODOQTY for all records where the value of the field ODORDR matches the value of OHORDR from ORDHEAD. When this statement is executed, the order total summary will be recalculated for all customers in the region 'NE'.

These examples illustrate how you can use SQL to update data in one file based on values from another. As I've shown, you need to put some careful consideration into each of the SUB-SELECTs used, but this method can be a great time saver when you're performing SQL updates.

Mike Faust is MIS Manager for The Lehigh Group in Macungie, Pennsylvania. Mike is also the author of the books The iSeries and AS/400 Programmer's Guide to Cool Things and Active Server Pages Primer from MC Press. You can contact Mike at [email protected].
 
Back
Top