|
程序使用游标读分批读取MySQL的数据,但是程序容器却发生OOM
MySQL版本:8.0.25
JDBC版本:8.0.25
JDBC配置:
connectionProperties=useUnicode=true;autoReconnect=true;defaultFetchSize=800;useServerPrepStmts=false;rewriteBatchedStatements=true;useCompression=true;useCursorFetch=true;allowMultiQueries=true
批量程序的OOM日志:
获取dump下来的内存快照后,使用jdk自带的Java visualVM打开后,找到右侧最大的对象:
发现java.lang.Object[]
最大,点击后发现里面存的是ByteArrayRow
类型对象,它是数据库的游标对象,说明在查询数据库的过程中,内存已经溢出,还没来得及转换成实体类,说明此时游标读失效。
通过查看堆栈上的线程报错信息
显示的代码的流程调用的是ClientPreparedStatement
类的方法,没有调用ServerPreparedStatement
类的方法,调用的是客户端来执行,此时是普通读。
利用游标读demo测试,发现游标读的调用时走ServerPreparedStatement
类的方法(下图第3、4行),然后调用ServerPreparedQuery
类的ServerPreparedQuery
方法(下图第1行)
查看源码,ServerPreparedQuery
方法中调用了packet.writeInteger(IntegerDataType.
INT1
,
OPEN_CURSOR_FLAG
)
方法进行游标读。
ClientPreparedStatement
:查询是在客户端准备的。这意味着所有的SQL语句处理,包括参数替换,都在客户端完成,然后作为一个整体发送到服务器,只能普通读。
ServerPreparedStatement
:查询是在服务器端准备的。这意味着SQL语句和其参数在服务器上被处理,这可以利用服务器的某些优化特性,可以普通读、游标读、流式读。
进一步分析,PreparedStatement的具体实现什么时候确定是ClientPreparedStatement还是ServerPreparedStatement?
在调用Connection.prepareStatement()
或Connection.prepareStatement(String sql, int resultSetType, int resultSetConcurrency)
等方法时,JDBC驱动会根据当前的配置和数据库服务器的能力来确定使用哪种PreparedStatement实现。
@Override
public java.sql.PreparedStatement prepareStatement(String sql, int resultSetType, int resultSetConcurrency) throws SQLException {
synchronized (getConnectionMutex()) {
checkClosed();
//
// FIXME: Create warnings if can't create results of the given type or concurrency
//
ClientPreparedStatement pStmt = null;
boolean canServerPrepare = true;
String nativeSql = this.processEscapeCodesForPrepStmts.getValue() ? nativeSQL(sql) : sql;
if (this.useServerPrepStmts.getValue() && this.emulateUnsupportedPstmts.getValue()) {
canServerPrepare = canHandleAsServerPreparedStatement(nativeSql);
}
if (this.useServerPrepStmts.getValue() && canServerPrepare) {
if (this.cachePrepStmts.getValue()) {
synchronized (this.serverSideStatementCache) {
pStmt = this.serverSideStatementCache.remove(new CompoundCacheKey(this.database, sql));
if (pStmt != null) {
((com.mysql.cj.jdbc.ServerPreparedStatement) pStmt).setClosed(false);
pStmt.clearParameters();
}
if (pStmt == null) {
try {
pStmt = ServerPreparedStatement.getInstance(getMultiHostSafeProxy(), nativeSql, this.database, resultSetType,
resultSetConcurrency);
if (sql.length() < this.prepStmtCacheSqlLimit.getValue()) {
((com.mysql.cj.jdbc.ServerPreparedStatement) pStmt).isCacheable = true;
}
pStmt.setResultSetType(resultSetType);
pStmt.setResultSetConcurrency(resultSetConcurrency);
} catch (SQLException sqlEx) {
// Punt, if necessary
if (this.emulateUnsupportedPstmts.getValue()) {
pStmt = (ClientPreparedStatement) clientPrepareStatement(nativeSql, resultSetType, resultSetConcurrency, false);
if (sql.length() < this.prepStmtCacheSqlLimit.getValue()) {
this.serverSideStatementCheckCache.put(sql, Boolean.FALSE);
}
} else {
throw sqlEx;
}
}
}
}
} else {
try {
pStmt = ServerPreparedStatement.getInstance(getMultiHostSafeProxy(), nativeSql, this.database, resultSetType, resultSetConcurrency);
pStmt.setResultSetType(resultSetType);
pStmt.setResultSetConcurrency(resultSetConcurrency);
} catch (SQLException sqlEx) {
// Punt, if necessary
if (this.emulateUnsupportedPstmts.getValue()) {
pStmt = (ClientPreparedStatement) clientPrepareStatement(nativeSql, resultSetType, resultSetConcurrency, false);
} else {
throw sqlEx;
}
}
}
} else {
pStmt = (ClientPreparedStatement) clientPrepareStatement(nativeSql, resultSetType, resultSetConcurrency, false);
}
return pStmt;
}
}
通过debug发现,会走到16行的 canServerPrepare = canHandleAsServerPreparedStatement(nativeSql);
说明在jdbc配置useServerPrepStmts=true
是生效的,emulateUnsupportedPstmts
系统默认值就是true,判断成立。
继续debug,进入canHandleAsServerPreparedStatement
方法
private boolean canHandleAsServerPreparedStatement(String sql) throws SQLException {
if (sql == null || sql.length() == 0) {
return true;
}
if (!this.useServerPrepStmts.getValue()) {
return false;
}
boolean allowMultiQueries = this.propertySet.getBooleanProperty(PropertyKey.allowMultiQueries).getValue();
if (this.cachePrepStmts.getValue()) {
synchronized (this.serverSideStatementCheckCache) {
Boolean flag = this.serverSideStatementCheckCache.get(sql);
if (flag != null) {
return flag.booleanValue();
}
boolean canHandle = StringUtils.canHandleAsServerPreparedStatementNoCache(sql, getServerVersion(), allowMultiQueries,
this.session.getServerSession().isNoBackslashEscapesSet(), this.session.getServerSession().useAnsiQuotedIdentifiers());
if (sql.length() < this.prepStmtCacheSqlLimit.getValue()) {
this.serverSideStatementCheckCache.put(sql, canHandle ? Boolean.TRUE : Boolean.FALSE);
}
return canHandle;
}
}
return StringUtils.canHandleAsServerPreparedStatementNoCache(sql, getServerVersion(), allowMultiQueries,
this.session.getServerSession().isNoBackslashEscapesSet(), this.session.getServerSession().useAnsiQuotedIdentifiers());
}
cachePrepStmts
默认值是false,前面的判断是不成立的,直接走到最后的StringUtils
类的canHandleAsServerPreparedStatementNoCache
方法。
public static boolean canHandleAsServerPreparedStatementNoCache(String sql, ServerVersion serverVersion, boolean allowMultiQueries,
boolean noBackslashEscapes, boolean useAnsiQuotes) {
// Can't use server-side prepare for CALL
if (startsWithIgnoreCaseAndNonAlphaNumeric(sql, "CALL")) {
return false;
}
boolean canHandleAsStatement = true;
boolean allowBackslashEscapes = !noBackslashEscapes;
String quoteChar = useAnsiQuotes ? "\"" : "'";
if (allowMultiQueries) {
if (StringUtils.indexOfIgnoreCase(0, sql, ";", quoteChar, quoteChar,
allowBackslashEscapes ? StringUtils.SEARCH_MODE__ALL : StringUtils.SEARCH_MODE__MRK_COM_WS) != -1) {
canHandleAsStatement = false;
}
} else if (startsWithIgnoreCaseAndWs(sql, "XA ")) {
canHandleAsStatement = false;
} else if (startsWithIgnoreCaseAndWs(sql, "CREATE TABLE")) {
canHandleAsStatement = false;
} else if (startsWithIgnoreCaseAndWs(sql, "DO")) {
canHandleAsStatement = false;
} else if (startsWithIgnoreCaseAndWs(sql, "SET")) {
canHandleAsStatement = false;
} else if (StringUtils.startsWithIgnoreCaseAndWs(sql, "SHOW WARNINGS") && serverVersion.meetsMinimum(ServerVersion.parseVersion("5.7.2"))) {
canHandleAsStatement = false;
} else if (sql.startsWith("/* ping */")) {
canHandleAsStatement = false;
}
return canHandleAsStatement;
}
canHandleAsServerPreparedStatementNoCache
是在不开启缓存的情况下是否能使用ServerPreparedStatement
。
根据后续反馈,游标读不是一直不生效,只是在运行某个sql的时候不生效,为了隐私,这里将这个sql简化为
select * from t;
由于sql不是CALL开头而且jdbc的参数allowMultiQueries=true
会走到15行的代码,indexOfIgnoreCase
方法的意思是在字符串中查找子字符串的位置,忽略大小写,并有选择地跳过由给定标记限定的文本或在注释中的文本。
这行的代码意思在sql语句中查找;的位置,忽略''符号之间的内容,如果不存在,即返回-1,就允许使用**ServerPreparedStatement
,否则使用ClientPreparedStatement
**。经过debug,确实会走到这里。
问题发生路径:开启allowMultiQueries=true
且当前sql带分号 ——>
canHandleAsServerPreparedStatementNoCache
返回值为false ——>
canHandleAsServerPreparedStatement
返回值为false ——>
执行 (ClientPreparedStatement) clientPrepareStatement(nativeSql, resultSetType, resultSetConcurrency, false)
返回ClientPreparedStatement
——>
客户端执行普通读。
allowMultiQueries=true
,其默认值为false(默认设置下会影响到需要多语句执行的场景,可根据实际需要临时开启)。全文完。
合作电话:010-64087828
社区邮箱:greatsql@greatdb.com