Heres how to get started importing DB2/400 data into an Excel 97 workbook using OLE DB. Brant Klepel, IBMs AS/400 OLE DB team leader, builds a complete sample application from scratch and explains the ins and outs of this technique, showing you how to increase your Excel programming efficiency and offering some programming tips along the way.
As IBMs project leader for the AS/400 OLE DB provider, I receive a lot of questions about using the provider in different tools. In this article, I explain how the Client Access Express for Windows (Express client) OLE DB provider works with Microsoft Excel 97 through VBScript macros, illustrating how to build and customize Excel applications that read and update AS/400 database files. After you understand how easy it is, youll be slam-dunking AS/400 data into Excel in no time.
For this piece, Im assuming that you are already familiar with ActiveX Data Objects (ADO), OLE DB, and the IBM AS/400 Software Developers Kit (SDK) for ActiveX and OLE DB. In Express client, the SDK has been eliminated and merged into the Client Access Express Toolkit (also called the Express client toolkit). To load the Express client toolkit onto your machine, you must perform an Express client custom installation and select the Client Access Express Toolkit option. If Express client is already installed, you can also install the toolkit from the Selective Setup icon.
Getting Started with Excel
The hardest part about slam-dunking AS/400 data into Excel is figuring out what Excel interfaces are available for spreadsheet manipulation. To begin, specify the Help for Visual Basic option when you install Excel. (To do this, perform a Custom Excel installation and select Help for Visual Basic under the Help and Sample Files install component.) This is the online help text for your Excel programming. The other source that answers your questions is Matthew Harris Teach Yourself Excel Programming with Visual Basic for Applications in 21 Days. (Although this book is currently out of print, you might be able to find it at your local library.)
For this example, I have used the DDS shown in Figure 1 to create an AS/400 file called CUSTOMER in the ACTIVEXSDK library. You may use a different library, but be sure to use the same DDS that I have listed here, complete with field names in the proper order, or else your VBScript will not work.
To access OS/400 data in Excel, start Excel and open a new workbook. Select Tools/Macro/Visual Basic Editor to create your VBScript. Once inside the editor, select Tools/References to set your project references. You need to select Microsoft ActiveX Data Objects (msado10.dll or msado15.dll) and AS/400 Express Toolkit Table Index Library
1.2 (cwbzzidx.dll), which are the Component Object Model (COM) objects you will be using in your programming.
To add code, right-click on This Workbook in the Project Explorer and select View Code. Then add the General Declarations as shown in Figure 2. You open your CUSTOMER file and read records through an SQL SELECT statement. You will also open that same file for updates using record-level access.
Add the code shown in Figure 3 to the end of your code window. This code runs every time you open the workbook and follows a predefined path for accessing AS/400 records. It first opens the AS/400 connection and then opens the CUSTOMER file for update. Next, it calls the READ routine to execute SQL statements and load the records into your Excel spreadsheet. Finally, it sets the Ctrl+Shift+R, A, U, and D keys to call the appropriate read, add, update, and delete record routines. Change this code for your AS/400 system name, user ID, password, library, and file name. In addition, change these items in every other code module you load into this workbooks code window so your VBScript functions correctly.
There are a couple of important items in the Workbook_Open routine. First, notice that you can bypass user ID and password information when opening the connection, avoiding an Express client prompt for security information. In the Windows 95/NT client, bypassing user IDs and passwords is honored only when the latest service pack has been installed and the connection uses record-level access. With Express client, user ID and password bypassing avoids prompting for all OLE DB provider functions.
Also, after you open the record-level access recordset, you must execute the Move Previous command. To understand why this is necessary, you must first understand cursor type and lock type. The IBMDA400 provider always opens a record-level access table as a dynamic cursor. That is, your application immediately sees all other record updates, inserts, and deletions as you move from record to record. The lock type is always pessimistic. To avoid updates by others, the current record always locks when the file is opened for update. When you open a recordset using ADO, you are automatically positioned at the first record. Consequently, coding a Move Previous statement moves you off the first record and releases the record lock so other applications can open the same file for update. This point is very important.
Paste the code shown in Figure 4 to the end of your code window so you can create the Read subroutine. This code executes the SQL SELECT statement and inserts the results into the recordset object. An SQL recordset using the IBMDA400 provider differs from the record-level access recordset. The SQL recordset always contains a static cursor. The recordset is a snapshot in time of the actual database file, and any changes to database file records following the snapshot are not updated in the SQL recordset object. No record locking is performed in this case. The reason for using SQL to read the records instead of using record-level access is that SQL supports blocked reads. With just one AS/400 server request, you can transfer multiple records back to the PC client. IBMDA400 SQL performs better than record-level access for multiple AS/400 reads. Record-level access performs better for single-record insert, update, and delete operations. By combining these techniques, you have created the most efficient application using both SQL and record-level access support.
Create the worksheet add, update, and delete subroutines by copying the code in Figure 5 to the end of your open code window. You can see that each of these routines
returns the recordset position to Beginning of File (BOF) after each operation to avoid record locking.
To complete the application, add the code in Figure 6 to create the Workbook_BeforeClose subroutine. This code runs every time the workbook closes. To save the VBScript in your workbook, click on File/Save in Visual Basic Editor to save the VBScript code you entered. Finally, close and save your Excel workbook.
Ready to Run
The next time you open this workbook, it will start a session on your AS/400 and transfer your CUSTOMER file records to your spreadsheet, and each VBScript subroutine can then be called in Excel as a macro. If you type in a new record and press Ctrl+Shift+A, the worksheet adds a record. Change any field (except the CUSTID fieldthe records key fieldwhich this application has not been coded to update) and press Ctrl+Shift+U to update the record. To delete a record, place your cursor on any field in the target records row and press Ctrl+Shift+D. To redisplay all CUSTOMER file records, press Ctrl+Shift+R from anywhere in the spreadsheet.
You can also assign these macros to a command button by using the Excel forms toolbar. If you do not want the Workbook_Open or Workbook_BeforeClose code to run, hold the Shift key down while opening or closing the Excel workbook.
As you can see, inserting AS/400 data into an Excel 97 worksheet is simpler than you think. Once you get a feel for how to code AS/400 access, youll find that programming these functions is easier than slam-dunking a basketball into a six-foot rim.
Reference
A Fast Path to AS/400 Client/Server Using AS/400 OLE DB Support, Redbook (SG24-5183)
Related Reading AS/400 Client/Server Programming with ADO, Microsoft Excel 2000, and OLE DB, AS/400 Network Expert, May/June 1999
Making PC Application-to-AS/400 Programming a Snap with IBMs AS/400 SDK for ActiveX and OLE DB, AS/400 Network Expert, January/February 1999
Programming in Visual Basic Using the IBM AS/400 SDK for ActiveX and OLE DB, MC, October 1998 (also available at www.midrangecomputing.com/mc/98/10)
*************** Beginning of data ************************************
A UNIQUE
A R CUSTREC
A LNAME 20 TEXT('Customer first name')
A FNAME 20 TEXT('Customer last name')
A ADDRESS 20 TEXT('Customer address')
A CUSTID 7 TEXT('Customer number')
A K CUSTID
****************** End of data *************************************** Option Explicit
Public cn_SystemA As New ADODB.Connection
Public ix_SystemA As New AD400.Connection
Public cm_SQL_Customer As New ADODB.Command
Public rs_SQL_Customer As ADODB.Recordset
Public cm_RLA_Customer As New ADODB.Command
Public rs_RLA_Customer As ADODB.Recordset
Public ix_Customer As AD400.Index
Figure 1: Use this DDS to create the AS/400 file accessed through VBScript.
Figure 2: Insert this code into the General Declarations of your VBScript to specify the global ADO objects used by ThisWorkbook.
Private Sub Workbook_Open()
Dim rcds As Variant
Dim parms As Variant
MsgBox "Workbook is opening..."
Application.Caption = "Slam-Dunk Application"
Application.StatusBar = "Connecting to AS/400 SystemA..."
cn_SystemA.Open "provider=IBMDA400;data source=SystemA;", "userid", "password"
ix_SystemA.Open "SystemA", "userid", "password"
Application.StatusBar = "Opening Customer file for update..."
Set cm_RLA_Customer.ActiveConnection = cn_SystemA
cm_RLA_Customer.CommandText = _
"/QSYS.LIB/ACTIVEXSDK.LIB/CUSTOMER.FILE(*FIRST, *NONE)"
cm_RLA_Customer.Properties("Updatability") = 7
cm_RLA_Customer.Parameters.Append cm_RLA_Customer.CreateParameter("P1", _
adChar, adParamInput, 1)
Set rs_RLA_Customer = cm_RLA_Customer.Execute(rcds, parms, adCmdTable)
If Not rs_RLA_Customer.BOF Then
rs_RLA_Customer.MovePrevious
End If
Set ix_Customer = _
ix_SystemA.OpenIndex("/QSYS.LIB/ACTIVEXSDK.LIB/CUSTOMER.FILE(*FIRST, _
*NONE)", "/QSYS.LIB/ACTIVEXSDK.LIB/CUSTOMER.FILE(*FIRST, *NONE)")
Application.StatusBar = "Reading Customer file into spreadsheet..."
Set cm_SQL_Customer.ActiveConnection = cn_SystemA
cm_SQL_Customer.CommandText = "SELECT * FROM ACTIVEXSDK.CUSTOMER _
ORDER BY CUSTID"
cm_SQL_Customer.CommandType = adCmdText
Read
Application.OnKey Key:="^+r", Procedure:="ThisWorkbook.Read"
Application.OnKey Key:="^+a", Procedure:="ThisWorkbook.Add"
Application.OnKey Key:="^+u", Procedure:="ThisWorkbook.Update"
Application.OnKey Key:="^+d", Procedure:="ThisWorkbook.Delete"
End Sub Sub Read()
Dim rowCount As Integer
Dim colCount As Integer
Set rs_SQL_Customer = cm_SQL_Customer.Execute()
Worksheets("Sheet1").Cells.Clear
rowCount = 1
For colCount = 0 To rs_SQL_Customer.Fields.Count - 1
Worksheets("Sheet1").Cells(rowCount, colCount + 1).Value = _
rs_SQL_Customer.Fields(colCount).Name
Next colCount
While Not rs_SQL_Customer.EOF
rowCount = rowCount + 1
For colCount = 0 To rs_SQL_Customer.Fields.Count - 1
Worksheets("Sheet1").Cells(rowCount, colCount + 1).Value = _
rs_SQL_Customer.Fields(colCount).Value
Next colCount
rs_SQL_Customer.MoveNext
Wend
Application.StatusBar = "All records read into spreadsheet."
End Sub Sub Add()
Dim currentRow As Integer
Dim flds As Variant
Dim vals As Variant
currentRow = Selection.Row
flds = Array("LNAME", "FNAME", "ADDRESS", "CUSTID")
vals = Array(Worksheets("Sheet1").Cells(currentRow, 1).Text, _
Worksheets("Sheet1").Cells(currentRow, 2).Text, _
Worksheets("Sheet1").Cells(currentRow, 3).Text, _
Worksheets("Sheet1").Cells(currentRow, 4).Value)
rs_RLA_Customer.AddNew flds, vals
rs_RLA_Customer.Move -1, adBookmarkFirst
Application.StatusBar = "Record added."
End Sub
Sub Update()
Dim currentRow As Integer
Dim Keys As Variant
Dim Bookmark As Variant
Dim flds As Variant
Dim vals As Variant
Figure 3: The Workbook_Open event procedure runs each time the workbook is opened.
Figure 4: The Read subroutine reads all database records into spreadsheet cells.
currentRow = Selection.Row
Keys = Array(Worksheets("Sheet1").Cells(currentRow, 4).Value)
Bookmark = ix_Customer.GetBookmark(Keys, ad400SeekFirstEQ)
rs_RLA_Customer.Move 0, Bookmark
flds = Array("LNAME", "FNAME", "ADDRESS", "CUSTID")
vals = Array(Worksheets("Sheet1").Cells(currentRow, 1).Text, _
Worksheets("Sheet1").Cells(currentRow, 2).Text, _
Worksheets("Sheet1").Cells(currentRow, 3).Text, _
Worksheets("Sheet1").Cells(currentRow, 4).Value)
rs_RLA_Customer.Update flds, vals
rs_RLA_Customer.Move -1, adBookmarkFirst
Application.StatusBar = "Record updated."
End Sub
Sub Delete()
Dim currentRow As Integer
Dim Keys As Variant
Dim Bookmark As Variant
currentRow = Selection.Row
Keys = Array(Worksheets("Sheet1").Cells(currentRow, 4).Value)
Bookmark = ix_Customer.GetBookmark(Keys, ad400SeekFirstEQ)
rs_RLA_Customer.Move 0, Bookmark
rs_RLA_Customer.Delete adAffectCurrent
If Not rs_RLA_Customer.BOF Then
rs_RLA_Customer.Move -1, adBookmarkFirst
End If
Selection.EntireRow.Clear
Application.StatusBar = "Record deleted."
End Sub Private Sub Workbook_BeforeClose(Cancel As Boolean)
MsgBox "Workbook is closing..."
Application.OnKey Key:="^+r"
Application.OnKey Key:="^+a"
Application.OnKey Key:="^+u"
Application.OnKey Key:="^+d"
rs_SQL_Customer.Close
Set rs_SQL_Customer = Nothing
Set cm_SQL_Customer = Nothing
Set ix_Customer = Nothing
rs_RLA_Customer.Close
Set rs_RLA_Customer = Nothing
Set cm_RLA_Customer = Nothing
Set ix_SystemA = Nothing
cn_SystemA.Close
Set cn_SystemA = Nothing
Worksheets("Sheet1").Cells.Clear
Range("A1").Select
Application.Caption = Empty
Application.SaveWorkspace
Application.Quit
End Sub
Figure 6: The Workbook_BeforeClose event procedure runs each time the
workbook is closed.
Figure 5: The Add, Update, and Delete subroutines modify database file records.
LATEST COMMENTS
MC Press Online