MySQL 驱动会在 JDBC URL 添加 rewriteBatchedStatements 参数时,对 batch 操作进行优化。本文测试各种参数组合的行为,并结合驱动代码简单分析。
batch参数组合行为
useServerPrepStmts 参数
1 2 3
PreparedStatementpsmt= connection.prepareStatement("DELETE FROM t_order WHERE `order_id` = ?"); psmt.setObject(1, 1); psmt.execute();
开启: 使用服务端预编译,先发送 prepared 语句,再发送 excute 语句
不开启: mysql 驱动会将占位符填充后,明文下发sql.
比如 DELETE FROM t_order WHERE order_id = ?; 语句
MySQL 驱动会下发 DELETE FROM t_order WHERE order_id = 1;
allowMultiQueries 参数
1 2
Statementstatement= connection.createStatement(); statement.execute("DELETE FROM t_order WHERE `order_id` = 1;DELETE FROM t_order WHERE `order_id` = 2;");
不开启: 服务端不支持 DELETE FROM t_order WHERE order_id = 1;DELETE FROM t_order WHERE order_id = 2; 这样的批量delete语句
开启: 支持多语句,比如: DELETE FROM t_order WHERE order_id = 1;DELETE FROM t_order WHERE order_id = 2;
rewriteBatchedStatements 参数
1 2 3 4 5 6
PreparedStatementpsmt= connection.prepareStatement("DELETE FROM t_order WHERE `order_id` = ?"); for (inti=1; i <= 500; i++) { psmt.setObject(1, i); psmt.addBatch(); } psmt.executeBatch();
不开启: batch 操作,在 addBatch 时一条条下发参数值。
开启: 在执行 executeBatch 时,将 batch 操作改写后批量下发;改写后的 SQL 比如 DELETE FROM t_order WHERE order_id = 1;DELETE FROM t_order WHERE order_id = 2;…;DELETE FROM t_order WHERE order_id = 500;
useServerPrepStmts+allowMultiQueries 参数
1 2
PreparedStatementpsmt= connection.prepareStatement("DELETE FROM t_order WHERE `order_id` = ?;DELETE FROM t_order WHERE `order_id` = ?;"); psmt.execute();
虽然开启了服务端预编译参数 useServerPrepStmts,但是 MySQL JDBC 驱动会判断预编译 SQL 不支持 allowMultiQueries,会直接转换成客户端预编译,也就时会将占位符赋值后下发到 mysql。
比如对于以下 SQL: DELETE FROM t_order WHERE order_id = ?;DELETE FROM t_order WHERE order_id = ?;
客户端会将占位符填充后发送: DELETE FROM t_order WHERE order_id = 1;DELETE FROM t_order WHERE order_id = 2;
useServerPrepStmts+rewriteBatchedStatements 参数
1 2 3 4 5 6
PreparedStatementpsmt= connection.prepareStatement("DELETE FROM t_order WHERE `order_id` = ?"); for (inti=1; i < 500; i++) { psmt.setObject(1, i); psmt.addBatch(); } psmt.executeBatch();
对于 DELETE FROM t_order WHERE order_id = ? 的 batch 语句,
会转换成 DELETE FROM t_order WHERE order_id = ?;DELETE FROM t_order WHERE order_id = ?;多语句下发,但是服务端返回不支持。
然后客户端再使用客户端预编译尝试发送(会先发送 set multi option on 包,执行完再关闭该标识),然后下发多语句 DELETE FROM t_order WHERE order_id = 1;DELETE FROM t_order WHERE order_id = 2;…;DELETE FROM t_order WHERE order_id = 500;
PreparedStatementpsmt= connection.prepareStatement("DELETE FROM t_order WHERE `order_id` = ?"); for (inti=1; i < 500; i++) { psmt.setObject(1, i); psmt.addBatch(); } psmt.executeBatch();
当执行 batch delete 语句时:
虽然开启了 useServerPrepStmts 预编译参数,但是 MySQL JDBC 驱动会判断预编译 SQL 不支持 allowMultiQueries,会直接转换成客户端预编译,也就将占位符赋值后下发到服务端。
也就是发送 DELETE FROM t_order WHERE order_id = 1;DELETE FROM t_order WHERE order_id = 2;…;DELETE FROM t_order WHERE order_id = 500;
// 计算 maxSizeOfParameterSet: 每个参数中最大的长度 // sizeOfEntireBatch: batch所有参数长度相加 /** * Computes the maximum parameter set size and the size of the entire batch given * the number of arguments in the batch. */ @Override protectedlong[] computeMaxParameterSetSizeAndBatchSize(int numBatchedArgs) {
You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near ‘DELETE FROM t_order WHERE order_id = ?;DELETE FROM t_order WHERE order_id ‘ at line 1