IBM Support

How to query PostgreSQL data source using Federation Server through JDBC driver

Question & Answer


Question

How to query PostgreSQL data source using Federation Server through JDBC driver?

Cause

Customers want to use Federation server connect to PostgreSQL through JDBC driver.

Answer

To configure a federation to access PostgreSQL data source through JDBC wrapper, you need to provide information about data sources and objects that you want to access. Then create wrapper, server, user mapping and nickname about the tables on remote PostgreSQL data source.

Before you begin

Check the driver FOpostgresql.jar in the path $/INSTANCE_HOME/sqllib/federation/jdbc/lib.

1. Enable Federation server and restart Db2.

# db2 update dbm cfg using federated YES

# db2stop force

# db2start

2. Test the connection to the PostgreSQL data source and verify the service is started correctly.

telnet <greenplum_ip> <port>
If the connection is successful, you receive the following similar output from the command.

# telnet 9.30.101.11 5432
Trying 9.30.101.11...
Connected to 9.30.101.11.


If the connection fails, you will receive an error, please check the PostgreSQL service status.

3. Create wrapper, server, user mapping, nickname, and query the nickname.

(1) For Db2 on Linux or Unix platform

# connect to testdb

# create wrapper "wrapper1" library 'libdb2rcjdbc.so' options(db2_fenced 'y')

# CREATE SERVER server1 TYPE POSTGRESQL WRAPPER "wrapper1" OPTIONS (DRIVER_CLASS  'com.ibm.fluidquery.jdbc.postgresql.PostgreSQLDriver' ,DRIVER_PACKAGE  '/home/db2inst1/sqllib/federation/jdbc/lib/FOpostgresql.jar' , URL  'jdbc:ibm:postgresql://9.30.101.11:5432;DatabaseName=postgres' )

# CREATE USER MAPPING FOR PUBLIC SERVER server1 OPTIONS (REMOTE_AUTHID  'postgres' ,REMOTE_PASSWORD 'password' )
# create nickname nk1 for server1."tb11"

# select * from nk1

col_1

--------------------------

1970-11-23-12.12.12.000000

1999-12-31-12.12.12.000000

  2 record(s) selected.

(2) For Db2 on windows platform

db2 => connect to sample

   Database Connection Information

 Database server        = DB2/NT64 11.5.6.0
 SQL authorization ID   = ADMINIST...
 Local database alias   = SAMPLE

db2 => CREATE SERVER server1 type JDBC options (DRIVER_PACKAGE 'C:\Program Files\IBM\SQLLIB_04\federation\jdbc\lib\FOpostgresql.jar', DRIVER_CLASS  'com.ibm.fluidquery.jdbc.postgresql.PostgreSQLDriver',URL  'jdbc:ibm:postgresql://test1.fyre.ibm.com:5432;DatabaseName=postgres');

db2 => create user mapping for user server server1 options ( REMOTE_AUTHID 'postgres', REMOTE_PASSWORD 'password');

db2 => set passthru server1

db2 => drop table test1

db2 => create table test1(col1 integer, col2 varchar(20))

db2 => insert into test1 values(1, 'haijunshen')

db2 => set passthru reset

db2 => create nickname nk_test1 for server1."test1"

db2 => select * from nk_test1

col1        col2
----------- --------------------
          1 haijunshen

  1 record(s) selected.

[{"Business Unit":{"code":"BU058","label":"IBM Infrastructure w\/TPS"},"Product":{"code":"SSEPGG","label":"Db2 for Linux, UNIX and Windows"},"ARM Category":[{"code":"a8m500000008PkvAAE","label":"Federation"}],"ARM Case Number":"","Platform":[{"code":"PF025","label":"Platform Independent"}],"Version":"All Version(s)","Line of Business":{"code":"LOB10","label":"Data and AI"}}]

Document Information

Modified date:
09 January 2023

UID

ibm11127553