Added named parameters to the BulletinBoardSQLServer.

Added support for H2 SQL engine.
Further generalization of the BulletinBoardSQLServer.
Bulletin-Board-Client-phase_1
Arbel Deutsch Peled 2015-12-12 11:54:52 +02:00
parent 3de54f16a2
commit 520697d121
12 changed files with 502 additions and 281 deletions

View File

@ -47,6 +47,7 @@ dependencies {
compile 'org.glassfish.jersey.containers:jersey-container-servlet:2.22.+'
// JDBC connections
compile 'org.springframework:spring-jdbc:4.2.+'
compile 'org.xerial:sqlite-jdbc:3.7.+'
compile 'mysql:mysql-connector-java:5.1.+'
compile 'com.h2database:h2:1.0.+'
@ -73,8 +74,14 @@ dependencies {
test {
exclude '**/*SQLite*Test*'
exclude '**/*H2*Test*'
exclude '**/*MySql*Test'
exclude '**/*IntegrationTest*'
outputs.upToDateWhen { false }
}
task dbTest(type: Test) {
include '**/*H2*Test*'
include '**/*MySql*Test'
}
task integrationTest(type: Test) {

View File

@ -3,10 +3,12 @@ package meerkat.bulletinboard.sqlserver;
import java.sql.*;
import java.util.*;
import com.google.protobuf.InvalidProtocolBufferException;
import com.google.protobuf.ProtocolStringList;
import meerkat.bulletinboard.BulletinBoardServer;
import meerkat.bulletinboard.sqlserver.mappers.EntryNumMapper;
import meerkat.bulletinboard.sqlserver.mappers.MessageMapper;
import meerkat.bulletinboard.sqlserver.mappers.SignatureMapper;
import meerkat.comm.CommunicationException;
import meerkat.protobuf.BulletinBoardAPI.*;
import meerkat.protobuf.Crypto.Signature;
@ -14,6 +16,13 @@ import meerkat.protobuf.Crypto.SignatureVerificationKey;
import meerkat.crypto.Digest;
import meerkat.crypto.concrete.SHA256Digest;
import javax.sql.DataSource;
import org.springframework.jdbc.core.namedparam.MapSqlParameterSource;
import org.springframework.jdbc.core.namedparam.NamedParameterJdbcTemplate;
import org.springframework.jdbc.support.GeneratedKeyHolder;
import org.springframework.jdbc.support.KeyHolder;
/**
* This is a generic SQL implementation of the BulletinBoardServer API.
*/
@ -27,16 +36,80 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
/**
* Allowed query types.
* Note that each query returned has to comply with the placeholder ("?") requirements written in its comment.
* Note that each query returned has to comply with the parameter names specified ny getParamNames
*/
public static enum QueryType {
FIND_MSG_ID, // Placeholders for: MsgId
INSERT_MSG, // Placeholders for: MsgId, Msg
INSERT_NEW_TAG, // Placeholders for: Tag
CONNECT_TAG, // Placeholders for: EntryNum, Tag
ADD_SIGNATURE, // Placeholders for: EntryNum, SignerId, Signature
GET_SIGNATURES, // Placeholders for: EntryNum
GET_MESSAGES // Placeholders for: N/A
FIND_MSG_ID(new String[] {"MsgId"}),
INSERT_MSG(new String[] {"MsgId","Msg"}),
INSERT_NEW_TAG(new String[] {"Tag"}),
CONNECT_TAG(new String[] {"EntryNum","Tag"}),
ADD_SIGNATURE(new String[] {"EntryNum","SignerId","Signature"}),
GET_SIGNATURES(new String[] {"EntryNum"}),
GET_MESSAGES(new String[] {});
private String[] paramNames;
private QueryType(String[] paramNames) {
this.paramNames = paramNames;
}
public String[] getParamNames() {
return paramNames;
}
}
/**
* This enum provides the standard translation between a filter type and the corresponding parameter name in the SQL query
*/
public static enum FilterTypeParam {
ENTRY_NUM("EntryNum", Types.INTEGER),
MSG_ID("MsgId", Types.BLOB),
SIGNER_ID("SignerId", Types.BLOB),
TAG("Tag", Types.VARCHAR),
LIMIT("Limit", Types.INTEGER);
private FilterTypeParam(String paramName, int paramType) {
this.paramName = paramName;
this.paramType = paramType;
}
private String paramName;
private int paramType;
public static FilterTypeParam getFilterTypeParamName(FilterType filterType) {
switch (filterType) {
case MSG_ID:
return MSG_ID;
case EXACT_ENTRY: // Go through
case MAX_ENTRY:
return ENTRY_NUM;
case SIGNER_ID:
return SIGNER_ID;
case TAG:
return TAG;
case MAX_MESSAGES:
return LIMIT;
default:
return null;
}
}
public String getParamName() {
return paramName;
}
public int getParamType() {
return paramType;
}
}
/**
@ -46,12 +119,21 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
*/
public String getSQLString(QueryType queryType) throws IllegalArgumentException;
public String getCondition(FilterType filterType) throws IllegalArgumentException;
/**
* Used to retrieve a condition to add to an SQL statement that will make the result comply with the filter type
* @param filterType is the filter type
* @param serialNum is a unique number used to identify the condition variables from other condition instances
* @return The SQL string for the condition
* @throws IllegalArgumentException if the filter type used is not supported
*/
public String getCondition(FilterType filterType, int serialNum) throws IllegalArgumentException;
public String getConditionParamTypeName(FilterType filterType) throws IllegalArgumentException;
/**
* @return the string needed in order to connect to the DB.
*/
public String getConnectionString();
public DataSource getDataSource();
/**
* This is used to get a list of queries that together create the schema needed for the DB.
@ -70,6 +152,30 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
}
private Object getParam(MessageFilter messageFilter) {
switch (messageFilter.getType()) {
case MSG_ID: // Go through
case SIGNER_ID:
return messageFilter.getId().toByteArray();
case EXACT_ENTRY: // Go through
case MAX_ENTRY:
return messageFilter.getEntry();
case TAG:
return messageFilter.getTag();
case MAX_MESSAGES:
return messageFilter.getMaxMessages();
default:
return null;
}
}
/**
* This class implements a comparator for the MessageFilter class
* The comparison is done solely by comparing the type of the filter
@ -85,7 +191,7 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
protected SQLQueryProvider sqlQueryProvider;
protected Connection connection;
protected NamedParameterJdbcTemplate jdbcTemplate;
protected Digest digest;
@ -103,18 +209,19 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
this.sqlQueryProvider = sqlQueryProvider;
}
/**
* This method creates the schema in the given DB to prepare for future transactions
* It does not assume anything about the current state of the database
* @throws SQLException
*/
private void createSchema() throws SQLException {
final int TIMEOUT = 20;
Statement statement = connection.createStatement();
statement.setQueryTimeout(TIMEOUT);
for (String command : sqlQueryProvider.getSchemaCreationCommands()) {
statement.executeUpdate(command);
jdbcTemplate.update(command,(Map) null);
}
statement.close();
}
/**
@ -126,13 +233,7 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
digest = new SHA256Digest();
try{
String dbString = sqlQueryProvider.getConnectionString();
connection = DriverManager.getConnection(dbString);
} catch (SQLException e) {
throw new CommunicationException("Couldn't form a connection with the database " + e.getMessage());
}
jdbcTemplate = new NamedParameterJdbcTemplate(sqlQueryProvider.getDataSource());
try {
createSchema();
@ -161,26 +262,18 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
*/
protected void insertNewTags(String[] tags) throws SQLException {
PreparedStatement pstmt;
String sql;
try {
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.INSERT_NEW_TAG);
Map namedParameters[] = new HashMap[tags.length];
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.INSERT_NEW_TAG);
pstmt = connection.prepareStatement(sql);
for (String tag : tags){
pstmt.setString(1, tag);
pstmt.addBatch();
}
pstmt.executeBatch();
pstmt.close();
} catch (SQLException e){
throw new SQLException("Error adding new tags to table: " + e.getMessage());
for (int i = 0 ; i < tags.length ; i++){
namedParameters[i] = new HashMap();
namedParameters[i].put("Tag", tags[i]);
}
jdbcTemplate.batchUpdate(sql, namedParameters);
}
/**
@ -200,10 +293,10 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
if (!verifyMessage(msg)) {
return boolToBoolMsg(false);
}
PreparedStatement pstmt;
ResultSet rs;
String sql;
Map[] namedParameterArray;
byte[] msgID;
long entryNum;
@ -221,36 +314,28 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
msgID = digest.digest();
// Add message to table if needed and store entry number of message.
try {
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.FIND_MSG_ID);
pstmt = connection.prepareStatement(sql);
pstmt.setBytes(1, msgID);
rs = pstmt.executeQuery();
if (rs.next()){
entryNum = rs.getLong(1);
} else{
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.INSERT_MSG);
pstmt = connection.prepareStatement(sql, Statement.RETURN_GENERATED_KEYS);
pstmt.setBytes(1, msgID);
pstmt.setBytes(2, msg.getMsg().toByteArray());
pstmt.executeUpdate();
rs = pstmt.getGeneratedKeys();
rs.next();
entryNum = rs.getLong(1);
}
pstmt.close();
} catch (SQLException e) {
throw new CommunicationException("Error inserting into MsgTable: " + e.getMessage());
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.FIND_MSG_ID);
Map namedParameters = new HashMap();
namedParameters.put("MsgId",msgID);
List<Long> entryNums = jdbcTemplate.query(sql, new MapSqlParameterSource(namedParameters), new EntryNumMapper());
if (entryNums.size() > 0){
entryNum = entryNums.get(0);
} else{
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.INSERT_MSG);
namedParameters.put("Msg", msg.getMsg().toByteArray());
KeyHolder keyHolder = new GeneratedKeyHolder();
jdbcTemplate.update(sql,new MapSqlParameterSource(namedParameters),keyHolder);
entryNum = keyHolder.getKey().longValue();
}
// Retrieve tags and store new ones in tag table.
@ -268,24 +353,18 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
}
// Connect message to tags.
try{
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.CONNECT_TAG);
pstmt = connection.prepareStatement(sql);
pstmt.setLong(1, entryNum);
for (String tag : tags){
pstmt.setString(2, tag);
pstmt.addBatch();
}
pstmt.executeBatch();
pstmt.close();
} catch (SQLException e) {
throw new CommunicationException("Error Linking tags: " + e.getMessage());
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.CONNECT_TAG);
namedParameterArray = new HashMap[tags.length];
for (int i = 0 ; i < tags.length ; i++) {
namedParameterArray[i] = new HashMap();
namedParameterArray[i].put("EntryNum", entryNum);
namedParameterArray[i].put("Tag", tags[i]);
}
jdbcTemplate.batchUpdate(sql, namedParameterArray);
// Retrieve signatures.
@ -294,170 +373,111 @@ public class BulletinBoardSQLServer implements BulletinBoardServer{
signatures = signatureList.toArray(signatures);
// Connect message to signatures.
try{
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.ADD_SIGNATURE);
pstmt = connection.prepareStatement(sql);
pstmt.setLong(1, entryNum);
for (Signature sig : signatures){
pstmt.setBytes(2, sig.getSignerId().toByteArray());
pstmt.setBytes(3, sig.toByteArray());
pstmt.addBatch();
}
pstmt.executeBatch();
pstmt.close();
} catch (SQLException e) {
throw new CommunicationException("Error Linking tags: " + e.getMessage());
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.ADD_SIGNATURE);
namedParameterArray = new HashMap[signatures.length];
for (int i = 0 ; i < signatures.length ; i++) {
namedParameterArray[i] = new HashMap();
namedParameterArray[i].put("EntryNum", entryNum);
namedParameterArray[i].put("SignerId", signatures[i].getSignerId().toByteArray());
namedParameterArray[i].put("Signature", signatures[i].toByteArray());
}
jdbcTemplate.batchUpdate(sql,namedParameterArray);
return boolToBoolMsg(true);
}
@Override
public BulletinBoardMessageList readMessages(MessageFilterList filterList) throws CommunicationException {
PreparedStatement pstmt;
ResultSet messages, signatures;
long entryNum;
BulletinBoardMessageList.Builder resultListBuilder = BulletinBoardMessageList.newBuilder();
BulletinBoardMessage.Builder messageBuilder;
String sql;
MapSqlParameterSource namedParameters;
int paramNum;
MessageMapper messageMapper = new MessageMapper();
SignatureMapper signatureMapper = new SignatureMapper();
List<MessageFilter> filters = new ArrayList<MessageFilter>(filterList.getFilterList());
int i;
boolean tagsRequired = false;
boolean signaturesRequired = false;
boolean isFirstFilter = true;
Collections.sort(filters, new FilterTypeComparator());
// Check if Tag/Signature tables are required for filtering purposes.
// Check if Tag/Signature tables are required for filtering purposes
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.GET_MESSAGES);
// Add conditions.
// Add conditions
if (!filters.isEmpty()){
namedParameters = new MapSqlParameterSource();
if (!filters.isEmpty()) {
sql += " WHERE ";
for (MessageFilter filter : filters){
for (paramNum = 0 ; paramNum < filters.size() ; paramNum++) {
if (filter.getType().getNumber() != FilterType.MAX_MESSAGES_VALUE){
if (isFirstFilter){
MessageFilter filter = filters.get(paramNum);
if (filter.getType().getNumber() != FilterType.MAX_MESSAGES_VALUE) {
if (isFirstFilter) {
isFirstFilter = false;
} else{
} else {
sql += " AND ";
}
}
sql += sqlQueryProvider.getCondition(filter.getType());
sql += sqlQueryProvider.getCondition(filter.getType(), paramNum);
SQLQueryProvider.FilterTypeParam filterTypeParam = SQLQueryProvider.FilterTypeParam.getFilterTypeParamName(filter.getType());
namedParameters.addValue(
filterTypeParam.getParamName() + Integer.toString(paramNum),
getParam(filter),
filterTypeParam.getParamType(),
sqlQueryProvider.getConditionParamTypeName(filter.getType()));
}
}
// Make query.
// Run query
try {
pstmt = connection.prepareStatement(sql);
List<BulletinBoardMessage.Builder> msgBuilders = jdbcTemplate.query(sql, namedParameters, messageMapper);
// Specify values for filters.
i = 1;
for (MessageFilter filter : filters){
// Compile list of messages
switch (filter.getType().getNumber()){
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.GET_SIGNATURES);
case FilterType.EXACT_ENTRY_VALUE: // Go through.
case FilterType.MAX_ENTRY_VALUE:
pstmt.setLong(i, filter.getEntry());
i++;
break;
for (BulletinBoardMessage.Builder msgBuilder : msgBuilders) {
case FilterType.MSG_ID_VALUE: // Go through.
case FilterType.SIGNER_ID_VALUE:
pstmt.setBytes(i, filter.getId().toByteArray());
i++;
break;
// Retrieve signatures
case FilterType.TAG_VALUE:
pstmt.setString(i, filter.getTag());
i++;
break;
namedParameters = new MapSqlParameterSource();
namedParameters.addValue("EntryNum", msgBuilder.getEntryNum());
// The max-messages condition is applied as a suffix. Therefore, it is treated differently.
case FilterType.MAX_MESSAGES_VALUE:
pstmt.setLong(filters.size(), filter.getMaxMessages());
i++;
break;
List<Signature> signatures = jdbcTemplate.query(sql, namedParameters, signatureMapper);
}
}
// Append signatures
msgBuilder.addAllSig(signatures);
// Run query.
// Finalize message and add to message list.
messages = pstmt.executeQuery();
resultListBuilder.addMessage(msgBuilder.build());
// Compile list of messages.
sql = sqlQueryProvider.getSQLString(SQLQueryProvider.QueryType.GET_SIGNATURES);
pstmt = connection.prepareStatement(sql);
while (messages.next()){
// Get entry number and retrieve signatures.
entryNum = messages.getLong(1);
pstmt.setLong(1, entryNum);
signatures = pstmt.executeQuery();
// Create message and append signatures.
messageBuilder = BulletinBoardMessage.newBuilder()
.setEntryNum(entryNum)
.setMsg(UnsignedBulletinBoardMessage.parseFrom(messages.getBytes(2)));
while (signatures.next()){
messageBuilder.addSig(Signature.parseFrom(signatures.getBytes(1)));
}
// Finalize message and add to message list.
resultListBuilder.addMessage(messageBuilder.build());
}
pstmt.close();
} catch (SQLException e){
throw new CommunicationException("Error reading messages from DB: " + e.getMessage());
} catch (InvalidProtocolBufferException e) {
throw new CommunicationException("Invalid data from DB: " + e.getMessage());
}
//Combine results and return.
return resultListBuilder.build();
}
@Override
public void close() throws CommunicationException {
try{
connection.close();
} catch (SQLException e) {
throw new CommunicationException("Couldn't close connection to the database");
}
}
public void close() {}
}

View File

@ -1,7 +1,12 @@
package meerkat.bulletinboard.sqlserver;
import meerkat.protobuf.BulletinBoardAPI.FilterType;
import org.h2.jdbcx.JdbcDataSource;
import javax.naming.Context;
import javax.naming.InitialContext;
import javax.naming.NamingException;
import javax.sql.DataSource;
import java.util.LinkedList;
import java.util.List;
@ -11,10 +16,14 @@ import java.util.List;
public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider {
private String dbConnectionString;
private String dbAddress;
private String username;
private String password;
public H2QueryProvider(String dbAddress) {
dbConnectionString = "jdbc:h2:" + dbAddress + ";MODE=MYSQL";
public H2QueryProvider(String dbAddress, String username, String password) {
this.dbAddress = dbAddress;
this.username = username;
this.password = password;
}
@ -23,20 +32,33 @@ public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider
switch(queryType) {
case ADD_SIGNATURE:
return "INSERT IGNORE INTO SignatureTable (EntryNum, SignerId, Signature) VALUES (?,?,?)";
return "INSERT INTO SignatureTable (EntryNum, SignerId, Signature)"
+ " SELECT DISTINCT :EntryNum AS Entry, :SignerId AS Id, :Signature AS Sig FROM UtilityTable AS Temp"
+ " WHERE NOT EXISTS"
+ " (SELECT 1 FROM SignatureTable AS SubTable WHERE SubTable.SignerId = :SignerId AND SubTable.EntryNum = :EntryNum)";
case CONNECT_TAG:
return "INSERT IGNORE INTO MsgTagTable (TagId, EntryNum)"
+ " SELECT TagTable.TagId, ? AS EntryNum FROM TagTable WHERE Tag = ?";
return "INSERT INTO MsgTagTable (TagId, EntryNum)"
+ " SELECT DISTINCT TagTable.TagId, :EntryNum AS NewEntry FROM TagTable WHERE Tag = :Tag"
+ " AND NOT EXISTS (SELECT 1 FROM MsgTagTable AS SubTable WHERE SubTable.TagId = TagTable.TagId"
+ " AND SubTable.EntryNum = :EntryNum)";
case FIND_MSG_ID:
return "SELECT EntryNum From MsgTable WHERE MsgId = ?";
return "SELECT EntryNum From MsgTable WHERE MsgId = :MsgId";
case GET_MESSAGES:
return "SELECT MsgTable.EntryNum, MsgTable.Msg FROM MsgTable";
case GET_SIGNATURES:
return "SELECT Signature FROM SignatureTable WHERE EntryNum = ?";
return "SELECT Signature FROM SignatureTable WHERE EntryNum = :EntryNum";
case INSERT_MSG:
return "INSERT INTO MsgTable (MsgId, Msg) VALUES(?,?)";
return "INSERT INTO MsgTable (MsgId, Msg) VALUES(:MsgId,:Msg)";
case INSERT_NEW_TAG:
return "INSERT IGNORE INTO TagTable(Tag) VALUES (?)";
return "INSERT INTO TagTable(Tag) SELECT DISTINCT :Tag AS NewTag FROM UtilityTable WHERE"
+ " NOT EXISTS (SELECT 1 FROM TagTable AS SubTable WHERE SubTable.Tag = :Tag)";
default:
throw new IllegalArgumentException("Cannot serve a query of type " + queryType);
}
@ -44,24 +66,26 @@ public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider
}
@Override
public String getCondition(FilterType filterType) throws IllegalArgumentException {
public String getCondition(FilterType filterType, int serialNum) throws IllegalArgumentException {
String serialString = Integer.toString(serialNum);
switch(filterType) {
case EXACT_ENTRY:
return "MsgTable.EntryNum = ?";
return "MsgTable.EntryNum = :EntryNum" + serialString;
case MAX_ENTRY:
return "MsgTable.EntryNum <= ?";
return "MsgTable.EntryNum <= :EntryNum" + serialString;
case MAX_MESSAGES:
return "LIMIT ?";
return "LIMIT :Limit" + serialString;
case MSG_ID:
return "MsgTable.MsgId = ?";
return "MsgTable.MsgId = MsgId" + serialString;
case SIGNER_ID:
return "EXISTS (SELECT 1 FROM SignatureTable"
+ " WHERE SignatureTable.SignerId = ? AND SignatureTable.EntryNum = MsgTable.EntryNum)";
+ " WHERE SignatureTable.SignerId = :SignerId" + serialString + " AND SignatureTable.EntryNum = MsgTable.EntryNum)";
case TAG:
return "EXISTS (SELECT 1 FROM TagTable"
+ " INNER JOIN MsgTagTable ON TagTable.TagId = MsgTagTable.TagId"
+ " WHERE TagTable.Tag = ? AND MsgTagTable.EntryNum = MsgTable.EntryNum)";
+ " WHERE TagTable.Tag = :Tag" + serialString + " AND MsgTagTable.EntryNum = MsgTable.EntryNum)";
default:
throw new IllegalArgumentException("Cannot serve a filter of type " + filterType);
}
@ -69,8 +93,43 @@ public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider
}
@Override
public String getConnectionString() {
return dbConnectionString;
public String getConditionParamTypeName(FilterType filterType) throws IllegalArgumentException {
switch(filterType) {
case EXACT_ENTRY: // Go through
case MAX_ENTRY: // Go through
case MAX_MESSAGES:
return "INT";
case MSG_ID: // Go through
case SIGNER_ID:
return "TINYBLOB";
case TAG:
return "VARCHAR";
default:
throw new IllegalArgumentException("Cannot serve a filter of type " + filterType);
}
}
@Override
public DataSource getDataSource() {
// TODO: Fix this
JdbcDataSource dataSource = new JdbcDataSource();
dataSource.setURL("jdbc:h2:~/" + dbAddress + "/meerkat"); // TODO: make this generic
dataSource.setUser(username);
dataSource.setPassword(password);
// Context ctx = null;
// try {
// ctx = new InitialContext();
// ctx.bind("jdbc/dsName", dataSource);
// } catch (NamingException e) {
// e.printStackTrace();
// }
return dataSource;
}
@ -80,7 +139,7 @@ public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider
list.add("CREATE TABLE IF NOT EXISTS MsgTable (EntryNum INT NOT NULL AUTO_INCREMENT PRIMARY KEY, MsgId TINYBLOB UNIQUE, Msg BLOB)");
list.add("CREATE TABLE IF NOT EXISTS TagTable (TagId INT NOT NULL AUTO_INCREMENT PRIMARY KEY, Tag varchar(50) UNIQUE)");
list.add("CREATE TABLE IF NOT EXISTS TagTable (TagId INT NOT NULL AUTO_INCREMENT PRIMARY KEY, Tag VARCHAR(50) UNIQUE)");
list.add("CREATE TABLE IF NOT EXISTS MsgTagTable (EntryNum INT, TagId INT,"
+ " FOREIGN KEY (EntryNum) REFERENCES MsgTable(EntryNum),"
@ -90,7 +149,13 @@ public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider
list.add("CREATE TABLE IF NOT EXISTS SignatureTable (EntryNum INT, SignerId TINYBLOB, Signature TINYBLOB UNIQUE,"
+ " FOREIGN KEY (EntryNum) REFERENCES MsgTable(EntryNum))");
list.add("CREATE UNIQUE INDEX IF NOT EXISTS SignerIdIndex ON SignatureTable(SignerId)");
list.add("CREATE INDEX IF NOT EXISTS SignerIndex ON SignatureTable(SignerId)");
list.add("CREATE UNIQUE INDEX IF NOT EXISTS SignerIndex ON SignatureTable(SignerId, EntryNum)");
// This is used to create a simple table with one entry.
// It is used for implementing a workaround for the missing INSERT IGNORE syntax
list.add("CREATE TABLE IF NOT EXISTS UtilityTable (Entry INT)");
list.add("INSERT INTO UtilityTable (Entry) VALUES (1)");
return list;
}
@ -99,6 +164,7 @@ public class H2QueryProvider implements BulletinBoardSQLServer.SQLQueryProvider
public List<String> getSchemaDeletionCommands() {
List<String> list = new LinkedList<String>();
list.add("DROP TABLE IF EXISTS UtilityTable");
list.add("DROP INDEX IF EXISTS SignerIdIndex");
list.add("DROP TABLE IF EXISTS MsgTagTable");
list.add("DROP TABLE IF EXISTS SignatureTable");

View File

@ -1,7 +1,10 @@
package meerkat.bulletinboard.sqlserver;
import com.mysql.jdbc.jdbc2.optional.MysqlDataSource;
import meerkat.bulletinboard.sqlserver.BulletinBoardSQLServer.SQLQueryProvider;
import meerkat.protobuf.BulletinBoardAPI.FilterType;
import javax.sql.DataSource;
import java.util.LinkedList;
import java.util.List;
@ -9,12 +12,16 @@ import java.util.List;
* Created by Arbel Deutsch Peled on 09-Dec-15.
*/
public class MySQLQueryProvider implements BulletinBoardSQLServer.SQLQueryProvider {
public class MySQLQueryProvider implements SQLQueryProvider {
String dbConnectionString;
private String dbAddress;
private String username;
private String password;
public MySQLQueryProvider(String dbAddress, String username, String password) {
dbConnectionString = "jdbc:mysql:" + dbAddress + "?user=" + username + "&password=" + password;
this.dbAddress = dbAddress;
this.username = username;
this.password = password;
}
@Override
@ -22,20 +29,20 @@ public class MySQLQueryProvider implements BulletinBoardSQLServer.SQLQueryProvid
switch(queryType) {
case ADD_SIGNATURE:
return "INSERT IGNORE INTO SignatureTable (EntryNum, SignerId, Signature) VALUES (?,?,?)";
return "INSERT IGNORE INTO SignatureTable (EntryNum, SignerId, Signature) VALUES (:EntryNum, :SignerId, :Signature)";
case CONNECT_TAG:
return "INSERT IGNORE INTO MsgTagTable (TagId, EntryNum)"
+ " SELECT TagTable.TagId, ? AS EntryNum FROM TagTable WHERE Tag = ?";
+ " SELECT TagTable.TagId, :EntryNum AS EntryNum FROM TagTable WHERE Tag = :Tag";
case FIND_MSG_ID:
return "SELECT EntryNum From MsgTable WHERE MsgId = ?";
return "SELECT EntryNum From MsgTable WHERE MsgId = :MsgId";
case GET_MESSAGES:
return "SELECT MsgTable.EntryNum, MsgTable.Msg FROM MsgTable";
case GET_SIGNATURES:
return "SELECT Signature FROM SignatureTable WHERE EntryNum = ?";
return "SELECT Signature FROM SignatureTable WHERE EntryNum = :EntryNum";
case INSERT_MSG:
return "INSERT INTO MsgTable (MsgId, Msg) VALUES(?,?)";
return "INSERT INTO MsgTable (MsgId, Msg) VALUES(:MsgId, :Msg)";
case INSERT_NEW_TAG:
return "INSERT IGNORE INTO TagTable(Tag) VALUES (?)";
return "INSERT IGNORE INTO TagTable(Tag) VALUES (:Tag)";
default:
throw new IllegalArgumentException("Cannot serve a query of type " + queryType);
}
@ -43,24 +50,26 @@ public class MySQLQueryProvider implements BulletinBoardSQLServer.SQLQueryProvid
}
@Override
public String getCondition(FilterType filterType) throws IllegalArgumentException {
public String getCondition(FilterType filterType, int serialNum) throws IllegalArgumentException {
String serialString = Integer.toString(serialNum);
switch(filterType) {
case EXACT_ENTRY:
return "MsgTable.EntryNum = ?";
return "MsgTable.EntryNum = :EntryNum" + serialString;
case MAX_ENTRY:
return "MsgTable.EntryNum <= ?";
return "MsgTable.EntryNum <= :EntryNum" + serialString;
case MAX_MESSAGES:
return "LIMIT ?";
return "LIMIT :Limit" + serialString;
case MSG_ID:
return "MsgTable.MsgId = ?";
return "MsgTable.MsgId = :MsgId" + serialString;
case SIGNER_ID:
return "EXISTS (SELECT 1 FROM SignatureTable"
+ " WHERE SignatureTable.SignerId = ? AND SignatureTable.EntryNum = MsgTable.EntryNum)";
+ " WHERE SignatureTable.SignerId = :SignerId" + serialString + " AND SignatureTable.EntryNum = MsgTable.EntryNum)";
case TAG:
return "EXISTS (SELECT 1 FROM TagTable"
+ " INNER JOIN MsgTagTable ON TagTable.TagId = MsgTagTable.TagId"
+ " WHERE TagTable.Tag = ? AND MsgTagTable.EntryNum = MsgTable.EntryNum)";
+ " WHERE TagTable.Tag = :Tag" + serialString + " AND MsgTagTable.EntryNum = MsgTable.EntryNum)";
default:
throw new IllegalArgumentException("Cannot serve a filter of type " + filterType);
}
@ -68,10 +77,37 @@ public class MySQLQueryProvider implements BulletinBoardSQLServer.SQLQueryProvid
}
@Override
public String getConnectionString() {
return dbConnectionString;
public String getConditionParamTypeName(FilterType filterType) throws IllegalArgumentException {
switch(filterType) {
case EXACT_ENTRY: // Go through
case MAX_ENTRY: // Go through
case MAX_MESSAGES:
return "INT";
case MSG_ID: // Go through
case SIGNER_ID:
return "TINYBLOB";
case TAG:
return "VARCHAR";
default:
throw new IllegalArgumentException("Cannot serve a filter of type " + filterType);
}
}
@Override
public DataSource getDataSource() {
MysqlDataSource dataSource = new MysqlDataSource();
dataSource.setDatabaseName("meerkat"); //TODO: Make generic
dataSource.setUser(username);
dataSource.setPassword(password);
dataSource.setServerName(dbAddress);
return dataSource;
}
@Override
public List<String> getSchemaCreationCommands() {
@ -79,15 +115,15 @@ public class MySQLQueryProvider implements BulletinBoardSQLServer.SQLQueryProvid
list.add("CREATE TABLE IF NOT EXISTS MsgTable (EntryNum INT NOT NULL AUTO_INCREMENT PRIMARY KEY, MsgId TINYBLOB, Msg BLOB, UNIQUE(MsgId(50)))");
list.add("CREATE TABLE IF NOT EXISTS TagTable (TagId INT NOT NULL AUTO_INCREMENT PRIMARY KEY, Tag varchar(50), UNIQUE(Tag))");
list.add("CREATE TABLE IF NOT EXISTS TagTable (TagId INT NOT NULL AUTO_INCREMENT PRIMARY KEY, Tag VARCHAR(50), UNIQUE(Tag))");
list.add("CREATE TABLE IF NOT EXISTS MsgTagTable (EntryNum INT, TagId INT,"
+ " CONSTRAINT FOREIGN KEY (EntryNum) REFERENCES MsgTable(EntryNum),"
+ " CONSTRAINT FOREIGN KEY (TagId) REFERENCES TagTable(TagId),"
+ " CONSTRAINT UNIQUE (EntryNum, TagID))");
list.add("CREATE TABLE IF NOT EXISTS SignatureTable (EntryNum INT, SignerId TINYBLOB, Signature TINYBLOB, UNIQUE(Signature(150)),"
+ " INDEX(SignerId(50)), CONSTRAINT FOREIGN KEY (EntryNum) REFERENCES MsgTable(EntryNum))");
list.add("CREATE TABLE IF NOT EXISTS SignatureTable (EntryNum INT, SignerId TINYBLOB, Signature TINYBLOB,"
+ " INDEX(SignerId(32)), CONSTRAINT Uni UNIQUE(SignerId(32), EntryNum), CONSTRAINT FOREIGN KEY (EntryNum) REFERENCES MsgTable(EntryNum))");
return list;
}

View File

@ -1,22 +1,22 @@
package meerkat.bulletinboard.sqlserver;
import meerkat.protobuf.BulletinBoardAPI.*;
import org.sqlite.SQLiteDataSource;
import javax.sql.DataSource;
import java.util.LinkedList;
import java.util.List;
import static meerkat.protobuf.BulletinBoardAPI.FilterType;
/**
* Created by Arbel Deutsch Peled on 09-Dec-15.
*/
public class SQLiteQueryProvider implements BulletinBoardSQLServer.SQLQueryProvider {
String dbConnectionString;
String dbName;
public SQLiteQueryProvider(String dbAddress) {
dbConnectionString = "jdbc:sqlite:" + dbAddress;
public SQLiteQueryProvider(String dbName) {
this.dbName = dbName;
}
@Override
@ -24,20 +24,20 @@ public class SQLiteQueryProvider implements BulletinBoardSQLServer.SQLQueryProvi
switch(queryType) {
case ADD_SIGNATURE:
return "INSERT OR IGNORE INTO SignatureTable (EntryNum, SignerId, Signature) VALUES (?,?,?)";
return "INSERT OR IGNORE INTO SignatureTable (EntryNum, SignerId, Signature) VALUES (:EntryNum,:SignerId,:Signature)";
case CONNECT_TAG:
return "INSERT OR IGNORE INTO MsgTagTable (TagId, EntryNum)"
+ " SELECT TagTable.TagId, ? AS EntryNum FROM TagTable WHERE Tag = ?";
+ " SELECT TagTable.TagId, :EntryNum AS EntryNum FROM TagTable WHERE Tag = :Tag";
case FIND_MSG_ID:
return "SELECT EntryNum From MsgTable WHERE MsgId = ?";
return "SELECT EntryNum From MsgTable WHERE MsgId = :MsgId";
case GET_MESSAGES:
return "SELECT MsgTable.EntryNum, MsgTable.Msg FROM MsgTable";
case GET_SIGNATURES:
return "SELECT Signature FROM SignatureTable WHERE EntryNum = ?";
return "SELECT Signature FROM SignatureTable WHERE EntryNum = :EntryNum";
case INSERT_MSG:
return "INSERT INTO MsgTable (MsgId, Msg) VALUES(?,?)";
return "INSERT INTO MsgTable (MsgId, Msg) VALUES(:MsgId,:Msg)";
case INSERT_NEW_TAG:
return "INSERT OR IGNORE INTO TagTable(Tag) VALUES (?)";
return "INSERT OR IGNORE INTO TagTable(Tag) VALUES (:Tag)";
default:
throw new IllegalArgumentException("Cannot serve a query of type " + queryType);
}
@ -45,24 +45,26 @@ public class SQLiteQueryProvider implements BulletinBoardSQLServer.SQLQueryProvi
}
@Override
public String getCondition(FilterType filterType) throws IllegalArgumentException {
public String getCondition(FilterType filterType, int serialNum) throws IllegalArgumentException {
String serialString = Integer.toString(serialNum);
switch(filterType) {
case EXACT_ENTRY:
return "MsgTable.EntryNum = ?";
return "MsgTable.EntryNum = :EntryNum" + serialString;
case MAX_ENTRY:
return "MsgTable.EntryNum <= ?";
return "MsgTable.EntryNum <= :EntryNum" + serialString;
case MAX_MESSAGES:
return "LIMIT = ?";
return "LIMIT = :Limit" + serialString;
case MSG_ID:
return "MsgTable.MsgId = ?";
return "MsgTable.MsgId = :MsgId" + serialString;
case SIGNER_ID:
return "EXISTS (SELECT 1 FROM SignatureTable"
+ " WHERE SignatureTable.SignerId = ? AND SignatureTable.EntryNum = MsgTable.EntryNum)";
+ " WHERE SignatureTable.SignerId = :SignerId" + serialString + " AND SignatureTable.EntryNum = MsgTable.EntryNum)";
case TAG:
return "EXISTS (SELECT 1 FROM TagTable"
+ " INNER JOIN MsgTagTable ON TagTable.TagId = MsgTagTable.TagId"
+ " WHERE TagTable.Tag = ? AND MsgTagTable.EntryNum = MsgTable.EntryNum)";
+ " WHERE TagTable.Tag = :Tag" + serialString + " AND MsgTagTable.EntryNum = MsgTable.EntryNum)";
default:
throw new IllegalArgumentException("Cannot serve a filter of type " + filterType);
}
@ -70,8 +72,18 @@ public class SQLiteQueryProvider implements BulletinBoardSQLServer.SQLQueryProvi
}
@Override
public String getConnectionString() {
return dbConnectionString;
public String getConditionParamTypeName(FilterType filterType) throws IllegalArgumentException {
return null; //TODO: write this.
}
@Override
public DataSource getDataSource() {
// TODO: Fix this
SQLiteDataSource dataSource = new SQLiteDataSource();
dataSource.setUrl("jdbc:sqlite:" + dbName);
dataSource.setDatabaseName("meerkat"); //TODO: Make generic
return dataSource;
}
@ -85,9 +97,11 @@ public class SQLiteQueryProvider implements BulletinBoardSQLServer.SQLQueryProvi
list.add("CREATE TABLE IF NOT EXISTS MsgTagTable (EntryNum BLOB, TagId INTEGER, FOREIGN KEY (EntryNum)"
+ " REFERENCES MsgTable(EntryNum), FOREIGN KEY (TagId) REFERENCES TagTable(TagId), UNIQUE (EntryNum, TagID))");
list.add("CREATE TABLE IF NOT EXISTS SignatureTable (EntryNum BLOB, SignerId BLOB, Signature BLOB UNIQUE,"
list.add("CREATE TABLE IF NOT EXISTS SignatureTable (EntryNum INTEGER, SignerId BLOB, Signature BLOB,"
+ " FOREIGN KEY (EntryNum) REFERENCES MsgTable(EntryNum))");
list.add("CREATE INDEX IF NOT EXISTS SignerIndex ON SignatureTable(SignerId)");
list.add("CREATE UNIQUE INDEX IF NOT EXISTS SignerIndex ON SignatureTable(SignerId, EntryNum)");
return list;
}

View File

@ -0,0 +1,18 @@
package meerkat.bulletinboard.sqlserver.mappers;
import meerkat.protobuf.BulletinBoardAPI.MessageID;
import org.springframework.jdbc.core.RowMapper;
import java.sql.ResultSet;
import java.sql.SQLException;
/**
* Created by Arbel Deutsch Peled on 11-Dec-15.
*/
public class EntryNumMapper implements RowMapper<Long> {
@Override
public Long mapRow(ResultSet rs, int rowNum) throws SQLException {
return rs.getLong(1);
}
}

View File

@ -0,0 +1,32 @@
package meerkat.bulletinboard.sqlserver.mappers;
import com.google.protobuf.InvalidProtocolBufferException;
import meerkat.protobuf.BulletinBoardAPI.UnsignedBulletinBoardMessage;
import meerkat.protobuf.BulletinBoardAPI.BulletinBoardMessage;
import org.springframework.jdbc.core.RowMapper;
import java.sql.ResultSet;
import java.sql.SQLException;
/**
* Created by Arbel Deutsch Peled on 11-Dec-15.
*/
public class MessageMapper implements RowMapper<BulletinBoardMessage.Builder> {
@Override
public BulletinBoardMessage.Builder mapRow(ResultSet rs, int rowNum) throws SQLException {
BulletinBoardMessage.Builder builder = BulletinBoardMessage.newBuilder();
try {
builder.setEntryNum(rs.getLong(1))
.setMsg(UnsignedBulletinBoardMessage.parseFrom(rs.getBytes(2)));
} catch (InvalidProtocolBufferException e) {
throw new SQLException(e.getMessage(), e);
}
return builder;
}
}

View File

@ -0,0 +1,28 @@
package meerkat.bulletinboard.sqlserver.mappers;
import com.google.protobuf.InvalidProtocolBufferException;
import meerkat.protobuf.BulletinBoardAPI.BulletinBoardMessage;
import meerkat.protobuf.BulletinBoardAPI.UnsignedBulletinBoardMessage;
import meerkat.protobuf.Crypto.Signature;
import org.springframework.jdbc.core.RowMapper;
import java.sql.ResultSet;
import java.sql.SQLException;
/**
* Created by Arbel Deutsch Peled on 11-Dec-15.
*/
public class SignatureMapper implements RowMapper<Signature> {
@Override
public Signature mapRow(ResultSet rs, int rowNum) throws SQLException {
try {
return Signature.parseFrom(rs.getBytes(1));
} catch (InvalidProtocolBufferException e) {
throw new SQLException(e.getMessage(), e);
}
}
}

View File

@ -356,8 +356,7 @@ public class GenericBulletinBoardServerTest {
.addFilter(MessageFilter.newBuilder()
.setType(FilterType.SIGNER_ID)
.setId(signerIDs[1])
.build()
);
.build());
try {
messages = bulletinBoardServer.readMessages(filterListBuilder.build()).getMessageList();

View File

@ -7,13 +7,11 @@ import meerkat.comm.CommunicationException;
import org.junit.After;
import org.junit.Before;
import org.junit.Test;
import org.junit.runner.Result;
import java.lang.management.ManagementFactory;
import java.lang.management.ThreadMXBean;
import java.sql.Connection;
import java.sql.DriverManager;
import java.sql.SQLException;
import java.sql.Statement;
import java.sql.*;
import java.util.List;
import static org.junit.Assert.fail;
@ -23,23 +21,25 @@ import static org.junit.Assert.fail;
*/
public class H2BulletinBoardServerTest {
private final String dbAddress = "~/meerkatTest";
private final String dbAddress = "meerkatTest";
private GenericBulletinBoardServerTest serverTest;
private SQLQueryProvider queryProvider;
private final ThreadMXBean threadBean = ManagementFactory.getThreadMXBean(); // Used to time the tests
// @Before
@Before
public void init(){
System.err.println("Starting to initialize H2BulletinBoardServerTest");
long start = threadBean.getCurrentThreadCpuTime();
SQLQueryProvider queryProvider = new H2QueryProvider(dbAddress);
queryProvider = new H2QueryProvider(dbAddress, "", "");
try {
Connection conn = DriverManager.getConnection(queryProvider.getConnectionString());
Connection conn = queryProvider.getDataSource().getConnection();
Statement stmt = conn.createStatement();
List<String> deletionQueries = queryProvider.getSchemaDeletionCommands();
@ -76,7 +76,7 @@ public class H2BulletinBoardServerTest {
System.err.println("Time of operation: " + (end - start));
}
// @Test
@Test
public void bulkTest() {
System.err.println("Starting bulkTest of H2BulletinBoardServerTest");
long start = threadBean.getCurrentThreadCpuTime();
@ -107,7 +107,7 @@ public class H2BulletinBoardServerTest {
System.err.println("Time of operation: " + (end - start));
}
// @After
@After
public void close() {
System.err.println("Starting to close H2BulletinBoardServerTest");
long start = threadBean.getCurrentThreadCpuTime();

View File

@ -3,20 +3,17 @@ package meerkat.bulletinboard;
import meerkat.bulletinboard.sqlserver.BulletinBoardSQLServer;
import meerkat.bulletinboard.sqlserver.BulletinBoardSQLServer.SQLQueryProvider;
import meerkat.bulletinboard.sqlserver.MySQLQueryProvider;
import meerkat.bulletinboard.sqlserver.SQLiteQueryProvider;
import meerkat.comm.CommunicationException;
import org.junit.After;
import org.junit.Before;
import org.junit.Test;
import java.io.File;
import java.lang.management.ManagementFactory;
import java.lang.management.ThreadMXBean;
import java.sql.Connection;
import java.sql.DriverManager;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.LinkedList;
import java.util.List;
import static org.junit.Assert.fail;
@ -26,7 +23,7 @@ import static org.junit.Assert.fail;
*/
public class MySQLBulletinBoardServerTest {
private final String dbAddress = "//localhost:3306/meerkat";
private final String dbAddress = "localhost";
private final String username = "arbel";
private final String password = "mypass";
@ -44,7 +41,7 @@ public class MySQLBulletinBoardServerTest {
try {
Connection conn = DriverManager.getConnection(queryProvider.getConnectionString());
Connection conn = queryProvider.getDataSource().getConnection();
Statement stmt = conn.createStatement();
List<String> deletionQueries = queryProvider.getSchemaDeletionCommands();

View File

@ -52,6 +52,10 @@ enum FilterType {
MAX_ENTRY = 2; // Find all entries in database up to specified entry number (chronological)
SIGNER_ID = 3; // Find all entries in database that correspond to specific signature (signer)
TAG = 4; // Find all entries in database that have a specific tag
// NOTE: The MAX_MESSAGES filter must remain the last filter type
// This is because the condition it specifies in an SQL statement must come last in the statement
// Keeping it last here allows for easily sorting the filters and keeping the code general
MAX_MESSAGES = 5; // Return at most some specified number of messages
}