Parameter marker swapping in {fn timestampdiff()}

From: Matthew Bellew <matthewb(at)labkey(dot)com>
To: pgsql-jdbc(at)postgresql(dot)org
Subject: Parameter marker swapping in {fn timestampdiff()}
Date: 2023-03-26 22:23:01
Message-ID: CAJnjrPOC6=nMs-Kb07xOwszJDFzeMaV67MBA9+onMLxdqG3TgA@mail.gmail.com
Views: Whole Thread | Raw Message | Download mbox | Resend email
Thread:
Lists: pgsql-jdbc

(moved/reposted from pgsql-bugs)

version info:
Database Product Name PostgreSQL
Database Product Version 14.2
JDBC Driver Name PostgreSQL JDBC Driver
JDBC Driver Version 42.5.3

I recently made a small change to a core utility and our sql tests flagged
some unexpected results. I traced these to timestampdiff(). Below is a
running code function (except for creating the JDBC Connection). I expect
the same result for all three executeQuery() calls. The version that uses
string literals return 366 and the versions that use parameter markers
return -366.

Output:
w/o parameters: 366
w/ parameters: -366
w/ parameters varchar: -366

void testTimestampDiffParameters(Connection conn) throws SQLException
{
// WITHOUT PARAMETERS
try (PreparedStatement stmt = conn.prepareStatement("SELECT {fn
TIMESTAMPDIFF(SQL_TSI_DAY, CAST('01 Jan 2000 12:00' AS TIMESTAMP), CAST('01
Jan 2001 12:00' AS TIMESTAMP))"))
{
try (ResultSet rs = stmt.executeQuery())
{
rs.next();
System.out.println("w/o parameters: " + rs.getInt(1));
}
}

// WITH PARAMETERS
try (PreparedStatement stmt = conn.prepareStatement("SELECT {fn
TIMESTAMPDIFF(SQL_TSI_DAY, CAST(? AS TIMESTAMP), CAST(? AS TIMESTAMP))"))
{
stmt.setString(1,"01 Jan 2000 12:00");
stmt.setString(2,"01 Jan 2001 12:00");
try (ResultSet rs = stmt.executeQuery())
{
rs.next();
System.out.println("w/ parameters: " + rs.getInt(1));
}
}

// WITH PARAMETERS
try (PreparedStatement stmt = conn.prepareStatement("SELECT {fn
TIMESTAMPDIFF(SQL_TSI_DAY, CAST(CAST(? AS VARCHAR(50)) AS TIMESTAMP),
CAST(CAST(? AS VARCHAR(50)) AS TIMESTAMP))"))
{
stmt.setString(1,"01 Jan 2000 12:00");
stmt.setString(2,"01 Jan 2001 12:00");
try (ResultSet rs = stmt.executeQuery())
{
rs.next();
System.out.println("w/ parameters varchar: " +
rs.getInt(1));
}
}
}

Since the parameters to DateDiff are swapped from {fn timestampdiff()}, the
obvious guess would be that the driver is swapping the arguments, but not
remapping the JDBC parameter indexes to the new swapped location.

Thank you,
Matt

Browse pgsql-jdbc by date

  From Date Subject
Next Message Blake McBride 2023-07-20 16:33:10 Executing the same query multiple times gets slow
Previous Message Andy Fan 2023-03-26 08:16:37 Re: Duplicate Proxy.newProxyInstance calls during PGXAConnection.getConnection?