Connecting to IBM AS400 server for database operations hangs
Asked Answered
P

4

11

I'm trying to talk to an AS400 in Python. The goal is to use SQLAlchemy, but when I couldn't get that to work I stepped back to a more basic script using just ibm_db instead of ibm_db_sa.

import ibm_db
dbConnection = ibm_db.pconnect("DATABASE=myLibrary;HOSTNAME=1.2.3.4;PORT=8471;PROTOCOL=TCPIP;UID=username;PWD=password", "", "") #this line is where it hangs
print ibm_db.conn_errormsg()

The problem seems to be the port. If I use the 50000 I see in all the examples, I get an error. If I use 446, I get an error. The baffling part is this: if I use 8471, which IBM says to do, I get no error, no timeout, no response whatsoever. I've left the script running for over twenty minutes, and it just sits there, doing nothing. It's active, because I can't use the command prompt at all, but it never gives me any feedback of any kind.

This same 400 is used by the company I work for every day, for logging, emailing, and (a great deal of) database usage, so I know it works. The software we use, which talks to the database behind the scenes, runs just fine on my machine. That tells me my driver is good, the network settings are right, and so on. I can even telnet into the 400 from here.

I'm on the SQLAlchemy and ibm_db email lists, and have been communicating with them for days about this problem. I've also googled it so much I'm starting to run out of un-visited links in my search results. No one seems to have the problem of the connection hanging indefinitely. If there's anything I can try in Python, I'll try it. I don't deal with the 400 directly, but I can ask the guy who does to check/configure whatever I need to. As I said though, several workstations can talk to the 400's database with no problems, and queries run against the library I want to access work fine, if run from the 400 itself. If anyone has any suggestions, I'd greatly appreciate hearing them. Thanks!

Peacetime answered 17/2, 2016 at 15:47 Comment(6)
If you have made any progress on this, it would be great if you shared it here. I was poking around the code for ibm_db_sa to see if anything jumped out at me, and something did: The pyodbc.py module within ibm_db_sa has a class called AS400Dialect_pyodbc, and it has the right value for pyodbc_driver_name. So clearly at least some attempt was made to get SQLAlchemy working with DB2 for i.Shoplifter
I haven't. Well, my app is moving along, but for now I'm relying only on pyodbc. I tried to use SA by connecting to pyodbc, then passing the function that does the connecting to create_engine, but that didn't work.Peacetime
How much does not having the extra functionality of SQLAlchemy hurt you? And how well do you (a) know Python and (b) know SQLAlchemy? The reason I ask is because through a bit more poking and prodding, I have managed to get create_engine() to successfully create an engine, and use that engine to do naked SQL queries. In other words, I can make SQLAlchemy serve as an extremely convoluted wrapper for PyODBC, with no value added. I'm happy to share my findings, but I have never used ORM, so there may well be further issues lurking about before you can fully leverage SQLAlchemy.Shoplifter
So where your knowledge comes in is, if there is any more experimentation and fixing that needs to be done, you may have to roll up your sleeves and get your hands a bit dirty.Shoplifter
I feel comfortable in Python, but I'm new to SQLAlchemy. The main reason for me wanting to use SA is the convenience of ORM, so if all it can handle is straight SQL, I guess I may as well stick to pyodbc. Thanks for following up, though.Peacetime
Well, don't give up on the ORM before trying it first. For all I know, it will work completely once you fix the ODBC connection as I've described in my answer.Shoplifter
S
12

The README for ibm_db_sa only lists DB2 for Linux/Unix/Windows in the "Supported Database" section. So it most likely doesn't work for DB2 for i, at least not right out of the box.

Since you've stated you have IBM System i Access for Windows, I strongly recommend just using one of the drivers that comes with it (ODBC, OLEDB, or ADO.NET, as @Charles mentioned).

Personally, I always use ODBC, with either pyodbc or pypyodbc. Either one works fine. A simple example:

