From d2446be69e71d353679c37115cec7f75c20f599e Mon Sep 17 00:00:00 2001 From: cxyzhang0 Date: Fri, 20 Jul 2018 08:25:15 -0700 Subject: [PATCH] MSSQL support (#3382) * MSSQL support * changes per reviewer's comments; doc * clean up * CONTRIBUTORS.md * minor change in comment * another minor change in comment * minor formatting * Comments formatting per recommend style; contributors in alphabet order * more comment formatting per coding style * Change MSSQL to SQLServer in codes and comments * Change MSSQL to SQLServer in doc * Use generateSequence to build repeats of ?,?,...? --- CONTRIBUTORS.md | 1 + docs/source/node-database.rst | 32 +++++ .../selection/CashSelectionSQLServerImpl.kt | 114 ++++++++++++++++++ ...asset.cash.selection.AbstractCashSelection | 3 +- .../node/services/vault/NodeVaultService.kt | 6 +- 5 files changed, 154 insertions(+), 2 deletions(-) create mode 100644 finance/src/main/kotlin/net/corda/finance/contracts/asset/cash/selection/CashSelectionSQLServerImpl.kt diff --git a/CONTRIBUTORS.md b/CONTRIBUTORS.md index 5179b3cff5..b947c7644e 100644 --- a/CONTRIBUTORS.md +++ b/CONTRIBUTORS.md @@ -171,6 +171,7 @@ see changes to this list. * Sam Chadwick (Thomson Reuters) * Sasmit Sahu * Scott James +* Sean Zhang (Wells Fargo) * Shams Asari (R3) * Siddhartha Sengupta (Tradewind Markets) * Simon Taylor (Barclays) diff --git a/docs/source/node-database.rst b/docs/source/node-database.rst index 0a89c1de63..cbb44c9548 100644 --- a/docs/source/node-database.rst +++ b/docs/source/node-database.rst @@ -71,3 +71,35 @@ Note that: `PostgreSQL documentation `_, or the schema search path must be set explicitly for the user. +SQLServer +---------- +Nodes also have untested support for Microsoft SQL Server 2017, using Microsoft JDBC Driver 6.2 for SQL Server. + +.. warning:: This is an experimental community contribution, and is currently untested. We welcome pull requests to add + tests and additional support for this feature. + +Configuration +~~~~~~~~~~~~~ +Here is an example node configuration for SQLServer: + +.. sourcecode:: groovy + + dataSourceProperties = { + dataSourceClassName = "com.microsoft.sqlserver.jdbc.SQLServerDataSource" + dataSource.url = "jdbc:sqlserver://[HOST]:[PORT];databaseName=[DATABASE_NAME]" + dataSource.user = [USER] + dataSource.password = [PASSWORD] + } + database = { + transactionIsolationLevel = READ_COMMITTED + schema = [SCHEMA] + } + jarDirs = ["[FULL_PATH]/sqljdbc_6.2/enu/"] + +Note that: + +* The ``database.schema`` property is optional and is ignored as of release 3.1. +* Ensure the directory referenced by jarDirs contains only one JDBC driver JAR file; by the default, + sqljdbc_6.2/enu/contains two JDBC JAR file for different Java versions. +======= + diff --git a/finance/src/main/kotlin/net/corda/finance/contracts/asset/cash/selection/CashSelectionSQLServerImpl.kt b/finance/src/main/kotlin/net/corda/finance/contracts/asset/cash/selection/CashSelectionSQLServerImpl.kt new file mode 100644 index 0000000000..246842668b --- /dev/null +++ b/finance/src/main/kotlin/net/corda/finance/contracts/asset/cash/selection/CashSelectionSQLServerImpl.kt @@ -0,0 +1,114 @@ +package net.corda.finance.contracts.asset.cash.selection + +import net.corda.core.contracts.Amount +import net.corda.core.crypto.toStringShort +import net.corda.core.identity.AbstractParty +import net.corda.core.identity.Party +import net.corda.core.utilities.OpaqueBytes +import net.corda.core.utilities.contextLogger +import net.corda.core.utilities.debug +import java.sql.Connection +import java.sql.DatabaseMetaData +import java.sql.ResultSet +import java.util.* + +class CashSelectionSQLServerImpl : AbstractCashSelection() { + companion object { + val JDBC_DRIVER_NAME_REGEX = """Microsoft JDBC Driver (\w+.\w+) for SQL Server""".toRegex() + private val log = contextLogger() + } + + override fun isCompatible(metadata: DatabaseMetaData): Boolean { + return JDBC_DRIVER_NAME_REGEX.matches(metadata.driverName) + } + + override fun toString() = "${this::class.qualifiedName} for '$JDBC_DRIVER_NAME_REGEX'" + + // This is one MSSQL implementation of the query to select just enough cash states to meet the desired amount. + // We select the cash states with smaller amounts first so that as the result, we minimize the numbers of + // unspent cash states remaining in the vault. + // + // If there is not enough cash, the query will return an empty resultset, which should signal to the caller + // of an exception, since the desired amount is assumed to always > 0. + // NOTE: The other two implementations, H2 and PostgresSQL, behave differently in this case - they return + // all in the vault instead of nothing. That seems to give the caller an extra burden to verify total returned + // >= amount. + // In addition, extra data fetched results in unnecessary I/O. + // Nevertheless, if so desired, we can achieve the same by changing the last FROM clause to + // FROM CTE LEFT JOIN Boundary AS B ON 1 = 1 + // WHERE B.seqNo IS NULL OR CTE.seqNo <= B.seqNo + // + // Common Table Expression and Windowed functions help make the query more readable. + // Query plan does index scan on pennies_idx, which may be unavoidable due to the nature of the query. + override fun executeQuery(connection: Connection, amount: Amount, lockId: UUID, notary: Party?, onlyFromIssuerParties: Set, withIssuerRefs: Set, withResultSet: (ResultSet) -> Boolean): Boolean { + val sb = StringBuilder() + sb.append( """ + ;WITH CTE AS + ( + SELECT + vs.transaction_id, + vs.output_index, + ccs.pennies, + vs.lock_id, + total_pennies = SUM(ccs.pennies) OVER (ORDER BY ccs.pennies), + seqNo = ROW_NUMBER() OVER (ORDER BY ccs.pennies) + FROM vault_states AS vs INNER JOIN contract_cash_states AS ccs + ON vs.transaction_id = ccs.transaction_id AND vs.output_index = ccs.output_index + WHERE + vs.state_status = 0 + AND ccs.ccy_code = ? + AND (vs.lock_id = ? OR vs.lock_id IS NULL) + """ + ) + if (notary != null) + sb.append(""" + AND vs.notary_name = ? + """) + if (onlyFromIssuerParties.isNotEmpty()) { + val repeats = generateSequence { "?" }.take(onlyFromIssuerParties.size).joinToString(",") + sb.append(""" + AND ccs.issuer_key_hash IN ($repeats) + """) + } + if (withIssuerRefs.isNotEmpty()) { + val repeats = generateSequence { "?" }.take(withIssuerRefs.size).joinToString(",") + sb.append(""" + AND ccs.issuer_ref IN ($repeats) + """) + } + sb.append( + """ + ), + Boundary AS + ( + SELECT TOP (1) * FROM CTE WHERE total_pennies >= ? ORDER BY seqNo + ) + SELECT CTE.transaction_id, CTE.output_index, CTE.pennies, CTE.total_pennies, CTE.lock_id + FROM CTE INNER JOIN Boundary AS B ON CTE.seqNo <= B.seqNo + ; + """ + ) + val selectJoin = sb.toString() + log.debug { selectJoin } + connection.prepareStatement(selectJoin).use { psSelectJoin -> + var pIndex = 0 + psSelectJoin.setString(++pIndex, amount.token.currencyCode) + psSelectJoin.setString(++pIndex, lockId.toString()) + if (notary != null) + psSelectJoin.setString(++pIndex, notary.name.toString()) + onlyFromIssuerParties.forEach { + psSelectJoin.setString(++pIndex, it.owningKey.toStringShort()) + } + withIssuerRefs.forEach { + psSelectJoin.setBytes(++pIndex, it.bytes) + } + psSelectJoin.setLong(++pIndex, amount.quantity) + + log.debug { psSelectJoin.toString() } + + psSelectJoin.executeQuery().use { rs -> + return withResultSet(rs) + } + } + } +} \ No newline at end of file diff --git a/finance/src/main/resources/META-INF/services/net.corda.finance.contracts.asset.cash.selection.AbstractCashSelection b/finance/src/main/resources/META-INF/services/net.corda.finance.contracts.asset.cash.selection.AbstractCashSelection index eb11e0083b..decfa4fadc 100644 --- a/finance/src/main/resources/META-INF/services/net.corda.finance.contracts.asset.cash.selection.AbstractCashSelection +++ b/finance/src/main/resources/META-INF/services/net.corda.finance.contracts.asset.cash.selection.AbstractCashSelection @@ -1,2 +1,3 @@ net.corda.finance.contracts.asset.cash.selection.CashSelectionH2Impl -net.corda.finance.contracts.asset.cash.selection.CashSelectionPostgreSQLImpl \ No newline at end of file +net.corda.finance.contracts.asset.cash.selection.CashSelectionPostgreSQLImpl +net.corda.finance.contracts.asset.cash.selection.CashSelectionSQLServerImpl diff --git a/node/src/main/kotlin/net/corda/node/services/vault/NodeVaultService.kt b/node/src/main/kotlin/net/corda/node/services/vault/NodeVaultService.kt index cf9b1ba9f2..91608e13b7 100644 --- a/node/src/main/kotlin/net/corda/node/services/vault/NodeVaultService.kt +++ b/node/src/main/kotlin/net/corda/node/services/vault/NodeVaultService.kt @@ -471,7 +471,11 @@ class NodeVaultService( if (paging.pageSize < 1) throw VaultQueryException("Page specification: invalid page size ${paging.pageSize} [must be a value between 1 and $MAX_PAGE_SIZE]") } - query.firstResult = (paging.pageNumber - 1) * paging.pageSize + // For both SQLServer and PostgresSQL, firstResult must be >= 0. So we set a floor at 0. + // TODO: This is a catch-all solution. But why is the default pageNumber set to be -1 in the first place? + // Even if we set the default pageNumber to be 1 instead, that may not cover the non-default cases. + // So the floor may be necessary anyway. + query.firstResult = maxOf(0, (paging.pageNumber - 1) * paging.pageSize) query.maxResults = paging.pageSize + 1 // detection too many results // execution