From bd3c9250dce43d394d26172689f4bbd8eae28621 Mon Sep 17 00:00:00 2001 From: Lari Hotari Date: Thu, 7 Jan 2021 10:18:35 +0200 Subject: [PATCH] Add support for MS SQLServer in JDBC Registry - include Microsoft SQLServer driver - port DDL scripts to SQLServer syntax - CREATE TABLE table_name IF NOT EXISTS -> IF OBJECT_ID('table_name', 'U') IS NULL CREATE TABLE table_name - BOOLEAN -> BIT - TEXT -> NTEXT (for unicode support) - TIMESTAMP -> DATETIME2 - CHAR/VARCHAR -> NVARCHAR - support Unicode - char -> varchar to get rid of issues with trailing spaces - Implement upsert queries for MS SQLServer - using MERGE syntax, https://docs.microsoft.com/en-us/sql/t-sql/statements/merge-transact-sql - Test MS SQLServer with Testcontainers - Use code to accept MS SQL Server Docker image license - see https://www.testcontainers.org/modules/databases/mssqlserver/ for more info Signed-off-by: Lari Hotari --- bom/pom.xml | 7 ++ .../resources/legal/LICENSE.mssql-jdbc.txt | 14 ++++ legal/src/main/resources/legal/NOTICE.md | 9 +++ .../hono/service/base/jdbc/store/SQL.java | 1 + .../jdbc/store/device/TableAdapterStore.java | 3 +- .../jdbc/store/devcon/base.sqlserver.sql.yaml | 33 +++++++++ .../jdbc/store/device/base.sqlserver.sql.yaml | 9 +++ .../src/main/sql/sqlserver/create.devices.sql | 67 +++++++++++++++++++ .../src/main/sql/sqlserver/create.tenants.sql | 24 +++++++ .../hono/service/base/jdbc/store/SQLTest.java | 4 +- services/device-registry-jdbc/pom.xml | 23 +++++++ .../jdbc/impl/AbstractJdbcRegistryTest.java | 23 +++++++ .../jdbc-device-registry-config.md | 4 +- 13 files changed, 217 insertions(+), 4 deletions(-) create mode 100644 legal/src/main/resources/legal/LICENSE.mssql-jdbc.txt create mode 100644 services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/devcon/base.sqlserver.sql.yaml create mode 100644 services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/device/base.sqlserver.sql.yaml create mode 100644 services/base-jdbc/src/main/sql/sqlserver/create.devices.sql create mode 100644 services/base-jdbc/src/main/sql/sqlserver/create.tenants.sql diff --git a/bom/pom.xml b/bom/pom.xml index f7d6be99a8..aaadc0030e 100644 --- a/bom/pom.xml +++ b/bom/pom.xml @@ -57,6 +57,7 @@ 1.6.2 3.6.28 mongo:4.2.11 + 8.4.1.jre11 4.1.49.Final 2.0.30.Final 0.33.0 @@ -711,6 +712,12 @@ ${postgresql-jdbc.version} runtime + + com.microsoft.sqlserver + mssql-jdbc + ${mssql-jdbc.version} + runtime + diff --git a/legal/src/main/resources/legal/LICENSE.mssql-jdbc.txt b/legal/src/main/resources/legal/LICENSE.mssql-jdbc.txt new file mode 100644 index 0000000000..d9f4831442 --- /dev/null +++ b/legal/src/main/resources/legal/LICENSE.mssql-jdbc.txt @@ -0,0 +1,14 @@ +Copyright(c) 2020 Microsoft Corporation +All rights reserved. + +MIT License +Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files(the "Software"), +to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, +and / or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions : + +The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. + +THE SOFTWARE IS PROVIDED *AS IS*, WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS +IN THE SOFTWARE. diff --git a/legal/src/main/resources/legal/NOTICE.md b/legal/src/main/resources/legal/NOTICE.md index bfe379bedd..06f2edb026 100644 --- a/legal/src/main/resources/legal/NOTICE.md +++ b/legal/src/main/resources/legal/NOTICE.md @@ -261,6 +261,15 @@ is also available at http://www.apache.org/licenses/LICENSE-2.0.html. The source code is available from [Maven Central](http://search.maven.org/#search%7Cga%7C1%7Cg%3A%22io.micrometer%22%20AND%20v%3A%22${micrometer.version}%22). +### Microsoft JDBC Driver for SQL Server ${mssql-jdbc.version} + +This product includes software developed by Microsoft. + +Your use of the *Microsoft JDBC Driver for SQL Server* is subject to the terms and conditions defined in the file +[LICENSE.mssql-jdbc.txt](LICENSE.mssql-jdbc.txt). + +The source code is available from [Maven Central](https://search.maven.org/remotecontent?filepath=com/microsoft/sqlserver/mssql-jdbc/${mssql-jdbc.version}/mssql-jdbc-${mssql-jdbc.version}-sources.jar). + ### Mongo Java Driver This product includes software developed by the [MongoDB Java Drivers project](https://mongodb.github.io/mongo-java-driver/). diff --git a/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/SQL.java b/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/SQL.java index 026c8dad27..3b0b1297b6 100644 --- a/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/SQL.java +++ b/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/SQL.java @@ -45,6 +45,7 @@ */ public final class SQL { public static String DIALECT_POSTGRESQL = "postgresql"; + public static String DIALECT_SQLSERVER = "sqlserver"; private static final Logger log = LoggerFactory.getLogger(SQL.class); diff --git a/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/device/TableAdapterStore.java b/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/device/TableAdapterStore.java index ec37394bb0..105fa1ca8a 100644 --- a/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/device/TableAdapterStore.java +++ b/services/base-jdbc/src/main/java/org/eclipse/hono/service/base/jdbc/store/device/TableAdapterStore.java @@ -255,7 +255,8 @@ private Object convertToArrayValue(final Collection values) { // to convert the CSV string to an array // vertx jdbc doesn't support arrays, see https://stackoverflow.com/a/42295098 // TODO: introduce a better way to configure the way array values get passed - if (dialect.equals(SQL.DIALECT_POSTGRESQL)) { + if (dialect.equals(SQL.DIALECT_POSTGRESQL) || + dialect.equals(SQL.DIALECT_SQLSERVER)) { return String.join(",", values); } return values.toArray(String[]::new); diff --git a/services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/devcon/base.sqlserver.sql.yaml b/services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/devcon/base.sqlserver.sql.yaml new file mode 100644 index 0000000000..fa2ff759d4 --- /dev/null +++ b/services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/devcon/base.sqlserver.sql.yaml @@ -0,0 +1,33 @@ +updateLastKnownGateway: | + MERGE + %s AS Target + USING + (VALUES (:tenant_id, :device_id, :gateway_id)) + AS Source (tenant_id, device_id, last_known_gateway) + ON + Target.tenant_id=Source.tenant_id AND + Target.device_id=Source.device_id + WHEN NOT MATCHED THEN + INSERT (tenant_id, device_id, last_known_gateway) + VALUES (Source.tenant_id, Source.device_id, Source.last_known_gateway) + WHEN MATCHED THEN + UPDATE + SET last_known_gateway=Source.last_known_gateway + ; + +updateAdapterInstance: | + MERGE + %s AS Target + USING + (VALUES (:tenant_id, :device_id, :adapter_instance_id)) + AS Source (tenant_id, device_id, adapter_instance_id) + ON + Target.tenant_id=Source.tenant_id AND + Target.device_id=Source.device_id + WHEN NOT MATCHED THEN + INSERT (tenant_id, device_id, adapter_instance_id) + VALUES (Source.tenant_id, Source.device_id, Source.adapter_instance_id) + WHEN MATCHED THEN + UPDATE + SET adapter_instance_id=Source.adapter_instance_id + ; diff --git a/services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/device/base.sqlserver.sql.yaml b/services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/device/base.sqlserver.sql.yaml new file mode 100644 index 0000000000..bc2e8b30d0 --- /dev/null +++ b/services/base-jdbc/src/main/resources/org/eclipse/hono/service/base/jdbc/store/device/base.sqlserver.sql.yaml @@ -0,0 +1,9 @@ +resolveGroups: | + SELECT + device_id + FROM + %3$s + WHERE + tenant_id=:tenant_id + AND + group_id in (SELECT Value FROM string_split(:group_ids,',')) diff --git a/services/base-jdbc/src/main/sql/sqlserver/create.devices.sql b/services/base-jdbc/src/main/sql/sqlserver/create.devices.sql new file mode 100644 index 0000000000..bb4b6ed370 --- /dev/null +++ b/services/base-jdbc/src/main/sql/sqlserver/create.devices.sql @@ -0,0 +1,67 @@ +IF OBJECT_ID('device_registrations', 'U') IS NULL +CREATE TABLE device_registrations +( + TENANT_ID NVARCHAR(36) NOT NULL, + DEVICE_ID NVARCHAR(256) NOT NULL, + VERSION VARCHAR(36) NOT NULL, + + CREATED DATETIME2 NOT NULL, + UPDATED_ON DATETIME2, + + AUTO_PROVISIONED BIT, + AUTO_PROVISIONING_NOTIFICATION_SENT BIT, + + DATA NTEXT, + + PRIMARY KEY (TENANT_ID, DEVICE_ID) +); + +IF OBJECT_ID('device_credentials', 'U') IS NULL +CREATE TABLE device_credentials +( + TENANT_ID NVARCHAR(36) NOT NULL, + DEVICE_ID NVARCHAR(256) NOT NULL, + + TYPE NVARCHAR(64) NOT NULL, + AUTH_ID NVARCHAR(256) NOT NULL, + + DATA NTEXT, + + PRIMARY KEY (TENANT_ID, TYPE, AUTH_ID), + FOREIGN KEY (TENANT_ID, DEVICE_ID) REFERENCES device_registrations (TENANT_ID, DEVICE_ID) ON DELETE CASCADE +); + +IF OBJECT_ID('device_groups', 'U') IS NULL +CREATE TABLE device_groups +( + TENANT_ID NVARCHAR(36) NOT NULL, + DEVICE_ID NVARCHAR(256) NOT NULL, + GROUP_ID NVARCHAR(256) NOT NULL, + + PRIMARY KEY (TENANT_ID, DEVICE_ID, GROUP_ID), + FOREIGN KEY (TENANT_ID, DEVICE_ID) REFERENCES device_registrations (TENANT_ID, DEVICE_ID) ON DELETE CASCADE +); + +IF OBJECT_ID('device_states', 'U') IS NULL +CREATE TABLE device_states +( + TENANT_ID NVARCHAR(36) NOT NULL, + DEVICE_ID NVARCHAR(256) NOT NULL, + + LAST_KNOWN_GATEWAY NVARCHAR(256), + ADAPTER_INSTANCE_ID NVARCHAR(256), + + PRIMARY KEY (TENANT_ID, DEVICE_ID) +); + +-- create indexes for non-primary key access paths + +CREATE INDEX idx_device_registrations_tenant ON device_registrations (TENANT_ID); + +CREATE INDEX idx_device_credentials_tenant ON device_credentials (TENANT_ID); +CREATE INDEX idx_device_credentials_tenant_and_device ON device_credentials (TENANT_ID, DEVICE_ID); + +CREATE INDEX idx_device_states_tenant ON device_states (TENANT_ID); + +CREATE INDEX idx_device_member_of_tenant ON device_groups (TENANT_ID); +CREATE INDEX idx_device_member_of_tenant_and_device ON device_groups (TENANT_ID, DEVICE_ID); diff --git a/services/base-jdbc/src/main/sql/sqlserver/create.tenants.sql b/services/base-jdbc/src/main/sql/sqlserver/create.tenants.sql new file mode 100644 index 0000000000..ca955103bc --- /dev/null +++ b/services/base-jdbc/src/main/sql/sqlserver/create.tenants.sql @@ -0,0 +1,24 @@ +IF OBJECT_ID('tenants', 'U') IS NULL +CREATE TABLE tenants +( + TENANT_ID NVARCHAR(36) NOT NULL, + VERSION VARCHAR(36) NOT NULL, + DATA NTEXT, + + PRIMARY KEY (TENANT_ID) +); + +IF OBJECT_ID('tenant_trust_anchors', 'U') IS NULL +CREATE TABLE tenant_trust_anchors +( + SUBJECT_DN NVARCHAR(256) NOT NULL, + TENANT_ID NVARCHAR(36) NOT NULL, + DATA NTEXT, + + PRIMARY KEY (SUBJECT_DN), + FOREIGN KEY (TENANT_ID) REFERENCES tenants (TENANT_ID) ON DELETE CASCADE +); + +-- create indexes for non-primary key access paths + +CREATE INDEX idx_tenant_trust_anchors_tenant ON tenant_trust_anchors (TENANT_ID); diff --git a/services/base-jdbc/src/test/java/org/eclipse/hono/service/base/jdbc/store/SQLTest.java b/services/base-jdbc/src/test/java/org/eclipse/hono/service/base/jdbc/store/SQLTest.java index fc2f4fc748..9aab80b62f 100644 --- a/services/base-jdbc/src/test/java/org/eclipse/hono/service/base/jdbc/store/SQLTest.java +++ b/services/base-jdbc/src/test/java/org/eclipse/hono/service/base/jdbc/store/SQLTest.java @@ -33,7 +33,9 @@ public class SQLTest { public static Stream typeDetectorValue() { return Stream.of( Arguments.of("jdbc:postgresql://localhost:1234/device-registry", "postgresql"), - Arguments.of("jdbc:h2:~/test;ACCESS_MODE_DATA=rws", "h2")); + Arguments.of("jdbc:h2:~/test;ACCESS_MODE_DATA=rws", "h2"), + Arguments.of("jdbc:sqlserver://localhost:1433;databaseName=hono", "sqlserver") + ); } /** diff --git a/services/device-registry-jdbc/pom.xml b/services/device-registry-jdbc/pom.xml index cbbc31ca46..06ea5e5264 100644 --- a/services/device-registry-jdbc/pom.xml +++ b/services/device-registry-jdbc/pom.xml @@ -55,6 +55,11 @@ postgresql runtime + + com.microsoft.sqlserver + mssql-jdbc + runtime + @@ -68,6 +73,12 @@ ${testcontainers.version} test + + org.testcontainers + mssqlserver + ${testcontainers.version} + test + org.eclipse.hono hono-service-device-registry-base @@ -106,6 +117,18 @@ + + sqlserver-tests + + test + + + ${no.docker} + + sqlserver + + + diff --git a/services/device-registry-jdbc/src/test/java/org/eclipse/hono/deviceregistry/jdbc/impl/AbstractJdbcRegistryTest.java b/services/device-registry-jdbc/src/test/java/org/eclipse/hono/deviceregistry/jdbc/impl/AbstractJdbcRegistryTest.java index e68bede357..4671eab414 100644 --- a/services/device-registry-jdbc/src/test/java/org/eclipse/hono/deviceregistry/jdbc/impl/AbstractJdbcRegistryTest.java +++ b/services/device-registry-jdbc/src/test/java/org/eclipse/hono/deviceregistry/jdbc/impl/AbstractJdbcRegistryTest.java @@ -45,6 +45,7 @@ import org.junit.jupiter.api.BeforeEach; import org.junit.jupiter.api.extension.ExtendWith; import org.testcontainers.containers.JdbcDatabaseContainer; +import org.testcontainers.containers.MSSQLServerContainer; import org.testcontainers.containers.PostgreSQLContainer; import io.opentracing.Span; @@ -58,6 +59,7 @@ abstract class AbstractJdbcRegistryTest { enum DatabaseType { H2, + SQLSERVER, POSTGRESQL } protected static final Span SPAN = NoopSpan.INSTANCE; @@ -66,11 +68,14 @@ enum DatabaseType { private static final DatabaseType DATABASE_TYPE = DatabaseType.valueOf(System.getProperty(AbstractJdbcRegistryTest.class.getSimpleName() + ".databaseType", DEFAULT_DATABASE_TYPE.name()).toUpperCase()); private static final Map> DATABASE_CONTAINER_CACHE = new ConcurrentHashMap<>(); + private static final String SQLSERVER_IMAGE_NAME = System.getProperty(AbstractJdbcRegistryTest.class.getSimpleName() + + ".sqlserverImageName", "mcr.microsoft.com/mssql/server:2017-CU12"); private static final String POSTGRESQL_IMAGE_NAME = System.getProperty(AbstractJdbcRegistryTest.class.getSimpleName() + ".postgresqlImageName", "postgres:12-alpine"); private static final AtomicLong UNIQUE_ID_GENERATOR = new AtomicLong(System.currentTimeMillis()); + private static final Tracer TRACER = NoopTracerFactory.create(); private static final Path EXAMPLE_SQL_BASE = Path.of("..", "base-jdbc", "src", "main", "sql", DATABASE_TYPE.name().toLowerCase()); @@ -132,6 +137,10 @@ private JdbcProperties resolveJdbcProperties() { jdbc.setDriverClass(Driver.class.getName()); jdbc.setUrl("jdbc:h2:" + BASE_DIR.resolve(UUID.randomUUID().toString()).toAbsolutePath()); break; + case SQLSERVER: + jdbc.setUrl(jdbc.getUrl() + ";SelectMethod=Cursor"); + createNewPerTestSchemaAndUserForSQLServer(jdbc); + break; case POSTGRESQL: createNewPerTestSchemaForPostgres(jdbc); break; @@ -151,6 +160,9 @@ private JdbcDatabaseContainer getDatabaseContainer() { __ -> { final JdbcDatabaseContainer container; switch (DATABASE_TYPE) { + case SQLSERVER: + container = new MSSQLServerContainer<>(SQLSERVER_IMAGE_NAME).acceptLicense(); + break; case POSTGRESQL: container = new PostgreSQLContainer<>(POSTGRESQL_IMAGE_NAME); final List commandLine = new ArrayList<>(Arrays.asList(container.getCommandParts())); @@ -167,6 +179,17 @@ private JdbcDatabaseContainer getDatabaseContainer() { }); } + void createNewPerTestSchemaAndUserForSQLServer(final JdbcProperties jdbc) { + final var schemaName = "test" + UNIQUE_ID_GENERATOR.incrementAndGet(); + final var userName = "user" + UNIQUE_ID_GENERATOR.incrementAndGet(); + final var sql = "create login " + userName + " with password='" + jdbc.getPassword() + "';\n" + + "create schema " + schemaName + ";\n" + + "create user " + userName + " for login " + userName + " with default_schema = " + schemaName + ";\n" + + "exec sp_addrolemember 'db_owner', '" + userName + "';\n"; + executeSQLScript(jdbc, sql); + jdbc.setUsername(userName); + } + private void executeSQLScript(final JdbcProperties jdbc, final String sql) { try ( var connection = DriverManager.getConnection(jdbc.getUrl(), jdbc.getUsername(), jdbc.getPassword()); diff --git a/site/documentation/content/admin-guide/jdbc-device-registry-config.md b/site/documentation/content/admin-guide/jdbc-device-registry-config.md index aac29e82a1..d27b848c2b 100644 --- a/site/documentation/content/admin-guide/jdbc-device-registry-config.md +++ b/site/documentation/content/admin-guide/jdbc-device-registry-config.md @@ -15,10 +15,10 @@ The application is implemented as a Spring Boot application, and it uses a JDBC provides the following features: * Run only the registration and credentials service, or run including the tenant service. -* By default, supports H2 and PostgreSQL +* By default, supports H2, PostgreSQL and MS SQL Server * Supports different JDBC connections for read-only and read-write operations, to support read-only replicas -**Note:** The provided container images contains only the H2 and PostgreSQL configuration and JDBC driver. While it is +**Note:** The provided container images contains only the H2, PostgreSQL and MS SQL Server configuration and JDBC driver. While it is possible to use other JDBC compliant databases, database specific configuration and JDBC driver have to be provided by the user.