From 2853bbf6651a7d942470e47643a7a584c0bb65f5 Mon Sep 17 00:00:00 2001 From: Sergey Matvienko Date: Fri, 9 Jul 2021 09:58:02 +0300 Subject: [PATCH] refactored DatabaseSchemaService (Abstract and Psql), psql-specific indexes decoupled with common indexes. SQL simplified and notes added. This fixed hsql test suite tests. PsqlEntityDatabaseSchemaServiceTest added --- .../upgrade/3.2.2/schema_update_event.sql | 6 +-- .../PsqlEntityDatabaseSchemaService.java | 16 +++++- .../SqlAbstractDatabaseSchemaService.java | 27 +++++----- .../PsqlEntityDatabaseSchemaServiceTest.java | 54 +++++++++++++++++++ .../sql/schema-entities-idx-psql-addon.sql | 38 +++++++++++++ .../resources/sql/schema-entities-idx.sql | 16 ------ 6 files changed, 123 insertions(+), 34 deletions(-) create mode 100644 application/src/test/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaServiceTest.java create mode 100644 dao/src/main/resources/sql/schema-entities-idx-psql-addon.sql diff --git a/application/src/main/data/upgrade/3.2.2/schema_update_event.sql b/application/src/main/data/upgrade/3.2.2/schema_update_event.sql index c8c4e428c8..9b673bc7b6 100644 --- a/application/src/main/data/upgrade/3.2.2/schema_update_event.sql +++ b/application/src/main/data/upgrade/3.2.2/schema_update_event.sql @@ -64,7 +64,7 @@ DROP INDEX IF EXISTS public.idx_event_ts; -- Hint: add CONCURRENTLY to CREATE INDEX query in case of more then 1 million records or during live update -- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_event_ts CREATE INDEX IF NOT EXISTS idx_event_ts - ON public.event USING btree + ON public.event (ts DESC NULLS LAST) WITH (FILLFACTOR=95); @@ -78,8 +78,8 @@ DROP INDEX IF EXISTS public.idx_event_tenant_entity_type_entity_event_type_creat -- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des - ON public.event USING btree - (tenant_id ASC NULLS LAST, entity_type ASC NULLS LAST, entity_id ASC NULLS LAST, event_type ASC NULLS LAST, created_time DESC NULLS LAST) + ON public.event + (tenant_id ASC, entity_type ASC, entity_id ASC, event_type ASC, created_time DESC NULLS LAST) WITH (FILLFACTOR=95); COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des diff --git a/application/src/main/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaService.java b/application/src/main/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaService.java index 6bf3f4822d..e47a8ae0da 100644 --- a/application/src/main/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaService.java +++ b/application/src/main/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaService.java @@ -15,6 +15,7 @@ */ package org.thingsboard.server.service.install; +import lombok.extern.slf4j.Slf4j; import org.springframework.context.annotation.Profile; import org.springframework.stereotype.Service; import org.thingsboard.server.dao.util.PsqlDao; @@ -22,9 +23,22 @@ import org.thingsboard.server.dao.util.PsqlDao; @Service @PsqlDao @Profile("install") +@Slf4j public class PsqlEntityDatabaseSchemaService extends SqlAbstractDatabaseSchemaService implements EntityDatabaseSchemaService { + public static final String SCHEMA_ENTITIES_SQL = "schema-entities.sql"; + public static final String SCHEMA_ENTITIES_IDX_SQL = "schema-entities-idx.sql"; + public static final String SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL = "schema-entities-idx-psql-addon.sql"; + public PsqlEntityDatabaseSchemaService() { - super("schema-entities.sql", "schema-entities-idx.sql"); + super(SCHEMA_ENTITIES_SQL, SCHEMA_ENTITIES_IDX_SQL); } + + @Override + public void createDatabaseIndexes() throws Exception { + super.createDatabaseIndexes(); + log.info("Installing SQL DataBase schema PostgreSQL specific indexes part: " + SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); + executeQueryFromFile(SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); + } + } diff --git a/application/src/main/java/org/thingsboard/server/service/install/SqlAbstractDatabaseSchemaService.java b/application/src/main/java/org/thingsboard/server/service/install/SqlAbstractDatabaseSchemaService.java index 1e652880a0..ec56cc39b4 100644 --- a/application/src/main/java/org/thingsboard/server/service/install/SqlAbstractDatabaseSchemaService.java +++ b/application/src/main/java/org/thingsboard/server/service/install/SqlAbstractDatabaseSchemaService.java @@ -19,7 +19,7 @@ import lombok.extern.slf4j.Slf4j; import org.springframework.beans.factory.annotation.Autowired; import org.springframework.beans.factory.annotation.Value; -import java.nio.charset.Charset; +import java.io.IOException; import java.nio.file.Files; import java.nio.file.Path; import java.nio.file.Paths; @@ -59,14 +59,8 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema @Override public void createDatabaseSchema(boolean createIndexes) throws Exception { - log.info("Installing SQL DataBase schema part: " + schemaSql); - - Path schemaFile = Paths.get(installScripts.getDataDir(), SQL_DIR, schemaSql); - try (Connection conn = DriverManager.getConnection(dbUrl, dbUserName, dbPassword)) { - String sql = new String(Files.readAllBytes(schemaFile), Charset.forName("UTF-8")); - conn.createStatement().execute(sql); //NOSONAR, ignoring because method used to load initial thingsboard database schema - } + executeQueryFromFile(schemaSql); if (createIndexes) { this.createDatabaseIndexes(); @@ -77,11 +71,15 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema public void createDatabaseIndexes() throws Exception { if (schemaIdxSql != null) { log.info("Installing SQL DataBase schema indexes part: " + schemaIdxSql); - Path schemaIdxFile = Paths.get(installScripts.getDataDir(), SQL_DIR, schemaIdxSql); - try (Connection conn = DriverManager.getConnection(dbUrl, dbUserName, dbPassword)) { - String sql = new String(Files.readAllBytes(schemaIdxFile), Charset.forName("UTF-8")); - conn.createStatement().execute(sql); //NOSONAR, ignoring because method used to load initial thingsboard database schema - } + executeQueryFromFile(schemaIdxSql); + } + } + + void executeQueryFromFile(String schemaIdxSql) throws SQLException, IOException { + Path schemaIdxFile = Paths.get(installScripts.getDataDir(), SQL_DIR, schemaIdxSql); + String sql = Files.readString(schemaIdxFile); + try (Connection conn = DriverManager.getConnection(dbUrl, dbUserName, dbPassword)) { + conn.createStatement().execute(sql); //NOSONAR, ignoring because method used to load initial thingsboard database schema } } @@ -91,7 +89,8 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema log.info("Successfully executed query: {}", query); Thread.sleep(5000); } catch (InterruptedException | SQLException e) { - log.info("Failed to execute query: {} due to: {}", query, e.getMessage()); + log.error("Failed to execute query: {} due to: {}", query, e.getMessage()); + throw new RuntimeException("Failed to execute query: " + query, e); } } diff --git a/application/src/test/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaServiceTest.java b/application/src/test/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaServiceTest.java new file mode 100644 index 0000000000..eb08390ec7 --- /dev/null +++ b/application/src/test/java/org/thingsboard/server/service/install/PsqlEntityDatabaseSchemaServiceTest.java @@ -0,0 +1,54 @@ +/** + * Copyright © 2016-2021 The Thingsboard Authors + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + */ +package org.thingsboard.server.service.install; + +import org.junit.Test; + +import static org.mockito.ArgumentMatchers.anyString; +import static org.mockito.BDDMockito.willDoNothing; +import static org.mockito.Mockito.spy; +import static org.mockito.Mockito.times; +import static org.mockito.Mockito.verify; + +public class PsqlEntityDatabaseSchemaServiceTest { + + @Test + public void givenPsqlDbSchemaService_whenCreateDatabaseSchema_thenVerifyPsqlIndexSpecificCall() throws Exception { + PsqlEntityDatabaseSchemaService service = spy(new PsqlEntityDatabaseSchemaService()); + willDoNothing().given(service).executeQueryFromFile(anyString()); + + service.createDatabaseSchema(); + + verify(service, times(1)).createDatabaseIndexes(); + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_SQL); + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_SQL); + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); + verify(service, times(3)).executeQueryFromFile(anyString()); + } + + @Test + public void givenPsqlDbSchemaService_whenCreateDatabaseIndexes_thenVerifyPsqlIndexSpecificCall() throws Exception { + PsqlEntityDatabaseSchemaService service = spy(new PsqlEntityDatabaseSchemaService()); + willDoNothing().given(service).executeQueryFromFile(anyString()); + + service.createDatabaseIndexes(); + + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_SQL); + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); + verify(service, times(2)).executeQueryFromFile(anyString()); + } + +} diff --git a/dao/src/main/resources/sql/schema-entities-idx-psql-addon.sql b/dao/src/main/resources/sql/schema-entities-idx-psql-addon.sql new file mode 100644 index 0000000000..9884d48a1b --- /dev/null +++ b/dao/src/main/resources/sql/schema-entities-idx-psql-addon.sql @@ -0,0 +1,38 @@ +-- +-- Copyright © 2016-2021 The Thingsboard Authors +-- +-- Licensed under the Apache License, Version 2.0 (the "License"); +-- you may not use this file except in compliance with the License. +-- You may obtain a copy of the License at +-- +-- http://www.apache.org/licenses/LICENSE-2.0 +-- +-- Unless required by applicable law or agreed to in writing, software +-- distributed under the License is distributed on an "AS IS" BASIS, +-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. +-- See the License for the specific language governing permissions and +-- limitations under the License. +-- + +-- This file describes PostgreSQL-specific indexes that not supported by hsql +-- It is not a stand-alone file! Run schema-entities-idx.sql before! +-- Note: Hibernate DESC order translates to native SQL "ORDER BY .. DESC NULLS LAST" +-- While creating index PostgreSQL transforms short notation (ts DESC) to the full (DESC NULLS FIRST) +-- That difference between NULLS LAST and NULLS FIRST prevents to hit index while querying latest by ts +-- That why we need to define DESC index explicitly as (ts DESC NULLS LAST) + +CREATE INDEX IF NOT EXISTS idx_event_ts + ON public.event + (ts DESC NULLS LAST) + WITH (FILLFACTOR=95); + +COMMENT ON INDEX public.idx_event_ts + IS 'This index helps to delete events by TTL using timestamp'; + +CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des + ON public.event + (tenant_id ASC, entity_type ASC, entity_id ASC, event_type ASC, created_time DESC NULLS LAST) + WITH (FILLFACTOR=95); + +COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des + IS 'This index helps to open latest events on UI fast'; \ No newline at end of file diff --git a/dao/src/main/resources/sql/schema-entities-idx.sql b/dao/src/main/resources/sql/schema-entities-idx.sql index 443d99faad..78b1eda905 100644 --- a/dao/src/main/resources/sql/schema-entities-idx.sql +++ b/dao/src/main/resources/sql/schema-entities-idx.sql @@ -45,19 +45,3 @@ CREATE INDEX IF NOT EXISTS idx_attribute_kv_by_key_and_last_update_ts ON attribu CREATE INDEX IF NOT EXISTS idx_audit_log_tenant_id_and_created_time ON audit_log(tenant_id, created_time); CREATE INDEX IF NOT EXISTS idx_rpc_tenant_id_device_id ON rpc(tenant_id, device_id); - -CREATE INDEX IF NOT EXISTS idx_event_ts - ON public.event USING btree - (ts DESC NULLS LAST) - WITH (FILLFACTOR=95); - -COMMENT ON INDEX public.idx_event_ts - IS 'This index helps to delete events by TTL using timestamp'; - -CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des - ON public.event USING btree - (tenant_id ASC NULLS LAST, entity_type ASC NULLS LAST, entity_id ASC NULLS LAST, event_type ASC NULLS LAST, created_time DESC NULLS LAST) - WITH (FILLFACTOR=95); - -COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des - IS 'This index helps to open latest events on UI fast'; \ No newline at end of file