Commit 2853bbf6651a7d942470e47643a7a584c0bb65f5
1 parent
05908936
refactored DatabaseSchemaService (Abstract and Psql), psql-specific indexes deco…
…upled with common indexes. SQL simplified and notes added. This fixed hsql test suite tests. PsqlEntityDatabaseSchemaServiceTest added
Showing
6 changed files
with
123 additions
and
34 deletions
@@ -64,7 +64,7 @@ DROP INDEX IF EXISTS public.idx_event_ts; | @@ -64,7 +64,7 @@ DROP INDEX IF EXISTS public.idx_event_ts; | ||
64 | -- Hint: add CONCURRENTLY to CREATE INDEX query in case of more then 1 million records or during live update | 64 | -- Hint: add CONCURRENTLY to CREATE INDEX query in case of more then 1 million records or during live update |
65 | -- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_event_ts | 65 | -- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_event_ts |
66 | CREATE INDEX IF NOT EXISTS idx_event_ts | 66 | CREATE INDEX IF NOT EXISTS idx_event_ts |
67 | - ON public.event USING btree | 67 | + ON public.event |
68 | (ts DESC NULLS LAST) | 68 | (ts DESC NULLS LAST) |
69 | WITH (FILLFACTOR=95); | 69 | WITH (FILLFACTOR=95); |
70 | 70 | ||
@@ -78,8 +78,8 @@ DROP INDEX IF EXISTS public.idx_event_tenant_entity_type_entity_event_type_creat | @@ -78,8 +78,8 @@ DROP INDEX IF EXISTS public.idx_event_tenant_entity_type_entity_event_type_creat | ||
78 | 78 | ||
79 | -- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des | 79 | -- CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des |
80 | CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des | 80 | CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des |
81 | - ON public.event USING btree | ||
82 | - (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) | 81 | + ON public.event |
82 | + (tenant_id ASC, entity_type ASC, entity_id ASC, event_type ASC, created_time DESC NULLS LAST) | ||
83 | WITH (FILLFACTOR=95); | 83 | WITH (FILLFACTOR=95); |
84 | 84 | ||
85 | COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des | 85 | COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des |
@@ -15,6 +15,7 @@ | @@ -15,6 +15,7 @@ | ||
15 | */ | 15 | */ |
16 | package org.thingsboard.server.service.install; | 16 | package org.thingsboard.server.service.install; |
17 | 17 | ||
18 | +import lombok.extern.slf4j.Slf4j; | ||
18 | import org.springframework.context.annotation.Profile; | 19 | import org.springframework.context.annotation.Profile; |
19 | import org.springframework.stereotype.Service; | 20 | import org.springframework.stereotype.Service; |
20 | import org.thingsboard.server.dao.util.PsqlDao; | 21 | import org.thingsboard.server.dao.util.PsqlDao; |
@@ -22,9 +23,22 @@ import org.thingsboard.server.dao.util.PsqlDao; | @@ -22,9 +23,22 @@ import org.thingsboard.server.dao.util.PsqlDao; | ||
22 | @Service | 23 | @Service |
23 | @PsqlDao | 24 | @PsqlDao |
24 | @Profile("install") | 25 | @Profile("install") |
26 | +@Slf4j | ||
25 | public class PsqlEntityDatabaseSchemaService extends SqlAbstractDatabaseSchemaService | 27 | public class PsqlEntityDatabaseSchemaService extends SqlAbstractDatabaseSchemaService |
26 | implements EntityDatabaseSchemaService { | 28 | implements EntityDatabaseSchemaService { |
29 | + public static final String SCHEMA_ENTITIES_SQL = "schema-entities.sql"; | ||
30 | + public static final String SCHEMA_ENTITIES_IDX_SQL = "schema-entities-idx.sql"; | ||
31 | + public static final String SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL = "schema-entities-idx-psql-addon.sql"; | ||
32 | + | ||
27 | public PsqlEntityDatabaseSchemaService() { | 33 | public PsqlEntityDatabaseSchemaService() { |
28 | - super("schema-entities.sql", "schema-entities-idx.sql"); | 34 | + super(SCHEMA_ENTITIES_SQL, SCHEMA_ENTITIES_IDX_SQL); |
35 | + } | ||
36 | + | ||
37 | + @Override | ||
38 | + public void createDatabaseIndexes() throws Exception { | ||
39 | + super.createDatabaseIndexes(); | ||
40 | + log.info("Installing SQL DataBase schema PostgreSQL specific indexes part: " + SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); | ||
41 | + executeQueryFromFile(SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); | ||
29 | } | 42 | } |
43 | + | ||
30 | } | 44 | } |
@@ -19,7 +19,7 @@ import lombok.extern.slf4j.Slf4j; | @@ -19,7 +19,7 @@ import lombok.extern.slf4j.Slf4j; | ||
19 | import org.springframework.beans.factory.annotation.Autowired; | 19 | import org.springframework.beans.factory.annotation.Autowired; |
20 | import org.springframework.beans.factory.annotation.Value; | 20 | import org.springframework.beans.factory.annotation.Value; |
21 | 21 | ||
22 | -import java.nio.charset.Charset; | 22 | +import java.io.IOException; |
23 | import java.nio.file.Files; | 23 | import java.nio.file.Files; |
24 | import java.nio.file.Path; | 24 | import java.nio.file.Path; |
25 | import java.nio.file.Paths; | 25 | import java.nio.file.Paths; |
@@ -59,14 +59,8 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema | @@ -59,14 +59,8 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema | ||
59 | 59 | ||
60 | @Override | 60 | @Override |
61 | public void createDatabaseSchema(boolean createIndexes) throws Exception { | 61 | public void createDatabaseSchema(boolean createIndexes) throws Exception { |
62 | - | ||
63 | log.info("Installing SQL DataBase schema part: " + schemaSql); | 62 | log.info("Installing SQL DataBase schema part: " + schemaSql); |
64 | - | ||
65 | - Path schemaFile = Paths.get(installScripts.getDataDir(), SQL_DIR, schemaSql); | ||
66 | - try (Connection conn = DriverManager.getConnection(dbUrl, dbUserName, dbPassword)) { | ||
67 | - String sql = new String(Files.readAllBytes(schemaFile), Charset.forName("UTF-8")); | ||
68 | - conn.createStatement().execute(sql); //NOSONAR, ignoring because method used to load initial thingsboard database schema | ||
69 | - } | 63 | + executeQueryFromFile(schemaSql); |
70 | 64 | ||
71 | if (createIndexes) { | 65 | if (createIndexes) { |
72 | this.createDatabaseIndexes(); | 66 | this.createDatabaseIndexes(); |
@@ -77,11 +71,15 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema | @@ -77,11 +71,15 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema | ||
77 | public void createDatabaseIndexes() throws Exception { | 71 | public void createDatabaseIndexes() throws Exception { |
78 | if (schemaIdxSql != null) { | 72 | if (schemaIdxSql != null) { |
79 | log.info("Installing SQL DataBase schema indexes part: " + schemaIdxSql); | 73 | log.info("Installing SQL DataBase schema indexes part: " + schemaIdxSql); |
80 | - Path schemaIdxFile = Paths.get(installScripts.getDataDir(), SQL_DIR, schemaIdxSql); | ||
81 | - try (Connection conn = DriverManager.getConnection(dbUrl, dbUserName, dbPassword)) { | ||
82 | - String sql = new String(Files.readAllBytes(schemaIdxFile), Charset.forName("UTF-8")); | ||
83 | - conn.createStatement().execute(sql); //NOSONAR, ignoring because method used to load initial thingsboard database schema | ||
84 | - } | 74 | + executeQueryFromFile(schemaIdxSql); |
75 | + } | ||
76 | + } | ||
77 | + | ||
78 | + void executeQueryFromFile(String schemaIdxSql) throws SQLException, IOException { | ||
79 | + Path schemaIdxFile = Paths.get(installScripts.getDataDir(), SQL_DIR, schemaIdxSql); | ||
80 | + String sql = Files.readString(schemaIdxFile); | ||
81 | + try (Connection conn = DriverManager.getConnection(dbUrl, dbUserName, dbPassword)) { | ||
82 | + conn.createStatement().execute(sql); //NOSONAR, ignoring because method used to load initial thingsboard database schema | ||
85 | } | 83 | } |
86 | } | 84 | } |
87 | 85 | ||
@@ -91,7 +89,8 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema | @@ -91,7 +89,8 @@ public abstract class SqlAbstractDatabaseSchemaService implements DatabaseSchema | ||
91 | log.info("Successfully executed query: {}", query); | 89 | log.info("Successfully executed query: {}", query); |
92 | Thread.sleep(5000); | 90 | Thread.sleep(5000); |
93 | } catch (InterruptedException | SQLException e) { | 91 | } catch (InterruptedException | SQLException e) { |
94 | - log.info("Failed to execute query: {} due to: {}", query, e.getMessage()); | 92 | + log.error("Failed to execute query: {} due to: {}", query, e.getMessage()); |
93 | + throw new RuntimeException("Failed to execute query: " + query, e); | ||
95 | } | 94 | } |
96 | } | 95 | } |
97 | 96 |
1 | +/** | ||
2 | + * Copyright © 2016-2021 The Thingsboard Authors | ||
3 | + * | ||
4 | + * Licensed under the Apache License, Version 2.0 (the "License"); | ||
5 | + * you may not use this file except in compliance with the License. | ||
6 | + * You may obtain a copy of the License at | ||
7 | + * | ||
8 | + * http://www.apache.org/licenses/LICENSE-2.0 | ||
9 | + * | ||
10 | + * Unless required by applicable law or agreed to in writing, software | ||
11 | + * distributed under the License is distributed on an "AS IS" BASIS, | ||
12 | + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
13 | + * See the License for the specific language governing permissions and | ||
14 | + * limitations under the License. | ||
15 | + */ | ||
16 | +package org.thingsboard.server.service.install; | ||
17 | + | ||
18 | +import org.junit.Test; | ||
19 | + | ||
20 | +import static org.mockito.ArgumentMatchers.anyString; | ||
21 | +import static org.mockito.BDDMockito.willDoNothing; | ||
22 | +import static org.mockito.Mockito.spy; | ||
23 | +import static org.mockito.Mockito.times; | ||
24 | +import static org.mockito.Mockito.verify; | ||
25 | + | ||
26 | +public class PsqlEntityDatabaseSchemaServiceTest { | ||
27 | + | ||
28 | + @Test | ||
29 | + public void givenPsqlDbSchemaService_whenCreateDatabaseSchema_thenVerifyPsqlIndexSpecificCall() throws Exception { | ||
30 | + PsqlEntityDatabaseSchemaService service = spy(new PsqlEntityDatabaseSchemaService()); | ||
31 | + willDoNothing().given(service).executeQueryFromFile(anyString()); | ||
32 | + | ||
33 | + service.createDatabaseSchema(); | ||
34 | + | ||
35 | + verify(service, times(1)).createDatabaseIndexes(); | ||
36 | + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_SQL); | ||
37 | + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_SQL); | ||
38 | + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); | ||
39 | + verify(service, times(3)).executeQueryFromFile(anyString()); | ||
40 | + } | ||
41 | + | ||
42 | + @Test | ||
43 | + public void givenPsqlDbSchemaService_whenCreateDatabaseIndexes_thenVerifyPsqlIndexSpecificCall() throws Exception { | ||
44 | + PsqlEntityDatabaseSchemaService service = spy(new PsqlEntityDatabaseSchemaService()); | ||
45 | + willDoNothing().given(service).executeQueryFromFile(anyString()); | ||
46 | + | ||
47 | + service.createDatabaseIndexes(); | ||
48 | + | ||
49 | + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_SQL); | ||
50 | + verify(service, times(1)).executeQueryFromFile(PsqlEntityDatabaseSchemaService.SCHEMA_ENTITIES_IDX_PSQL_ADDON_SQL); | ||
51 | + verify(service, times(2)).executeQueryFromFile(anyString()); | ||
52 | + } | ||
53 | + | ||
54 | +} |
1 | +-- | ||
2 | +-- Copyright © 2016-2021 The Thingsboard Authors | ||
3 | +-- | ||
4 | +-- Licensed under the Apache License, Version 2.0 (the "License"); | ||
5 | +-- you may not use this file except in compliance with the License. | ||
6 | +-- You may obtain a copy of the License at | ||
7 | +-- | ||
8 | +-- http://www.apache.org/licenses/LICENSE-2.0 | ||
9 | +-- | ||
10 | +-- Unless required by applicable law or agreed to in writing, software | ||
11 | +-- distributed under the License is distributed on an "AS IS" BASIS, | ||
12 | +-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. | ||
13 | +-- See the License for the specific language governing permissions and | ||
14 | +-- limitations under the License. | ||
15 | +-- | ||
16 | + | ||
17 | +-- This file describes PostgreSQL-specific indexes that not supported by hsql | ||
18 | +-- It is not a stand-alone file! Run schema-entities-idx.sql before! | ||
19 | +-- Note: Hibernate DESC order translates to native SQL "ORDER BY .. DESC NULLS LAST" | ||
20 | +-- While creating index PostgreSQL transforms short notation (ts DESC) to the full (DESC NULLS FIRST) | ||
21 | +-- That difference between NULLS LAST and NULLS FIRST prevents to hit index while querying latest by ts | ||
22 | +-- That why we need to define DESC index explicitly as (ts DESC NULLS LAST) | ||
23 | + | ||
24 | +CREATE INDEX IF NOT EXISTS idx_event_ts | ||
25 | + ON public.event | ||
26 | + (ts DESC NULLS LAST) | ||
27 | + WITH (FILLFACTOR=95); | ||
28 | + | ||
29 | +COMMENT ON INDEX public.idx_event_ts | ||
30 | + IS 'This index helps to delete events by TTL using timestamp'; | ||
31 | + | ||
32 | +CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des | ||
33 | + ON public.event | ||
34 | + (tenant_id ASC, entity_type ASC, entity_id ASC, event_type ASC, created_time DESC NULLS LAST) | ||
35 | + WITH (FILLFACTOR=95); | ||
36 | + | ||
37 | +COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des | ||
38 | + IS 'This index helps to open latest events on UI fast'; |
@@ -45,19 +45,3 @@ CREATE INDEX IF NOT EXISTS idx_attribute_kv_by_key_and_last_update_ts ON attribu | @@ -45,19 +45,3 @@ CREATE INDEX IF NOT EXISTS idx_attribute_kv_by_key_and_last_update_ts ON attribu | ||
45 | CREATE INDEX IF NOT EXISTS idx_audit_log_tenant_id_and_created_time ON audit_log(tenant_id, created_time); | 45 | CREATE INDEX IF NOT EXISTS idx_audit_log_tenant_id_and_created_time ON audit_log(tenant_id, created_time); |
46 | 46 | ||
47 | CREATE INDEX IF NOT EXISTS idx_rpc_tenant_id_device_id ON rpc(tenant_id, device_id); | 47 | CREATE INDEX IF NOT EXISTS idx_rpc_tenant_id_device_id ON rpc(tenant_id, device_id); |
48 | - | ||
49 | -CREATE INDEX IF NOT EXISTS idx_event_ts | ||
50 | - ON public.event USING btree | ||
51 | - (ts DESC NULLS LAST) | ||
52 | - WITH (FILLFACTOR=95); | ||
53 | - | ||
54 | -COMMENT ON INDEX public.idx_event_ts | ||
55 | - IS 'This index helps to delete events by TTL using timestamp'; | ||
56 | - | ||
57 | -CREATE INDEX IF NOT EXISTS idx_event_tenant_entity_type_entity_event_type_created_time_des | ||
58 | - ON public.event USING btree | ||
59 | - (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) | ||
60 | - WITH (FILLFACTOR=95); | ||
61 | - | ||
62 | -COMMENT ON INDEX public.idx_event_tenant_entity_type_entity_event_type_created_time_des | ||
63 | - IS 'This index helps to open latest events on UI fast'; |