Permalink
Browse files

fix: Correct DatabaseMetaData.getFunctions() implementation (#918)

The old DatabaseMetaData.getFunctions() method returned incorrect column names and
function return types. The new implementation complies with the JDBC docs.
  • Loading branch information...
zemian authored and davecramer committed Nov 8, 2017
1 parent 2277ffb commit 8884202b9e7785a1eaf67ddcd97f2ba689d0cf19
@@ -2541,7 +2541,41 @@ public boolean isWrapperFor(Class<?> iface) throws SQLException {

public ResultSet getFunctions(String catalog, String schemaPattern, String functionNamePattern)
throws SQLException {
return getProcedures(catalog, schemaPattern, functionNamePattern);

// The pg_get_function_result only exists 8.4 or later
boolean pgFuncResultExists = connection.haveMinimumServerVersion(ServerVersion.v8_4);

// Use query that support pg_get_function_result to get function result, else unknown is defaulted
String funcTypeSql = DatabaseMetaData.functionResultUnknown + " ";
if (pgFuncResultExists) {
funcTypeSql = " CASE "
+ " WHEN (format_type(p.prorettype, null) = 'unknown') THEN " + DatabaseMetaData.functionResultUnknown
+ " WHEN "
+ " (substring(pg_get_function_result(p.oid) from 0 for 6) = 'TABLE') OR "
+ " (substring(pg_get_function_result(p.oid) from 0 for 6) = 'SETOF') THEN " + DatabaseMetaData.functionReturnsTable
+ " ELSE " + DatabaseMetaData.functionNoTable
+ " END ";
}

// Build query and result
String sql;
sql = "SELECT current_database() AS FUNCTION_CAT, n.nspname AS FUNCTION_SCHEM, p.proname AS FUNCTION_NAME, "
+ " d.description AS REMARKS, "
+ funcTypeSql + " AS FUNCTION_TYPE, "
+ " p.proname || '_' || p.oid AS SPECIFIC_NAME "
+ "FROM pg_catalog.pg_proc p "
+ "INNER JOIN pg_catalog.pg_namespace n ON p.pronamespace=n.oid "
+ "LEFT JOIN pg_catalog.pg_description d ON p.oid=d.objoid "
+ "WHERE pg_function_is_visible(p.oid) ";
if (schemaPattern != null && !schemaPattern.isEmpty()) {
sql += " AND n.nspname LIKE " + escapeQuotes(schemaPattern);
}
if (functionNamePattern != null && !functionNamePattern.isEmpty()) {
sql += " AND p.proname LIKE " + escapeQuotes(functionNamePattern);
}
sql += " ORDER BY FUNCTION_SCHEM, FUNCTION_NAME, p.oid::text ";

return createMetaDataStatement().executeQuery(sql);
}

public ResultSet getFunctionColumns(String catalog, String schemaPattern,
@@ -5,8 +5,11 @@

package org.postgresql.test.jdbc4;

import static org.hamcrest.CoreMatchers.is;
import static org.hamcrest.CoreMatchers.notNullValue;
import static org.junit.Assert.assertEquals;
import static org.junit.Assert.assertNull;
import static org.junit.Assert.assertThat;
import static org.junit.Assert.assertTrue;

import org.postgresql.core.ServerVersion;
@@ -20,6 +23,10 @@
import java.sql.DatabaseMetaData;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.ArrayList;
import java.util.Collections;
import java.util.List;

public class DatabaseMetaDataTest {

@@ -80,4 +87,149 @@ public void testGetSchemas() throws SQLException {
assertNull(rs.getString("TABLE_CATALOG"));
assertTrue(!rs.next());
}

@Test
public void testGetFunctionsWithBlankPatterns() throws SQLException {
int minFuncCount = 1000;
DatabaseMetaData dbmd = _conn.getMetaData();
ResultSet rs = dbmd.getFunctions("", "", "");
int count = assertGetFunctionRS(rs);
assertThat(count > minFuncCount, is(true));

// Should be same as blank pattern
ResultSet rs2 = dbmd.getFunctions(null, null, null);
int count2 = assertGetFunctionRS(rs2);
assertThat(count2 > minFuncCount, is(true));
assertThat(count2, is(count));

// Catalog parameter has no affect on our getFunctions filtering
ResultSet rs3 = dbmd.getFunctions("ANYTHING_WILL_WORK", null, null);
int count3 = assertGetFunctionRS(rs3);
assertThat(count3 > minFuncCount, is(true));
assertThat(count3, is(count));

// Filter by schema
ResultSet rs4 = dbmd.getFunctions("", "pg_catalog", null);
int count4 = assertGetFunctionRS(rs4);
assertThat(count4 > minFuncCount, is(true));

// Filter by schema and function name
ResultSet rs5 = dbmd.getFunctions("", "pg_catalog", "abs");
int count5 = assertGetFunctionRS(rs5);
assertThat(count5 >= 1, is(true));

// Filter by function name only
rs5 = dbmd.getFunctions("", "", "abs");
count5 = assertGetFunctionRS(rs5);
assertThat(count5 >= 1, is(true));

rs.close();
rs2.close();
rs3.close();
rs4.close();
rs5.close();
}

/** Assert some basic result from ResultSet of a GetFunctions method. Return the total row count. */
private int assertGetFunctionRS(ResultSet rs) throws SQLException {
// There should be at least one row
assertThat(rs.next(), is(true));
assertThat(rs.getString("FUNCTION_CAT"), is(System.getProperty("database")));
assertThat(rs.getString("FUNCTION_SCHEM"), notNullValue());
assertThat(rs.getString("FUNCTION_NAME"), notNullValue());
assertThat(rs.getShort("FUNCTION_TYPE") >= 0, is(true));
assertThat(rs.getString("SPECIFIC_NAME"), notNullValue());

// Ensure there is enough column and column value retrieve by index should be same as column name (ordered)
assertThat(rs.getMetaData().getColumnCount(), is(6));
assertThat(rs.getString(1), is(rs.getString("FUNCTION_CAT")));
assertThat(rs.getString(2), is(rs.getString("FUNCTION_SCHEM")));
assertThat(rs.getString(3), is(rs.getString("FUNCTION_NAME")));
assertThat(rs.getString(4), is(rs.getString("REMARKS")));
assertThat(rs.getShort(5), is(rs.getShort("FUNCTION_TYPE")));
assertThat(rs.getString(6), is(rs.getString("SPECIFIC_NAME")));

// Get all result and assert they are ordered per javadoc spec:
// FUNCTION_CAT, FUNCTION_SCHEM, FUNCTION_NAME and SPECIFIC_NAME
List<String> result = new ArrayList<String>();
do {
result.add(rs.getString("FUNCTION_CAT")
+ " "
+ rs.getString("FUNCTION_SCHEM")
+ " "
+ rs.getString("FUNCTION_NAME")
+ " "
+ rs.getString("SPECIFIC_NAME"));
} while (rs.next());

List<String> orderedResult = new ArrayList<String>(result);
Collections.sort(orderedResult);
assertThat(result, is(orderedResult));

return result.size();
}

@Test
public void testGetFunctionsWithSpecificTypes() throws SQLException {
// These function creation are borrow from jdbc2/DatabaseMetaDataTest
// We modify to ensure new function created are returned by getFunctions()

DatabaseMetaData dbmd = _conn.getMetaData();
if (TestUtil.haveMinimumServerVersion(_conn, ServerVersion.v8_4)) {
Statement stmt = _conn.createStatement();
stmt.execute(
"CREATE OR REPLACE FUNCTION getfunc_f1(int, varchar) RETURNS int AS 'SELECT 1;' LANGUAGE SQL");
ResultSet rs = dbmd.getFunctions("", "", "getfunc_f1");
assertThat(rs.next(), is(true));
assertThat(rs.getString("FUNCTION_NAME"), is("getfunc_f1"));
assertThat(rs.getShort("FUNCTION_TYPE"), is((short)DatabaseMetaData.functionNoTable));
assertThat(rs.next(), is(false));
rs.close();
stmt.execute("DROP FUNCTION getfunc_f1(int, varchar)");

stmt.execute(
"CREATE OR REPLACE FUNCTION getfunc_f3(IN a int, INOUT b varchar, OUT c timestamptz) AS $f$ BEGIN b := 'a'; c := now(); return; END; $f$ LANGUAGE plpgsql");
rs = dbmd.getFunctions("", "", "getfunc_f3");
assertThat(rs.next(), is(true));
assertThat(rs.getString("FUNCTION_NAME"), is("getfunc_f3"));
assertThat(rs.getShort("FUNCTION_TYPE"), is((short)DatabaseMetaData.functionNoTable));
assertThat(rs.next(), is(false));
rs.close();
stmt.execute("DROP FUNCTION getfunc_f3(int, varchar)");

// RETURNS TABLE requires PostgreSQL 8.4+
stmt.execute(
"CREATE OR REPLACE FUNCTION getfunc_f5() RETURNS TABLE (i int) LANGUAGE sql AS 'SELECT 1'");

rs = dbmd.getFunctions("", "", "getfunc_f5");
assertThat(rs.next(), is(true));
assertThat(rs.getString("FUNCTION_NAME"), is("getfunc_f5"));
assertThat(rs.getShort("FUNCTION_TYPE"), is((short)DatabaseMetaData.functionReturnsTable));
assertThat(rs.next(), is(false));
rs.close();
stmt.execute("DROP FUNCTION getfunc_f5()");
} else {
// For PG 8.3 or 8.2 it will resulted in unknown function type
Statement stmt = _conn.createStatement();
stmt.execute(
"CREATE OR REPLACE FUNCTION getfunc_f1(int, varchar) RETURNS int AS 'SELECT 1;' LANGUAGE SQL");
ResultSet rs = dbmd.getFunctions("", "", "getfunc_f1");
assertThat(rs.next(), is(true));
assertThat(rs.getString("FUNCTION_NAME"), is("getfunc_f1"));
assertThat(rs.getShort("FUNCTION_TYPE"), is((short)DatabaseMetaData.functionResultUnknown));
assertThat(rs.next(), is(false));
rs.close();
stmt.execute("DROP FUNCTION getfunc_f1(int, varchar)");

stmt.execute(
"CREATE OR REPLACE FUNCTION getfunc_f3(IN a int, INOUT b varchar, OUT c timestamptz) AS $f$ BEGIN b := 'a'; c := now(); return; END; $f$ LANGUAGE plpgsql");
rs = dbmd.getFunctions("", "", "getfunc_f3");
assertThat(rs.next(), is(true));
assertThat(rs.getString("FUNCTION_NAME"), is("getfunc_f3"));
assertThat(rs.getShort("FUNCTION_TYPE"), is((short)DatabaseMetaData.functionResultUnknown));
assertThat(rs.next(), is(false));
rs.close();
stmt.execute("DROP FUNCTION getfunc_f3(int, varchar)");
}
}
}

0 comments on commit 8884202

Please sign in to comment.