Feedback
Did this article resolve your question/issue?

   

Article

PostgreSQL JDBC driver 5.1 returns incorrect Resultset Metadata when using JOIN queries

Information

 
TitlePostgreSQL JDBC driver 5.1 returns incorrect Resultset Metadata when using JOIN queries
URL Namepostgresql-jdbc-driver-5-1-returns-incorrect-resultset-metadatawhen-using-join-queries
Article Number000114374
EnvironmentProduct: Connect for JDBC PostgreSQL Driver
Version : 5.1
OS: JAVA
Database : PostgreSQL
Application: All supported applications
Question/Problem Description

When there is a parenthesis around the joined tables, table name is the Resultset metadata is incorrect or missing.
Please see the SQLs below. All are equivalent and return the exact results.
However, Resultset metadata is incorrect or missing in 2 of the cases.

Case 1 - Table Name correctly returns as "part" :
SELECT  p_brand FROM PART INNER JOIN PARTSUPP ON p_partkey=ps_partkey INNER JOIN SUPPLIER ON (ps_suppkey = s_suppkey) 

Case 2 - Table Name returned is empty string :
SELECT  p_brand  FROM  (PART INNER JOIN PARTSUPP ON p_partkey=ps_partkey) INNER JOIN SUPPLIER ON (ps_suppkey = s_suppkey) 

Case 3 - Table Name returned is "supplier" which is incorrect  because column "p_brand" is only defined in the table "part":
SELECT  p_brand  FROM  SUPPLIER, (PART INNER JOIN PARTSUPP ON p_partkey=ps_partkey) WHERE (ps_suppkey = s_suppkey) 
 

Steps to ReproduceCreate the following tables:

CREATE TABLE part ( p_partkey INTEGER NOT NULL,
p_name VARCHAR(55) NOT NULL,
p_mfgr CHAR(25) NOT NULL,
p_brand CHAR(10) NOT NULL,
p_type VARCHAR(25) NOT NULL,
p_size INTEGER NOT NULL,
p_container CHAR(10) NOT NULL,
p_retailprice DECIMAL(15,2) NOT NULL,
p_comment VARCHAR(23) NOT NULL,
PRIMARY KEY (p_partkey));

CREATE TABLE supplier ( s_suppkey INTEGER NOT NULL,
s_name CHAR(25) NOT NULL,
s_address VARCHAR(40) NOT NULL,
s_nationkey INTEGER NOT NULL,
s_phone CHAR(15) NOT NULL,
s_acctbal DECIMAL(15,2) NOT NULL,
s_comment VARCHAR(101) NOT NULL,
PRIMARY KEY (s_suppkey)
);

CREATE TABLE partsupp ( ps_partkey INTEGER NOT NULL,
ps_suppkey INTEGER NOT NULL,
ps_availqty INTEGER NOT NULL,
ps_supplycost DECIMAL(15,2) NOT NULL,
ps_comment VARCHAR(199) NOT NULL,
PRIMARY KEY (ps_partkey, ps_suppkey),
FOREIGN KEY (ps_partkey) REFERENCES part (p_partkey),
FOREIGN KEY (ps_suppkey) REFERENCES supplier (s_suppkey));

Connection URL used : "jdbc:datadirect:postgresql://<hostname>:,port number>;User=<user id>;Password=<password>;ResultSetMetaDataOptions=1"

Java code snippets used:

Statement stmt = con.createStatement();
PreparedStatement ps = con.prepareStatement("SELECT p_brand FROM PART INNER JOIN PARTSUPP ON p_partkey=ps_partkey INNER JOIN SUPPLIER ON (ps_suppkey = s_suppkey)");
// you can do the same for other queries
ResultSet rs = ps.executeQuery();
ResultSetMetaData resultSetMetaData = rs.getMetaData();
System.out.println("Table name: "+resultSetMetaData.getTableName(1));
System.out.println("Column name: "+resultSetMetaData.getColumnName(1));
Clarifying Information
Error Message
Defect NumberEnhancement
Enhancement Number
Cause
The current query parser in the driver is not designed to handle JOIN queries to perfection. This information is derived by the driver in emulation mode and not provided by PostgreSQL server.
Hence returning correct source TABLE_NAME for each column in different variation of the JOIN queries is out of the scope for current implementation and hence this would be an enhancement request to the product.
Resolution
It was determined that the Progress Product is functioning as designed.

An enhancement to the product can be requested through the Progress Community via an Ideas submission. Customer feedback is valuable and Idea submissions are monitored by our Product Management team. Enhancement requests are reviewed during the planning phase of each new product release and a list of the enhancements chosen for implementation can be found in the Release Notes documents that accompany each release. Once an Idea is submitted the Progress Software Community will have the opportunity to comment on and vote for the Idea.

For detailed information on how to submit an Idea, please refer to Knowledge Base article  How to submit an enhancement request for a Progress product? 
Workaround
Notes
Last Modified Date11/20/2020 6:55 AM
Files
Disclaimer The origins of the information on this site may be internal or external to Progress Software Corporation (“Progress”). Progress Software Corporation makes all reasonable efforts to verify this information. However, the information provided is for your information only. Progress Software Corporation makes no explicit or implied claims to the validity of this information.

Any sample code provided on this site is not supported under any Progress support program or service. The sample code is provided on an "AS IS" basis. Progress makes no warranties, express or implied, and disclaims all implied warranties including, without limitation, the implied warranties of merchantability or of fitness for a particular purpose. The entire risk arising out of the use or performance of the sample code is borne by the user. In no event shall Progress, its employees, or anyone else involved in the creation, production, or delivery of the code be liable for any damages whatsoever (including, without limitation, damages for loss of business profits, business interruption, loss of business information, or other pecuniary loss) arising out of the use of or inability to use the sample code, even if Progress has been advised of the possibility of such damages.