Just been mucking around with this and having loads of problems, so I thought I'd try and answer your question
as well as including some code/documentation that I could have used earlier today.
First of all, the connection string userid should be
UID and not USER as you've written.
Secondly, what is the
Option parameter you've specified (I'm not saying it's wrong, I just couldn't find any docs on it)
Finally ... there seems to be 2 different flavours for specifying the connection string to connect to DB2. This is the one I got to work
Driver={IBM DB2 ODBC DRIVER};Database=DB2T;Hostname=xxxxx.xx.xxx.xx;Port=nnnn;Protocol=TCPIP;Uid=my_TSO_userid;Pwd=my_TSO_pwd"
How do you know which values to specify for Hostname and port? Simply follow these instructions (assuming your installation is reasonably similar)
Select
All programs, IBM DB2, DB2CLIENTBAS1, Set-up tools, Configuration Assistant
Double-click on the database you're interested in.
In the window shown, check that TCP/IP is selected on the protocol "tab"
Select the TCP/IP "tab" (number 2) and this should you which Hostname and Port number to use in your conection string.
After googling, I found some example code (sorry author, can't find it again)
Code:
'Declare a Connection object
Dim cnDB As New ADODB.Connection
'Declare a Recordset Object
Dim rsRecords As New ADODB.Recordset
Dim counter As Long
'Open the ODBC Connection using this statement (seems like you HAVE to specify the password)
connect_string = "Driver={IBM DB2 ODBC DRIVER};Database=DB2T;Hostname=xxxxxx.xx.xxx.xx;Port=nnnn;Protocol=TCPIP;Uid=my_TSO_userid;Pwd=my_TSO_pwd"
cnDB.Open connect_string
sql = "select * from DB2.table where UC_ORG_NR between '5550000000' and '5550000010' "
' OPEN THE RECORDSET
rsRecords.CursorLocation = adUseClient
' this allows the RecordCount property to work when the db is on the client side
rsRecords.Open sql, cnDB
' Get the number of records found
i = rsRecords.RecordCount
counter = 0
For counter = 0 To rsRecords.Fields.Count - 1
MsgBox rsRecords.Fields(counter).Name
Next
' This copies ALL the selected records into row 2 onwards
Sheets("ADO").Range("A1:C" & i).Offset(1, 0).CopyFromRecordset rsRecords
' Close everything and set the references to nothing
rsRecords.Close
Set rsRecords = Nothing
cnDB.Close
Set cnDB = Nothing
End Sub
One thing that surprised me was the following. If in Excel, you select
Data, From other sources, From Microsoft Query you'll be shown a list of databases to connect to. Select the relevant one and you'll suddenly see a window prompting you for your userid and password.
If I connect to DB2 using other ODBC code (not VBA), I can
exclude the password and ODBC will prompt me it.
Remove the PWD part from the connection string above and the connect fails.
Does anyone know
WHY this is and if there's a way to get round it ? (Don't like the idea of HAVING to include a userform JUST to prompt for the user's password)