Skip to content
Permalink
Browse files
Fix Network Performance of PgDatabaseMetaData.getTypeInfo() method (#…
…1668)

* Write failing test for use of cache for PgDatabaseMetadata.getTypeInfo()

* Implement cacheSQLTypes() and call from PgDatabaseMetaData.getTypeInfo()
  • Loading branch information
dupski committed Jan 29, 2020
1 parent c266b08 commit beb354eb4dd8196c72b6fa7780187d9f7a491a6d
@@ -9,6 +9,7 @@
import org.postgresql.core.Field;
import org.postgresql.core.Oid;
import org.postgresql.core.ServerVersion;
import org.postgresql.core.TypeInfo;
import org.postgresql.util.ByteConverter;
import org.postgresql.util.GT;
import org.postgresql.util.JdbcBlackHole;
@@ -2301,6 +2302,11 @@ public ResultSet getTypeInfo() throws SQLException {
byte[] bSearchable =
connection.encodeString(Integer.toString(java.sql.DatabaseMetaData.typeSearchable));

TypeInfo ti = connection.getTypeInfo();
if (ti instanceof TypeInfoCache) {
((TypeInfoCache) ti).cacheSQLTypes();
}

while (rs.next()) {
byte[][] tuple = new byte[19][];
String typname = rs.getString(1);
@@ -24,9 +24,13 @@
import java.util.HashMap;
import java.util.Iterator;
import java.util.Map;
import java.util.logging.Level;
import java.util.logging.Logger;

public class TypeInfoCache implements TypeInfo {

private static final Logger LOGGER = Logger.getLogger(TypeInfoCache.class.getName());

// pgname (String) -> java.sql.Types (Integer)
private Map<String, Integer> pgNameToSQLType;

@@ -57,6 +61,7 @@ public class TypeInfoCache implements TypeInfo {
private PreparedStatement getArrayElementOidStatement;
private PreparedStatement getArrayDelimiterStatement;
private PreparedStatement getTypeInfoStatement;
private PreparedStatement getAllTypeInfoStatement;

// basic pg types info:
// 0 - type name
@@ -177,6 +182,74 @@ public Iterator<String> getPGTypeNamesWithSQLTypes() {
return pgNameToSQLType.keySet().iterator();
}

private String getSQLTypeQuery(boolean typnameParam) {
// There's no great way of telling what's an array type.
// People can name their own types starting with _.
// Other types use typelem that aren't actually arrays, like box.
//
// in case of multiple records (in different schemas) choose the one from the current
// schema,
// otherwise take the last version of a type that is at least more deterministic then before
// (keeping old behaviour of finding types, that should not be found without correct search
// path)
StringBuilder sql = new StringBuilder();
sql.append("SELECT typinput='array_in'::regproc as is_array, typtype, typname ");
sql.append(" FROM pg_catalog.pg_type ");
sql.append(" LEFT JOIN (select ns.oid as nspoid, ns.nspname, r.r ");
sql.append(" from pg_namespace as ns ");
// -- go with older way of unnesting array to be compatible with 8.0
sql.append(" join ( select s.r, (current_schemas(false))[s.r] as nspname ");
sql.append(" from generate_series(1, array_upper(current_schemas(false), 1)) as s(r) ) as r ");
sql.append(" using ( nspname ) ");
sql.append(" ) as sp ");
sql.append(" ON sp.nspoid = typnamespace ");
if (typnameParam) {
sql.append(" WHERE typname = ? ");
}
sql.append(" ORDER BY sp.r, pg_type.oid DESC;");
return sql.toString();
}

private int getSQLTypeFromQueryResult(ResultSet rs) throws SQLException {
Integer type = null;
boolean isArray = rs.getBoolean("is_array");
String typtype = rs.getString("typtype");
if (isArray) {
type = Types.ARRAY;
} else if ("c".equals(typtype)) {
type = Types.STRUCT;
} else if ("d".equals(typtype)) {
type = Types.DISTINCT;
} else if ("e".equals(typtype)) {
type = Types.VARCHAR;
}
if (type == null) {
type = Types.OTHER;
}
return type;
}

public void cacheSQLTypes() throws SQLException {
LOGGER.log(Level.FINEST, "caching all SQL typecodes");
if (getAllTypeInfoStatement == null) {
getAllTypeInfoStatement = conn.prepareStatement(getSQLTypeQuery(false));
}
// Go through BaseStatement to avoid transaction start.
if (!((BaseStatement) getAllTypeInfoStatement)
.executeWithFlags(QueryExecutor.QUERY_SUPPRESS_BEGIN)) {
throw new PSQLException(GT.tr("No results were returned by the query."), PSQLState.NO_DATA);
}
ResultSet rs = getAllTypeInfoStatement.getResultSet();
while (rs.next()) {
String typeName = rs.getString("typname");
Integer type = getSQLTypeFromQueryResult(rs);
if (!pgNameToSQLType.containsKey(typeName)) {
pgNameToSQLType.put(typeName, type);
}
}
rs.close();
}

public int getSQLType(int oid) throws SQLException {
return getSQLType(getPGType(oid));
}
@@ -190,32 +263,10 @@ public synchronized int getSQLType(String pgTypeName) throws SQLException {
return i;
}

LOGGER.log(Level.FINEST, "querying SQL typecode for pg type '{0}'", pgTypeName);

if (getTypeInfoStatement == null) {
// There's no great way of telling what's an array type.
// People can name their own types starting with _.
// Other types use typelem that aren't actually arrays, like box.
//
String sql;
// in case of multiple records (in different schemas) choose the one from the current
// schema,
// otherwise take the last version of a type that is at least more deterministic then before
// (keeping old behaviour of finding types, that should not be found without correct search
// path)
sql = "SELECT typinput='array_in'::regproc, typtype "
+ " FROM pg_catalog.pg_type "
+ " LEFT "
+ " JOIN (select ns.oid as nspoid, ns.nspname, r.r "
+ " from pg_namespace as ns "
// -- go with older way of unnesting array to be compatible with 8.0
+ " join ( select s.r, (current_schemas(false))[s.r] as nspname "
+ " from generate_series(1, array_upper(current_schemas(false), 1)) as s(r) ) as r "
+ " using ( nspname ) "
+ " ) as sp "
+ " ON sp.nspoid = typnamespace "
+ " WHERE typname = ? "
+ " ORDER BY sp.r, pg_type.oid DESC LIMIT 1;";

getTypeInfoStatement = conn.prepareStatement(sql);
getTypeInfoStatement = conn.prepareStatement(getSQLTypeQuery(true));
}

getTypeInfoStatement.setString(1, pgTypeName);
@@ -228,23 +279,9 @@ public synchronized int getSQLType(String pgTypeName) throws SQLException {

ResultSet rs = getTypeInfoStatement.getResultSet();

Integer type = null;
Integer type = Types.OTHER;
if (rs.next()) {
boolean isArray = rs.getBoolean(1);
String typtype = rs.getString(2);
if (isArray) {
type = Types.ARRAY;
} else if ("c".equals(typtype)) {
type = Types.STRUCT;
} else if ("d".equals(typtype)) {
type = Types.DISTINCT;
} else if ("e".equals(typtype)) {
type = Types.VARCHAR;
}
}

if (type == null) {
type = Types.OTHER;
type = getSQLTypeFromQueryResult(rs);
}
rs.close();

@@ -0,0 +1,84 @@
/*
* Copyright (c) 2020, PostgreSQL Global Development Group
* See the LICENSE file in the project root for more information.
*/

package org.postgresql.test.jdbc2;

import static org.junit.Assert.assertEquals;

import org.postgresql.core.TypeInfo;
import org.postgresql.jdbc.PgConnection;
import org.postgresql.test.TestUtil;
import org.postgresql.util.TestLogHandler;

import org.junit.After;
import org.junit.Before;
import org.junit.Test;

import java.sql.SQLException;
import java.util.List;
import java.util.logging.Level;
import java.util.logging.LogManager;
import java.util.logging.LogRecord;
import java.util.logging.Logger;
import java.util.regex.Pattern;

/*
* Tests for caching of DatabaseMetadata
*
*/
public class DatabaseMetaDataCacheTest {
private PgConnection con;
private TestLogHandler log;
private Logger driverLogger;
private Level driverLogLevel;

private static final Pattern SQL_TYPE_QUERY_LOG_FILTER = Pattern.compile("querying SQL typecode for pg type");
private static final Pattern SQL_TYPE_CACHE_LOG_FILTER = Pattern.compile("caching all SQL typecodes");

@Before
public void setUp() throws Exception {
con = (PgConnection)TestUtil.openDB();
log = new TestLogHandler();
driverLogger = LogManager.getLogManager().getLogger("org.postgresql");
driverLogger.addHandler(log);
driverLogLevel = driverLogger.getLevel();
driverLogger.setLevel(Level.ALL);
}

@After
public void tearDown() throws Exception {
TestUtil.closeDB(con);
driverLogger.removeHandler(log);
driverLogger.setLevel(driverLogLevel);
log = null;
}

@Test
public void testGetSQLTypeQueryCache() throws SQLException {
TypeInfo ti = con.getTypeInfo();

List<LogRecord> typeQueries = log.getRecordsMatching(SQL_TYPE_QUERY_LOG_FILTER);
assertEquals(0, typeQueries.size());

ti.getSQLType("box"); // this must be a type not in the hardcoded 'types' list
typeQueries = log.getRecordsMatching(SQL_TYPE_QUERY_LOG_FILTER);
assertEquals(1, typeQueries.size());

ti.getSQLType("box"); // this time it should be retrieved from the cache
typeQueries = log.getRecordsMatching(SQL_TYPE_QUERY_LOG_FILTER);
assertEquals(1, typeQueries.size());
}

@Test
public void testGetTypeInfoUsesCache() throws SQLException {
con.getMetaData().getTypeInfo();

List<LogRecord> typeCacheQuery = log.getRecordsMatching(SQL_TYPE_CACHE_LOG_FILTER);
assertEquals("PgDatabaseMetadata.getTypeInfo() did not cache SQL typecodes", 1, typeCacheQuery.size());

List<LogRecord> typeQueries = log.getRecordsMatching(SQL_TYPE_QUERY_LOG_FILTER);
assertEquals("PgDatabaseMetadata.getTypeInfo() resulted in individual queries for SQL typecodes", 0, typeQueries.size());
}
}
@@ -0,0 +1,39 @@
/*
* Copyright (c) 2020, PostgreSQL Global Development Group
* See the LICENSE file in the project root for more information.
*/

package org.postgresql.util;

import java.util.ArrayList;
import java.util.List;
import java.util.logging.Handler;
import java.util.logging.LogRecord;
import java.util.regex.Pattern;

public class TestLogHandler extends Handler {
public List<LogRecord> records = new ArrayList<LogRecord>();

@Override
public void publish(LogRecord record) {
records.add(record);
}

@Override
public void flush() {
}

@Override
public void close() throws SecurityException {
}

public List<LogRecord> getRecordsMatching(Pattern messagePattern) {
ArrayList<LogRecord> matches = new ArrayList<LogRecord>();
for (LogRecord r: this.records) {
if (messagePattern.matcher(r.getMessage()).find()) {
matches.add(r);
}
}
return matches;
}
}

0 comments on commit beb354e

Please sign in to comment.