import pyodbc

connection = pyodbc.connect(
    driver='{iSeries Access ODBC Driver}',
    system='11.22.33.44',
    uid='username',
    pwd='password')
c1 = connection.cursor()

c1.execute('select * from qsys2.sysschemas')
for row in c1:
    print row

Now, one of SQLAlchemy's connection methods is pyodbc, so I would think that if you can establish a connection using pyodbc directly, you can somehow configure SQLAlchemy to do the same. But I'm not an SQLAlchemy user myself, so I don't have example code for that.

UPDATE

I managed to get SQLAlchemy to connect to our IBM i and execute straight SQL queries. In other words, to get it to about the same functionality as simply using PyODBC directly. I haven't tested any other SQLAlchemy features. What I did to set up the connection on my Windows 7 machine:

  • Install ibm_db_sa as an SQLAlchemy dialect
    You may be able to use pip for this, but I did it the low-tech way:

    1. Download ibm_db_sa from PyPI.
      As of this writing, the latest version is 0.3.2, uploaded on 2014-10-20. It's conceivable that later versions will either be fixed or broken in different ways (so in the future, the modifications I'm about to describe might be unnecessary, or they might not work).
    2. Unpack the archive (ibm_db_sa-0.3.2.tar.gz) and copy the enclosed ibm_db_sa directory into the sqlalchemy\dialects directory.
  • Modify sqlalchemy\dialects\ibm_db_sa\pyodbc.py

    • Add the initialize() method to the AS400Dialect_pyodbc class
      The point of this is to override the method of the same name in DB2Dialect, which AS400Dialect_pyodbc inherits from. The problem is that DB2Dialect.initialize() tries to set attributes dbms_ver and dbms_name, neither of which is available or relevant when connecting to IBM i using PyODBC (as far as I can tell).
    • Add the module-level name dialect and set it to the AS400Dialect_pyodbc class

Code for the above modifications should go at the end of the file, and look like this:

    def initialize(self, connection):
        super(DB2Dialect, self).initialize(connection)

dialect = AS400Dialect_pyodbc

Note the indentation! Remember, the initialize() method needs to belong to the AS400Dialect_pyodbc class, and dialect needs to be global to the module.

Finally, you need to give the engine creator the right URL:

'ibm_db_sa+pyodbc://username:password@host/*local'

(Obviously, substitute valid values for username, password, and host.)

That's it. At this point, you should be able to create the engine, connect to the i, and execute plain SQL through SQLAlchemy. I would think a lot of the ORM stuff should also work at this point, but I have not verified this.

Shoplifter answered 18/2, 2016 at 23:8 Comment(6)
Well, that seems to work! I can run queries and, obvciously, connect! There's so much out there about using ibm_db for this stuff that I'm surprised straight pyodbc did the job in a minute, whereas ibm_db/ibm_db_sa have failed for days. Now I just have to work out how to hook this back into sqlalchemy. Thanks for the help. Thanks to @Charles as well, for all your answers over the last couple days.Peacetime
I'm having the same issue but only have access to a linux server. I'm assuming pyodbc works only on windows systems. Do you know a solution for linux?Loan
@Loan - maybe you will find something useful here.Shoplifter
@JohnY This definitely helps!Loan
Do you have any experience writing back data to the i database? I have tried many combinations of libraries, dialects, drivers and so on by now but either I'm failing to establish the connection or having trouble writing stuff back to the db. With you solution above I can establish the connection but it seems that I cannot create a new table. Surprisingly, I don't get any error while executing the SQL statement.Awakening
@Awakening - my experience working with the IBM i database using Python is entirely with PyODBC directly. So I don't know if SQLAlchemy is swallowing errors, or if the database isn't reporting any. I will say that in my experience, if an SQL statement doesn't generate an error yet doesn't appear to have worked, it is usually an issue with commitment control (i.e. you tried to make a change but it was never committed). Another fairly common issue is insufficient authority on the i to make the change.Shoplifter
M
2

