-
Notifications
You must be signed in to change notification settings - Fork 137
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
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 <[email protected]>
- Loading branch information
Showing
13 changed files
with
217 additions
and
4 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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. |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
33 changes: 33 additions & 0 deletions
33
...rc/main/resources/org/eclipse/hono/service/base/jdbc/store/devcon/base.sqlserver.sql.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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 | ||
; |
9 changes: 9 additions & 0 deletions
9
...rc/main/resources/org/eclipse/hono/service/base/jdbc/store/device/base.sqlserver.sql.yaml
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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,',')) |
67 changes: 67 additions & 0 deletions
67
services/base-jdbc/src/main/sql/sqlserver/create.devices.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); |
24 changes: 24 additions & 0 deletions
24
services/base-jdbc/src/main/sql/sqlserver/create.tenants.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -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); |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters