Rewrote transactions for storing extension table data

Affects issues:
- Possibly fixed #1522
- Possibly fixed #1838
This commit is contained in:
Risto Lahtela 2021-04-16 16:28:03 +03:00
parent 53120ad65a
commit a8716e533e
5 changed files with 184 additions and 23 deletions

View File

@ -35,6 +35,7 @@ import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Types;
import java.util.List;
import java.util.UUID;
import static com.djrapitops.plan.storage.database.sql.building.Sql.*;
@ -79,42 +80,60 @@ public class StorePlayerTableResultTransaction extends ThrowawayTransaction {
}
Integer tableID = query(tableID());
deleteOldValues(tableID).execute(connection);
insertNewValues(tableID).execute(connection);
List<Object[]> rows = table.getRows();
Integer oldRowCount = query(currentRowCount(tableID));
int newRowCount = rows.size();
if (oldRowCount < newRowCount) {
updateRows(tableID, oldRowCount, rows);
insertNewRows(tableID, oldRowCount, rows);
} else if (oldRowCount == newRowCount) {
// No need to delete or insert rows
updateRows(tableID, oldRowCount, rows);
} else {
// oldRowCount > newRowCount
updateRows(tableID, newRowCount, rows);
deleteOldRows(tableID, newRowCount);
}
return false;
};
}
private Executable deleteOldValues(int tableID) {
private void deleteOldRows(Integer tableID, int afterRow) {
String sql = DELETE_FROM + TABLE_NAME +
WHERE + TABLE_ID + "=?" +
AND + USER_UUID + "=?";
AND + USER_UUID + "=?" +
AND + ROW_NUMBER + ">=?"; // Since row count is zero indexed and afterRow is size the value should be removed.
return new ExecStatement(sql) {
execute(new ExecStatement(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
statement.setInt(1, tableID);
statement.setString(2, playerUUID.toString());
statement.setInt(3, afterRow);
}
};
});
}
private Executable insertNewValues(int tableID) {
private void insertNewRows(Integer tableID, Integer afterRow, List<Object[]> rows) {
String sql = "INSERT INTO " + TABLE_NAME + '(' +
TABLE_ID + ',' +
USER_UUID + ',' +
VALUE_1 + ',' +
VALUE_2 + ',' +
VALUE_3 + ',' +
VALUE_4 +
") VALUES (?,?,?,?,?,?)";
VALUE_4 + ',' +
ROW_NUMBER +
") VALUES (?,?,?,?,?,?,?)";
return new ExecBatchStatement(sql) {
execute(new ExecBatchStatement(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
int maxColumnSize = Math.min(table.getMaxColumnSize(), 4); // Limit to maximum 4 columns, or how many column names there are.
for (Object[] row : table.getRows()) {
for (int rowNumber = afterRow; rowNumber < rows.size(); rowNumber++) {
Object[] row = rows.get(rowNumber);
statement.setInt(1, tableID);
statement.setString(2, playerUUID.toString());
for (int i = 0; i < maxColumnSize; i++) {
@ -126,9 +145,67 @@ public class StorePlayerTableResultTransaction extends ThrowawayTransaction {
statement.setNull(3 + i, Types.VARCHAR);
}
statement.setInt(7, rowNumber);
statement.addBatch();
}
}
});
}
private void updateRows(Integer tableID, Integer untilRow, List<Object[]> rows) {
String sql = "UPDATE " + TABLE_NAME + " SET " +
VALUE_1 + "=?," +
VALUE_2 + "=?," +
VALUE_3 + "=?," +
VALUE_4 + "=?" +
WHERE + TABLE_ID + "=?" +
AND + USER_UUID + "=?" +
AND + ROW_NUMBER + "=?";
execute(new ExecBatchStatement(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
int maxColumnSize = Math.min(table.getMaxColumnSize(), 4); // Limit to maximum 4 columns, or how many column names there are.
for (int rowNumber = 0; rowNumber < untilRow; rowNumber++) {
Object[] row = rows.get(rowNumber);
for (int valueIndex = 0; valueIndex < maxColumnSize; valueIndex++) {
Object value = row[valueIndex];
setStringOrNull(statement, 1 + valueIndex, value != null ? StringUtils.truncate(value.toString(), 250) : null);
}
// Rest are set null if not 4 columns wide.
for (int valueIndex = maxColumnSize; valueIndex < 4; valueIndex++) {
statement.setNull(1 + valueIndex, Types.VARCHAR);
}
statement.setInt(5, tableID);
statement.setString(6, playerUUID.toString());
statement.setInt(7, rowNumber);
statement.addBatch();
}
}
});
}
private Query<Integer> currentRowCount(Integer tableID) {
String sql = SELECT + "COALESCE(MAX(" + ROW_NUMBER + "), -1) as m" +
FROM + TABLE_NAME +
WHERE + TABLE_ID + "=?" +
AND + USER_UUID + "=?";
return new QueryStatement<Integer>(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
statement.setInt(1, tableID);
statement.setString(2, playerUUID.toString());
}
@Override
public Integer processResults(ResultSet set) throws SQLException {
// add one to the row number, which is 0 indexed
return set.next() ? set.getInt("m") + 1 : 0;
}
};
}

View File

@ -35,6 +35,7 @@ import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Types;
import java.util.List;
import static com.djrapitops.plan.storage.database.sql.building.Sql.*;
import static com.djrapitops.plan.storage.database.sql.tables.ExtensionServerTableValueTable.*;
@ -76,27 +77,43 @@ public class StoreServerTableResultTransaction extends ThrowawayTransaction {
}
Integer tableID = query(tableID());
deleteOldValues(tableID).execute(connection);
insertNewValues(tableID).execute(connection);
List<Object[]> rows = table.getRows();
Integer oldRowCount = query(currentRowCount(tableID));
int newRowCount = rows.size();
if (oldRowCount < newRowCount) {
updateRows(tableID, oldRowCount, rows);
insertNewRows(tableID, oldRowCount, rows);
} else if (oldRowCount == newRowCount) {
// No need to delete or insert rows
updateRows(tableID, oldRowCount, rows);
} else {
// oldRowCount > newRowCount
updateRows(tableID, newRowCount, rows);
deleteOldRows(tableID, newRowCount);
}
return false;
};
}
private Executable deleteOldValues(int tableID) {
private void deleteOldRows(Integer tableID, int afterRow) {
String sql = DELETE_FROM + TABLE_NAME +
WHERE + TABLE_ID + "=?" +
AND + SERVER_UUID + "=?";
AND + SERVER_UUID + "=?" +
AND + ROW_NUMBER + ">=?"; // Since row count is zero indexed and afterRow is size the value should be removed.
return new ExecStatement(sql) {
execute(new ExecStatement(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
statement.setInt(1, tableID);
statement.setString(2, serverUUID.toString());
statement.setInt(3, afterRow);
}
};
});
}
private Executable insertNewValues(int tableID) {
private void insertNewRows(Integer tableID, Integer afterRow, List<Object[]> rows) {
String sql = "INSERT INTO " + TABLE_NAME + '(' +
TABLE_ID + ',' +
SERVER_UUID + ',' +
@ -104,15 +121,17 @@ public class StoreServerTableResultTransaction extends ThrowawayTransaction {
VALUE_2 + ',' +
VALUE_3 + ',' +
VALUE_4 + ',' +
VALUE_5 +
") VALUES (?,?,?,?,?,?, ?)";
VALUE_5 + ',' +
ROW_NUMBER +
") VALUES (?,?,?,?,?,?,?,?)";
return new ExecBatchStatement(sql) {
execute(new ExecBatchStatement(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
int maxColumnSize = Math.min(table.getMaxColumnSize(), 5); // Limit to maximum 5 columns, or how many column names there are.
for (Object[] row : table.getRows()) {
for (int rowNumber = afterRow; rowNumber < rows.size(); rowNumber++) {
Object[] row = rows.get(rowNumber);
statement.setInt(1, tableID);
statement.setString(2, serverUUID.toString());
for (int i = 0; i < maxColumnSize; i++) {
@ -124,9 +143,68 @@ public class StoreServerTableResultTransaction extends ThrowawayTransaction {
statement.setNull(3 + i, Types.VARCHAR);
}
statement.setInt(8, rowNumber);
statement.addBatch();
}
}
});
}
private void updateRows(Integer tableID, Integer untilRow, List<Object[]> rows) {
String sql = "UPDATE " + TABLE_NAME + " SET " +
VALUE_1 + "=?," +
VALUE_2 + "=?," +
VALUE_3 + "=?," +
VALUE_4 + "=?," +
VALUE_5 + "=?" +
WHERE + TABLE_ID + "=?" +
AND + SERVER_UUID + "=?" +
AND + ROW_NUMBER + "=?";
execute(new ExecBatchStatement(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
int maxColumnSize = Math.min(table.getMaxColumnSize(), 5); // Limit to maximum 5 columns, or how many column names there are.
for (int rowNumber = 0; rowNumber < untilRow; rowNumber++) {
Object[] row = rows.get(rowNumber);
for (int valueIndex = 0; valueIndex < maxColumnSize; valueIndex++) {
Object value = row[valueIndex];
setStringOrNull(statement, 1 + valueIndex, value != null ? StringUtils.truncate(value.toString(), 250) : null);
}
// Rest are set null if not 5 columns wide.
for (int valueIndex = maxColumnSize; valueIndex < 5; valueIndex++) {
statement.setNull(1 + valueIndex, Types.VARCHAR);
}
statement.setInt(6, tableID);
statement.setString(7, serverUUID.toString());
statement.setInt(8, rowNumber);
statement.addBatch();
}
}
});
}
private Query<Integer> currentRowCount(Integer tableID) {
String sql = SELECT + "COALESCE(MAX(" + ROW_NUMBER + "), -1) as m" +
FROM + TABLE_NAME +
WHERE + TABLE_ID + "=?" +
AND + SERVER_UUID + "=?";
return new QueryStatement<Integer>(sql) {
@Override
public void prepare(PreparedStatement statement) throws SQLException {
statement.setInt(1, tableID);
statement.setString(2, serverUUID.toString());
}
@Override
public Integer processResults(ResultSet set) throws SQLException {
// add one to the row number, which is 0 indexed
return set.next() ? set.getInt("m") + 1 : 0;
}
};
}

View File

@ -178,7 +178,9 @@ public abstract class SQLDB extends AbstractDatabase {
new LitebansTableHeaderPatch(),
new UserInfoHostnamePatch(),
new ServerIsProxyPatch(),
new UserInfoHostnameAllowNullPatch()
new UserInfoHostnameAllowNullPatch(),
new ServerTableValuesRowNumberPatch(),
new PlayerTableValuesRowNumberPatch()
};
}

View File

@ -35,6 +35,7 @@ public class ExtensionPlayerTableValueTable {
public static final String TABLE_ID = "table_id";
public static final String USER_UUID = "uuid";
public static final String ROW_NUMBER = "row_number";
// All values can be null
public static final String VALUE_1 = "col_1_value";
public static final String VALUE_2 = "col_2_value";
@ -49,6 +50,7 @@ public class ExtensionPlayerTableValueTable {
return CreateTableBuilder.create(TABLE_NAME, dbType)
.column(ID, INT).primaryKey()
.column(USER_UUID, Sql.varchar(36)).notNull()
.column(ROW_NUMBER, INT).notNull()
.column(VALUE_1, Sql.varchar(250))
.column(VALUE_2, Sql.varchar(250))
.column(VALUE_3, Sql.varchar(250))

View File

@ -35,6 +35,7 @@ public class ExtensionServerTableValueTable {
public static final String TABLE_ID = "table_id";
public static final String SERVER_UUID = "uuid";
public static final String ROW_NUMBER = "row_number";
// All values can be null
public static final String VALUE_1 = "col_1_value";
public static final String VALUE_2 = "col_2_value";
@ -50,6 +51,7 @@ public class ExtensionServerTableValueTable {
return CreateTableBuilder.create(TABLE_NAME, dbType)
.column(ID, INT).primaryKey()
.column(SERVER_UUID, Sql.varchar(36)).notNull()
.column(ROW_NUMBER, INT).notNull()
.column(VALUE_1, Sql.varchar(250))
.column(VALUE_2, Sql.varchar(250))
.column(VALUE_3, Sql.varchar(250))