The way to find out what port is needed is to look at the service table entries on the IBM i.

Your IBM i guy can use the iNav GUI or the green screen Work with Service Table Entry (WRKSRVTBLE) command

Should get a screen like so:

Service                                  Port  Protocol  

as-admin-http                            2001  tcp       
as-admin-http                            2001  udp       
as-admin-https                           2010  tcp       
as-admin-https                           2010  udp       
as-central                               8470  tcp       
as-central-s                             9470  tcp       
as-database                              8471  tcp       
as-database-s                            9471  tcp  
drda                                      446  tcp
drda                                      446  udp     

The default port for the DB is indeed 8471. Though drda is used for "distributed db" operations.

Based upon this thread, to use ibm_db to connect to DB2 on an IBM i, you need the IBM Connect product; which is a commercial package that has to be paid for.

This thread suggests using ODBC via the pyodbc module. It also suggests that JDBC via the JT400 toolkit may also work.

Meyers answered 17/2, 2016 at 18:28 Comment(10)
Thanks for the quick reply. I'll ask them to double check the ports, but I'm told that no one has modified any of those. If I try 446 instead of 8471, I get something like "execution of the SQL statement failed because of an error in the communication data stream that will affect the successful execution of subsequent commands and SQL statements." SQLCode=-30020-0206, SQLState=58009Peacetime
I forgot to say that I have all necessary IBM drivers and products installed (our company has access to those). In fact, other software we use that has to talk to the 400 runs on my machine without problems, so I'm positive that I have all necessary software. Also, I've just gotten confirmation that our ports are set up just like the standard ones (so 446 and 8471 are the two possible ones). Yet, 8471 is the one that hangs and never errors or times out, while 446 errors out within two seconds.Peacetime
To add a bit to Charles' answer, almost all the examples on the net are for DB2 LUW or DB2 for mainframe. You really need exampled for DB2 for IBM i. Also, it's not an AS400, and that's really important when looking for help - if someone posted something as AS/400 it's either ancient, or THEY'RE ancient, and neither is likely to be helpful. Try IBM i or even iSeries.Cowper
My boss, and the other people who work with the system, all call it an AS400, so I figured that was the actual name. Thanks for the clarification on that. Also, I was told on a mailing list to only use 446, not 8471. When I do, I get SQLCode=-30020"0206")"". SQLState=58009. Hey, at least the attempt isn't hanging anymore! I'm sure my username and password are right, as is the host IP address and protocol setting (TCP/IP). I don't know... Do I need to put "http://" in front of the IP address?Peacetime
You say you have the drivers needed. However, I've been working with the IBM i for 20 years and I've never used the IBM Connect product. That includes 6 years at a 4 Billion dollar /yr Fortune 600 company.Meyers
We use ConnectShip, a shipping and package manager. As part of its operation, CS talks to our I Series server. My computer is able to run CS with no problem, establishing a connection to the server through an ADODB connection run in VBScript. I didn't set this machine up, it was set up for me by the company and I was told it had everything necessary to talk to our server. Since CS works, I figured that must be right. In my Start Menu, I have an entry called "IBM System i Series Access for Windows". If you need more information about my system, let me know. Thanks.Peacetime
IBM System i Access for Windows includes ODBC, OLEDB, and ADO.NET drivers for accessing the server. In my 20 years, that's all I've every needed. However, those are not the same as the driver provided by the IBM Connect product. Unless you have the IBM Connect product loaded, I don't think you can use the python ibm_db module.Meyers
I just downloaded and installed what I believe is the set of drivers needed. I got this package from www-01.ibm.com/marketing/iwm/iwm/web/reg/…. I'm not sure if I now have to register some DLLs or something, because I'm still getting the same error as in my previous comment.Peacetime
Per this page, www-01.ibm.com/support/knowledgecenter/SSEPGG_9.7.0/…, you still need a "DB2 Connect™ license key." to use the DS drivers to connect to the i.Meyers
In my (admittedly limited) understanding, Python needs DB2 Connect (or other similar driver) when using ibm_db. That's simply because it provides a pretty standard DRDA connection, e.g., via port 446. If you must use DRDA, options are limited. But the iAccess ODBC driver that works via pyodbc doesn't make the same connection. It connects to the database "host server" over port 8471 and has separate licensing requirements. I use pyodbc to avoid DB2 Connect, like @JohnY in his answer..Ferbam
N
1

Here is an example to work with as400, sqlalchemy and pandas. This exammple take a bunch of csv files and insert with pandas/sqlalchemy. Only works for windows, on linux the i series odbc driver segfaults (Centos 7 and Debian 9 x68_64)

Client is Windows 10.

My as400 version is 7.3

Python is 2.7.14

installed with pip: pandas, pyodbc, imb_db_sa, sqlalchemy

You need to install i access for windows from ftp://public.dhe.ibm.com/as400/products/clientaccess/win32/v7r1m0/servicepack/si66062/

Aditionally the modifications by @JohnY on pyodbc.py C:\Python27\Lib\site-packages\sqlalchemy\dialects\ibm_db_sa\pyodbc.py Change line 99 to

    pyodbc_driver_name = "IBM i Access ODBC Driver"

The odbc driver changed it's name.

#!/usr/bin/env python
# -*- coding: utf-8 -*-
import pandas as pd
import numpy as np
from sqlalchemy import create_engine
import glob

csvfiles=(glob.glob("c:/Users/nahum/Documents/OUT/*.csv"))
df_csvfiles = pd.DataFrame(csvfiles)
for index, row in df_csvfiles.iterrows():
    datastore2=pd.read_csv(str(row[0]), delimiter=',', header=[0],skipfooter=3)
    engine = create_engine('ibm_db_sa+pyodbc://DB2_USER:PASSWORD@IP_SERVER/*local')
    datastore2.to_sql('table', engine, schema='SCHEMA', chunksize=1000, if_exists='append', index=False)

Hope it helps.

Neoplatonism answered 29/12, 2017 at 22:11 Comment(0)
A
0

If you don't need Pandas/SQLAlchemy, just use pyodbc as suggested in John Y's answer. Otherwise, you can try doing what worked for me, below. It's taken from my answer to my own, similar question, which you can check out for more detail on what doesn't work (I tried and failed in so many ways before getting it working).

  1. I created a blank file in my project to appease this message that I was receiving:

    Unable to open 'hashtable_class_helper.pxi': File not found (file:///c:/git/dashboards/pandas/_libs/hashtable_class_helper.pxi).

    (My project folder is C:/Git/dashboards, so I created the rest of the path.)

  2. With that file present, the code below now works for me. For the record, it seems to work regardless of whether the ibm_db_sa module is modified as suggested in John Y's answer, so I would recommend leaving that module alone. Note that although they aren't imported by directly, you need these modules installed: pyodbc, ibm_db_sa, and possibly future (if using Python 2...I forget if it's necessary). If you are using Python 3, I you'll need urllib.parse instead of urllib. I also have i Access 7.1 drivers installed on my computer, which probably came into play.

import urllib
import pandas as pd
from sqlalchemy import create_engine

CONNECTION_STRING = (
    "driver={iSeries Access ODBC Driver};"
    "system=ip_address;"
    "database=database_name;"
    "uid=username;"
    "pwd=password;"
)

SQL= "SELECT..."

quoted = urllib.quote_plus(CONNECTION_STRING)
engine = create_engine('ibm_db_sa+pyodbc:///?odbc_connect={}'.format(quoted))

df = pd.read_sql_query(
    SQL,
    engine,
    index_col='some column'
)
print df
Arsine answered 17/1, 2019 at 19:10 Comment(0)

© 2022 - 2024 — McMap. All rights reserved.