Commit 6af34cf043da68943fd4aa26c608e548c3140776
Committed by
Andrew Shvayka
1 parent
083dc38c
refactoring ttl cleanup services
Showing
15 changed files
with
312 additions
and
142 deletions
... | ... | @@ -18,17 +18,18 @@ CREATE OR REPLACE PROCEDURE drop_partitions_by_max_ttl(IN partition_type varchar |
18 | 18 | LANGUAGE plpgsql AS |
19 | 19 | $$ |
20 | 20 | DECLARE |
21 | - max_tenant_ttl bigint; | |
22 | - max_customer_ttl bigint; | |
23 | - max_ttl bigint; | |
24 | - date timestamp; | |
25 | - partition_by_max_ttl_date varchar; | |
26 | - partition_month varchar; | |
27 | - partition_day varchar; | |
28 | - partition_year varchar; | |
29 | - partition varchar; | |
30 | - partition_to_delete varchar; | |
31 | - | |
21 | + max_tenant_ttl bigint; | |
22 | + max_customer_ttl bigint; | |
23 | + max_ttl bigint; | |
24 | + date timestamp; | |
25 | + partition_by_max_ttl_date varchar; | |
26 | + partition_by_max_ttl_month varchar; | |
27 | + partition_by_max_ttl_day varchar; | |
28 | + partition_by_max_ttl_year varchar; | |
29 | + partition varchar; | |
30 | + partition_year integer; | |
31 | + partition_month integer; | |
32 | + partition_day integer; | |
32 | 33 | |
33 | 34 | BEGIN |
34 | 35 | SELECT max(attribute_kv.long_v) |
... | ... | @@ -45,53 +46,138 @@ BEGIN |
45 | 46 | if max_ttl IS NOT NULL AND max_ttl > 0 THEN |
46 | 47 | date := to_timestamp(EXTRACT(EPOCH FROM current_timestamp) - max_ttl); |
47 | 48 | partition_by_max_ttl_date := get_partition_by_max_ttl_date(partition_type, date); |
49 | + RAISE NOTICE 'Date by max ttl: %', date; | |
48 | 50 | RAISE NOTICE 'Partition by max ttl: %', partition_by_max_ttl_date; |
49 | 51 | IF partition_by_max_ttl_date IS NOT NULL THEN |
50 | 52 | CASE |
51 | 53 | WHEN partition_type = 'DAYS' THEN |
52 | - partition_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
53 | - partition_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
54 | - partition_day := SPLIT_PART(partition_by_max_ttl_date, '_', 5); | |
54 | + partition_by_max_ttl_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
55 | + partition_by_max_ttl_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
56 | + partition_by_max_ttl_day := SPLIT_PART(partition_by_max_ttl_date, '_', 5); | |
55 | 57 | WHEN partition_type = 'MONTHS' THEN |
56 | - partition_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
57 | - partition_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
58 | + partition_by_max_ttl_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
59 | + partition_by_max_ttl_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
58 | 60 | ELSE |
59 | - partition_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
61 | + partition_by_max_ttl_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
60 | 62 | END CASE; |
61 | - FOR partition IN SELECT tablename | |
62 | - FROM pg_tables | |
63 | - WHERE schemaname = 'public' | |
64 | - AND tablename like 'ts_kv_' || '%' | |
65 | - AND tablename != 'ts_kv_latest' | |
66 | - AND tablename != 'ts_kv_dictionary' | |
67 | - AND tablename != 'ts_kv_indefinite' | |
68 | - LOOP | |
69 | - IF partition != partition_by_max_ttl_date THEN | |
70 | - IF partition_year IS NOT NULL THEN | |
71 | - IF SPLIT_PART(partition, '_', 3)::integer < partition_year::integer THEN | |
72 | - partition_to_delete := partition; | |
73 | - ELSE | |
74 | - IF partition_month IS NOT NULL THEN | |
75 | - IF SPLIT_PART(partition, '_', 4)::integer < partition_month::integer THEN | |
76 | - partition_to_delete := partition; | |
63 | + IF partition_by_max_ttl_year IS NULL THEN | |
64 | + RAISE NOTICE 'Failed to remove partitions by max ttl date due to partition_by_max_ttl_year is null!'; | |
65 | + ELSE | |
66 | + IF partition_type = 'YEARS' THEN | |
67 | + FOR partition IN SELECT tablename | |
68 | + FROM pg_tables | |
69 | + WHERE schemaname = 'public' | |
70 | + AND tablename like 'ts_kv_' || '%' | |
71 | + AND tablename != 'ts_kv_latest' | |
72 | + AND tablename != 'ts_kv_dictionary' | |
73 | + AND tablename != 'ts_kv_indefinite' | |
74 | + AND tablename != partition_by_max_ttl_date | |
75 | + LOOP | |
76 | + partition_year := SPLIT_PART(partition, '_', 3)::integer; | |
77 | + IF partition_year < partition_by_max_ttl_year::integer THEN | |
78 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
79 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
80 | + deleted := deleted + 1; | |
81 | + END IF; | |
82 | + END LOOP; | |
83 | + ELSE | |
84 | + IF partition_type = 'MONTHS' THEN | |
85 | + IF partition_by_max_ttl_month IS NULL THEN | |
86 | + RAISE NOTICE 'Failed to remove months partitions by max ttl date due to partition_by_max_ttl_month is null!'; | |
87 | + ELSE | |
88 | + FOR partition IN SELECT tablename | |
89 | + FROM pg_tables | |
90 | + WHERE schemaname = 'public' | |
91 | + AND tablename like 'ts_kv_' || '%' | |
92 | + AND tablename != 'ts_kv_latest' | |
93 | + AND tablename != 'ts_kv_dictionary' | |
94 | + AND tablename != 'ts_kv_indefinite' | |
95 | + AND tablename != partition_by_max_ttl_date | |
96 | + LOOP | |
97 | + partition_year := SPLIT_PART(partition, '_', 3)::integer; | |
98 | + IF partition_year > partition_by_max_ttl_year::integer THEN | |
99 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
100 | + CONTINUE; | |
77 | 101 | ELSE |
78 | - IF partition_day IS NOT NULL THEN | |
79 | - IF SPLIT_PART(partition, '_', 5)::integer < partition_day::integer THEN | |
80 | - partition_to_delete := partition; | |
102 | + IF partition_year < partition_by_max_ttl_year::integer THEN | |
103 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
104 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
105 | + deleted := deleted + 1; | |
106 | + ELSE | |
107 | + partition_month := SPLIT_PART(partition, '_', 4)::integer; | |
108 | + IF partition_year = partition_by_max_ttl_year::integer THEN | |
109 | + IF partition_month >= partition_by_max_ttl_month::integer THEN | |
110 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
111 | + CONTINUE; | |
112 | + ELSE | |
113 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
114 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
115 | + deleted := deleted + 1; | |
116 | + END IF; | |
81 | 117 | END IF; |
82 | 118 | END IF; |
83 | 119 | END IF; |
120 | + END LOOP; | |
121 | + END IF; | |
122 | + ELSE | |
123 | + IF partition_type = 'DAYS' THEN | |
124 | + IF partition_by_max_ttl_month IS NULL THEN | |
125 | + RAISE NOTICE 'Failed to remove days partitions by max ttl date due to partition_by_max_ttl_month is null!'; | |
126 | + ELSE | |
127 | + IF partition_by_max_ttl_day IS NULL THEN | |
128 | + RAISE NOTICE 'Failed to remove days partitions by max ttl date due to partition_by_max_ttl_day is null!'; | |
129 | + ELSE | |
130 | + FOR partition IN SELECT tablename | |
131 | + FROM pg_tables | |
132 | + WHERE schemaname = 'public' | |
133 | + AND tablename like 'ts_kv_' || '%' | |
134 | + AND tablename != 'ts_kv_latest' | |
135 | + AND tablename != 'ts_kv_dictionary' | |
136 | + AND tablename != 'ts_kv_indefinite' | |
137 | + AND tablename != partition_by_max_ttl_date | |
138 | + LOOP | |
139 | + partition_year := SPLIT_PART(partition, '_', 3)::integer; | |
140 | + IF partition_year > partition_by_max_ttl_year::integer THEN | |
141 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
142 | + CONTINUE; | |
143 | + ELSE | |
144 | + IF partition_year < partition_by_max_ttl_year::integer THEN | |
145 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
146 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
147 | + deleted := deleted + 1; | |
148 | + ELSE | |
149 | + partition_month := SPLIT_PART(partition, '_', 4)::integer; | |
150 | + IF partition_month > partition_by_max_ttl_month::integer THEN | |
151 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
152 | + CONTINUE; | |
153 | + ELSE | |
154 | + IF partition_month < partition_by_max_ttl_month::integer THEN | |
155 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
156 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
157 | + deleted := deleted + 1; | |
158 | + ELSE | |
159 | + partition_day := SPLIT_PART(partition, '_', 5)::integer; | |
160 | + IF partition_day >= partition_by_max_ttl_day::integer THEN | |
161 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
162 | + CONTINUE; | |
163 | + ELSE | |
164 | + IF partition_day < partition_by_max_ttl_day::integer THEN | |
165 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
166 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
167 | + deleted := deleted + 1; | |
168 | + END IF; | |
169 | + END IF; | |
170 | + END IF; | |
171 | + END IF; | |
172 | + END IF; | |
173 | + END IF; | |
174 | + END LOOP; | |
84 | 175 | END IF; |
85 | 176 | END IF; |
86 | 177 | END IF; |
87 | - IF partition_to_delete IS NOT NULL THEN | |
88 | - RAISE NOTICE 'Partition to delete by max ttl: %', partition_to_delete; | |
89 | - EXECUTE format('DROP TABLE IF EXISTS %I', partition_to_delete); | |
90 | - partition_to_delete := NULL; | |
91 | - deleted := deleted + 1; | |
92 | - END IF; | |
93 | 178 | END IF; |
94 | - END LOOP; | |
179 | + END IF; | |
180 | + END IF; | |
95 | 181 | END IF; |
96 | 182 | END IF; |
97 | 183 | END |
... | ... | @@ -107,8 +193,6 @@ BEGIN |
107 | 193 | partition := 'ts_kv_' || to_char(date, 'yyyy') || '_' || to_char(date, 'MM'); |
108 | 194 | WHEN partition_type = 'YEARS' THEN |
109 | 195 | partition := 'ts_kv_' || to_char(date, 'yyyy'); |
110 | - WHEN partition_type = 'INDEFINITE' THEN | |
111 | - partition := NULL; | |
112 | 196 | ELSE |
113 | 197 | partition := NULL; |
114 | 198 | END CASE; | ... | ... |
... | ... | @@ -45,9 +45,7 @@ public class EdgeEventsCleanUpService extends AbstractCleanUpService { |
45 | 45 | @Scheduled(initialDelayString = "${sql.ttl.edge_events.execution_interval_ms}", fixedDelayString = "${sql.ttl.edge_events.execution_interval_ms}") |
46 | 46 | public void cleanUp() { |
47 | 47 | if (ttlTaskExecutionEnabled && isSystemTenantPartitionMine()) { |
48 | - log.info("Going to cleanup old edge events using ttl: {}s", ttl); | |
49 | - long totalEdgeEventsRemoved = edgeService.cleanupEvents(ttl); | |
50 | - log.info("Total edge events removed by TTL: [{}]", totalEdgeEventsRemoved); | |
48 | + edgeService.cleanupEvents(ttl); | |
51 | 49 | } |
52 | 50 | } |
53 | 51 | ... | ... |
... | ... | @@ -48,9 +48,7 @@ public class EventsCleanUpService extends AbstractCleanUpService { |
48 | 48 | @Scheduled(initialDelayString = "${sql.ttl.events.execution_interval_ms}", fixedDelayString = "${sql.ttl.events.execution_interval_ms}") |
49 | 49 | public void cleanUp() { |
50 | 50 | if (ttlTaskExecutionEnabled && isSystemTenantPartitionMine()) { |
51 | - log.info("Going to cleanup old events using debug events ttl: {}s and other events ttl: {}s", debugTtl, ttl); | |
52 | - long totalEventsRemoved = eventService.cleanupEvents(ttl, debugTtl); | |
53 | - log.info("Total events removed by TTL: [{}]", totalEventsRemoved); | |
51 | + eventService.cleanupEvents(ttl, debugTtl); | |
54 | 52 | } |
55 | 53 | } |
56 | 54 | ... | ... |
... | ... | @@ -18,11 +18,15 @@ package org.thingsboard.server.service.ttl; |
18 | 18 | import lombok.extern.slf4j.Slf4j; |
19 | 19 | import org.springframework.beans.factory.annotation.Value; |
20 | 20 | import org.springframework.scheduling.annotation.Scheduled; |
21 | +import org.springframework.stereotype.Service; | |
21 | 22 | import org.thingsboard.server.dao.timeseries.TimeseriesService; |
22 | 23 | import org.thingsboard.server.queue.discovery.PartitionService; |
24 | +import org.thingsboard.server.queue.util.TbCoreComponent; | |
23 | 25 | import org.thingsboard.server.service.ttl.AbstractCleanUpService; |
24 | 26 | |
27 | +@TbCoreComponent | |
25 | 28 | @Slf4j |
29 | +@Service | |
26 | 30 | public class TimeseriesCleanUpService extends AbstractCleanUpService { |
27 | 31 | |
28 | 32 | @Value("${sql.ttl.ts.ts_key_value_ttl}") | ... | ... |
... | ... | @@ -180,7 +180,6 @@ public interface EdgeDao extends Dao<Edge> { |
180 | 180 | /** |
181 | 181 | * Executes stored procedure to cleanup old edge events. |
182 | 182 | * @param ttl the ttl for edge events in seconds |
183 | - * @return the number of deleted edge events | |
184 | 183 | */ |
185 | - long cleanupEvents(long ttl); | |
184 | + void cleanupEvents(long ttl); | |
186 | 185 | } |
\ No newline at end of file | ... | ... |
... | ... | @@ -628,8 +628,8 @@ public class EdgeServiceImpl extends AbstractEntityService implements EdgeServic |
628 | 628 | } |
629 | 629 | |
630 | 630 | @Override |
631 | - public long cleanupEvents(long ttl) { | |
632 | - return edgeDao.cleanupEvents(ttl); | |
631 | + public void cleanupEvents(long ttl) { | |
632 | + edgeDao.cleanupEvents(ttl); | |
633 | 633 | } |
634 | 634 | |
635 | 635 | private List<RuleChain> findEdgeRuleChains(TenantId tenantId, EdgeId edgeId) { | ... | ... |
... | ... | @@ -132,8 +132,8 @@ public class BaseEventService implements EventService { |
132 | 132 | } |
133 | 133 | |
134 | 134 | @Override |
135 | - public long cleanupEvents(long ttl, long debugTtl) { | |
136 | - return eventDao.cleanupEvents(ttl, debugTtl); | |
135 | + public void cleanupEvents(long ttl, long debugTtl) { | |
136 | + eventDao.cleanupEvents(ttl, debugTtl); | |
137 | 137 | } |
138 | 138 | |
139 | 139 | private DataValidator<Event> eventValidator = | ... | ... |
... | ... | @@ -106,7 +106,6 @@ public interface EventDao extends Dao<Event> { |
106 | 106 | * Executes stored procedure to cleanup old events. Uses separate ttl for debug and other events. |
107 | 107 | * @param otherEventsTtl the ttl for events in seconds |
108 | 108 | * @param debugEventsTtl the ttl for debug events in seconds |
109 | - * @return the number of deleted events | |
110 | 109 | */ |
111 | - long cleanupEvents(long otherEventsTtl, long debugEventsTtl); | |
110 | + void cleanupEvents(long otherEventsTtl, long debugEventsTtl); | |
112 | 111 | } | ... | ... |
... | ... | @@ -40,9 +40,9 @@ import org.thingsboard.server.dao.model.sql.EdgeInfoEntity; |
40 | 40 | import org.thingsboard.server.dao.relation.RelationDao; |
41 | 41 | import org.thingsboard.server.dao.sql.JpaAbstractSearchTextDao; |
42 | 42 | |
43 | -import java.sql.CallableStatement; | |
43 | +import java.sql.PreparedStatement; | |
44 | +import java.sql.ResultSet; | |
44 | 45 | import java.sql.SQLException; |
45 | -import java.sql.Types; | |
46 | 46 | import java.util.ArrayList; |
47 | 47 | import java.util.Collections; |
48 | 48 | import java.util.List; |
... | ... | @@ -198,17 +198,19 @@ public class JpaEdgeDao extends JpaAbstractSearchTextDao<EdgeEntity, Edge> imple |
198 | 198 | } |
199 | 199 | |
200 | 200 | @Override |
201 | - public long cleanupEvents(long ttl) { | |
201 | + public void cleanupEvents(long ttl) { | |
202 | 202 | try { |
203 | - CallableStatement stmt = dataSource.getConnection().prepareCall("{call cleanup_edge_events_by_ttl(?,?,?)}"); | |
203 | + log.info("Going to cleanup old edge events using ttl: {}s", ttl); | |
204 | + PreparedStatement stmt = dataSource.getConnection().prepareStatement("call cleanup_edge_events_by_ttl(?,?)"); | |
204 | 205 | stmt.setLong(1, ttl); |
205 | - stmt.registerOutParameter(3, Types.BIGINT); | |
206 | - stmt.executeUpdate(); | |
206 | + stmt.setLong(2, 0); | |
207 | + stmt.execute(); | |
207 | 208 | printWarnings(stmt); |
208 | - return stmt.getLong(3); | |
209 | + ResultSet resultSet = stmt.getResultSet(); | |
210 | + resultSet.next(); | |
211 | + log.info("Total edge events removed by TTL: [{}]", resultSet.getLong(1)); | |
209 | 212 | } catch (SQLException e) { |
210 | - log.error("SQLException occurred during TTL task execution ", e); | |
211 | - return 0; | |
213 | + log.error("SQLException occurred during edge events TTL task execution ", e); | |
212 | 214 | } |
213 | 215 | } |
214 | 216 | ... | ... |
... | ... | @@ -39,12 +39,9 @@ import org.thingsboard.server.dao.event.EventDao; |
39 | 39 | import org.thingsboard.server.dao.model.sql.EventEntity; |
40 | 40 | import org.thingsboard.server.dao.sql.JpaAbstractDao; |
41 | 41 | |
42 | -import javax.sql.DataSource; | |
43 | -import java.sql.CallableStatement; | |
42 | +import java.sql.PreparedStatement; | |
43 | +import java.sql.ResultSet; | |
44 | 44 | import java.sql.SQLException; |
45 | -import java.sql.SQLWarning; | |
46 | -import java.sql.Statement; | |
47 | -import java.sql.Types; | |
48 | 45 | import java.util.List; |
49 | 46 | import java.util.Objects; |
50 | 47 | import java.util.Optional; |
... | ... | @@ -262,18 +259,20 @@ public class JpaBaseEventDao extends JpaAbstractDao<EventEntity, Event> implemen |
262 | 259 | } |
263 | 260 | |
264 | 261 | @Override |
265 | - public long cleanupEvents(long otherEventsTtl, long debugEventsTtl) { | |
262 | + public void cleanupEvents(long otherEventsTtl, long debugEventsTtl) { | |
266 | 263 | try { |
267 | - CallableStatement stmt = dataSource.getConnection().prepareCall("{call cleanup_events_by_ttl(?,?,?)}"); | |
264 | + log.info("Going to cleanup old events using debug events ttl: {}s and other events ttl: {}s", debugEventsTtl, otherEventsTtl); | |
265 | + PreparedStatement stmt = dataSource.getConnection().prepareStatement("call cleanup_events_by_ttl(?,?,?)"); | |
268 | 266 | stmt.setLong(1, otherEventsTtl); |
269 | 267 | stmt.setLong(2, debugEventsTtl); |
270 | - stmt.registerOutParameter(3, Types.BIGINT); | |
271 | - stmt.executeUpdate(); | |
268 | + stmt.setLong(3, 0); | |
269 | + stmt.execute(); | |
272 | 270 | printWarnings(stmt); |
273 | - return stmt.getLong(3); | |
271 | + ResultSet resultSet = stmt.getResultSet(); | |
272 | + resultSet.next(); | |
273 | + log.info("Total events removed by TTL: [{}]", resultSet.getLong(1)); | |
274 | 274 | } catch (SQLException e) { |
275 | - log.error("SQLException occurred during TTL task execution ", e); | |
276 | - return 0; | |
275 | + log.error("SQLException occurred during events TTL task execution ", e); | |
277 | 276 | } |
278 | 277 | } |
279 | 278 | ... | ... |
... | ... | @@ -29,9 +29,9 @@ import org.thingsboard.server.dao.model.ModelConstants; |
29 | 29 | import org.thingsboard.server.dao.sql.ScheduledLogExecutorComponent; |
30 | 30 | |
31 | 31 | import javax.annotation.Nullable; |
32 | -import java.sql.CallableStatement; | |
32 | +import java.sql.PreparedStatement; | |
33 | +import java.sql.ResultSet; | |
33 | 34 | import java.sql.SQLException; |
34 | -import java.sql.Types; | |
35 | 35 | import java.util.List; |
36 | 36 | import java.util.Objects; |
37 | 37 | import java.util.concurrent.TimeUnit; |
... | ... | @@ -69,15 +69,17 @@ public abstract class AbstractSqlTimeseriesDao extends BaseAbstractSqlTimeseries |
69 | 69 | public void cleanup(long systemTtl) { |
70 | 70 | try { |
71 | 71 | log.info("Going to cleanup old timeseries data using ttl: {}s", systemTtl); |
72 | - CallableStatement stmt = dataSource.getConnection().prepareCall("{call cleanup_timeseries_by_ttl(?,?,?)}"); | |
72 | + PreparedStatement stmt = dataSource.getConnection().prepareStatement("call cleanup_timeseries_by_ttl(?,?,?)"); | |
73 | 73 | stmt.setObject(1, ModelConstants.NULL_UUID); |
74 | 74 | stmt.setLong(2, systemTtl); |
75 | - stmt.registerOutParameter(3, Types.BIGINT); | |
76 | - stmt.executeUpdate(); | |
75 | + stmt.setLong(3, 0); | |
76 | + stmt.execute(); | |
77 | 77 | printWarnings(stmt); |
78 | - log.info("Total telemetry removed stats by TTL for entities: [{}]", stmt.getLong(3)); | |
78 | + ResultSet resultSet = stmt.getResultSet(); | |
79 | + resultSet.next(); | |
80 | + log.info("Total telemetry removed stats by TTL for entities: [{}]", resultSet.getLong(1)); | |
79 | 81 | } catch (SQLException e) { |
80 | - log.error("SQLException occurred during TTL task execution ", e); | |
82 | + log.error("SQLException occurred during timeseries TTL task execution ", e); | |
81 | 83 | } |
82 | 84 | } |
83 | 85 | ... | ... |
... | ... | @@ -27,7 +27,6 @@ import org.springframework.stereotype.Component; |
27 | 27 | import org.thingsboard.server.common.data.id.EntityId; |
28 | 28 | import org.thingsboard.server.common.data.id.TenantId; |
29 | 29 | import org.thingsboard.server.common.data.kv.TsKvEntry; |
30 | -import org.thingsboard.server.dao.model.ModelConstants; | |
31 | 30 | import org.thingsboard.server.dao.model.sqlts.ts.TsKvEntity; |
32 | 31 | import org.thingsboard.server.dao.sqlts.AbstractChunkedAggregationTimeseriesDao; |
33 | 32 | import org.thingsboard.server.dao.sqlts.insert.psql.PsqlPartitioningRepository; |
... | ... | @@ -36,9 +35,9 @@ import org.thingsboard.server.dao.timeseries.SqlTsPartitionDate; |
36 | 35 | import org.thingsboard.server.dao.util.PsqlDao; |
37 | 36 | import org.thingsboard.server.dao.util.SqlTsDao; |
38 | 37 | |
39 | -import java.sql.CallableStatement; | |
38 | +import java.sql.PreparedStatement; | |
39 | +import java.sql.ResultSet; | |
40 | 40 | import java.sql.SQLException; |
41 | -import java.sql.Types; | |
42 | 41 | import java.time.Instant; |
43 | 42 | import java.time.LocalDateTime; |
44 | 43 | import java.time.ZoneOffset; |
... | ... | @@ -107,13 +106,15 @@ public class JpaPsqlTimeseriesDao extends AbstractChunkedAggregationTimeseriesDa |
107 | 106 | private void cleanupPartitions(long systemTtl) { |
108 | 107 | try { |
109 | 108 | log.info("Going to cleanup old timeseries data partitions using partition type: {} and ttl: {}s", partitioning, systemTtl); |
110 | - CallableStatement stmt = dataSource.getConnection().prepareCall("{call drop_partitions_by_max_ttl(?,?,?)}"); | |
111 | - stmt.setObject(1, partitioning); | |
109 | + PreparedStatement stmt = dataSource.getConnection().prepareStatement("call drop_partitions_by_max_ttl(?,?,?)"); | |
110 | + stmt.setString(1, partitioning); | |
112 | 111 | stmt.setLong(2, systemTtl); |
113 | - stmt.registerOutParameter(3, Types.BIGINT); | |
114 | - stmt.executeUpdate(); | |
112 | + stmt.setLong(3, 0); | |
113 | + stmt.execute(); | |
115 | 114 | printWarnings(stmt); |
116 | - log.info("Total partitions removed by TTL: [{}]", stmt.getLong(3)); | |
115 | + ResultSet resultSet = stmt.getResultSet(); | |
116 | + resultSet.next(); | |
117 | + log.info("Total partitions removed by TTL: [{}]", resultSet.getLong(1)); | |
117 | 118 | } catch (SQLException e) { |
118 | 119 | log.error("SQLException occurred during TTL task execution ", e); |
119 | 120 | } | ... | ... |
... | ... | @@ -38,17 +38,18 @@ CREATE OR REPLACE PROCEDURE drop_partitions_by_max_ttl(IN partition_type varchar |
38 | 38 | LANGUAGE plpgsql AS |
39 | 39 | $$ |
40 | 40 | DECLARE |
41 | - max_tenant_ttl bigint; | |
42 | - max_customer_ttl bigint; | |
43 | - max_ttl bigint; | |
44 | - date timestamp; | |
45 | - partition_by_max_ttl_date varchar; | |
46 | - partition_month varchar; | |
47 | - partition_day varchar; | |
48 | - partition_year varchar; | |
49 | - partition varchar; | |
50 | - partition_to_delete varchar; | |
51 | - | |
41 | + max_tenant_ttl bigint; | |
42 | + max_customer_ttl bigint; | |
43 | + max_ttl bigint; | |
44 | + date timestamp; | |
45 | + partition_by_max_ttl_date varchar; | |
46 | + partition_by_max_ttl_month varchar; | |
47 | + partition_by_max_ttl_day varchar; | |
48 | + partition_by_max_ttl_year varchar; | |
49 | + partition varchar; | |
50 | + partition_year integer; | |
51 | + partition_month integer; | |
52 | + partition_day integer; | |
52 | 53 | |
53 | 54 | BEGIN |
54 | 55 | SELECT max(attribute_kv.long_v) |
... | ... | @@ -65,53 +66,138 @@ BEGIN |
65 | 66 | if max_ttl IS NOT NULL AND max_ttl > 0 THEN |
66 | 67 | date := to_timestamp(EXTRACT(EPOCH FROM current_timestamp) - max_ttl); |
67 | 68 | partition_by_max_ttl_date := get_partition_by_max_ttl_date(partition_type, date); |
69 | + RAISE NOTICE 'Date by max ttl: %', date; | |
68 | 70 | RAISE NOTICE 'Partition by max ttl: %', partition_by_max_ttl_date; |
69 | 71 | IF partition_by_max_ttl_date IS NOT NULL THEN |
70 | 72 | CASE |
71 | 73 | WHEN partition_type = 'DAYS' THEN |
72 | - partition_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
73 | - partition_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
74 | - partition_day := SPLIT_PART(partition_by_max_ttl_date, '_', 5); | |
74 | + partition_by_max_ttl_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
75 | + partition_by_max_ttl_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
76 | + partition_by_max_ttl_day := SPLIT_PART(partition_by_max_ttl_date, '_', 5); | |
75 | 77 | WHEN partition_type = 'MONTHS' THEN |
76 | - partition_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
77 | - partition_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
78 | + partition_by_max_ttl_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
79 | + partition_by_max_ttl_month := SPLIT_PART(partition_by_max_ttl_date, '_', 4); | |
78 | 80 | ELSE |
79 | - partition_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
81 | + partition_by_max_ttl_year := SPLIT_PART(partition_by_max_ttl_date, '_', 3); | |
80 | 82 | END CASE; |
81 | - FOR partition IN SELECT tablename | |
82 | - FROM pg_tables | |
83 | - WHERE schemaname = 'public' | |
84 | - AND tablename like 'ts_kv_' || '%' | |
85 | - AND tablename != 'ts_kv_latest' | |
86 | - AND tablename != 'ts_kv_dictionary' | |
87 | - AND tablename != 'ts_kv_indefinite' | |
88 | - LOOP | |
89 | - IF partition != partition_by_max_ttl_date THEN | |
90 | - IF partition_year IS NOT NULL THEN | |
91 | - IF SPLIT_PART(partition, '_', 3)::integer < partition_year::integer THEN | |
92 | - partition_to_delete := partition; | |
93 | - ELSE | |
94 | - IF partition_month IS NOT NULL THEN | |
95 | - IF SPLIT_PART(partition, '_', 4)::integer < partition_month::integer THEN | |
96 | - partition_to_delete := partition; | |
83 | + IF partition_by_max_ttl_year IS NULL THEN | |
84 | + RAISE NOTICE 'Failed to remove partitions by max ttl date due to partition_by_max_ttl_year is null!'; | |
85 | + ELSE | |
86 | + IF partition_type = 'YEARS' THEN | |
87 | + FOR partition IN SELECT tablename | |
88 | + FROM pg_tables | |
89 | + WHERE schemaname = 'public' | |
90 | + AND tablename like 'ts_kv_' || '%' | |
91 | + AND tablename != 'ts_kv_latest' | |
92 | + AND tablename != 'ts_kv_dictionary' | |
93 | + AND tablename != 'ts_kv_indefinite' | |
94 | + AND tablename != partition_by_max_ttl_date | |
95 | + LOOP | |
96 | + partition_year := SPLIT_PART(partition, '_', 3)::integer; | |
97 | + IF partition_year < partition_by_max_ttl_year::integer THEN | |
98 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
99 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
100 | + deleted := deleted + 1; | |
101 | + END IF; | |
102 | + END LOOP; | |
103 | + ELSE | |
104 | + IF partition_type = 'MONTHS' THEN | |
105 | + IF partition_by_max_ttl_month IS NULL THEN | |
106 | + RAISE NOTICE 'Failed to remove months partitions by max ttl date due to partition_by_max_ttl_month is null!'; | |
107 | + ELSE | |
108 | + FOR partition IN SELECT tablename | |
109 | + FROM pg_tables | |
110 | + WHERE schemaname = 'public' | |
111 | + AND tablename like 'ts_kv_' || '%' | |
112 | + AND tablename != 'ts_kv_latest' | |
113 | + AND tablename != 'ts_kv_dictionary' | |
114 | + AND tablename != 'ts_kv_indefinite' | |
115 | + AND tablename != partition_by_max_ttl_date | |
116 | + LOOP | |
117 | + partition_year := SPLIT_PART(partition, '_', 3)::integer; | |
118 | + IF partition_year > partition_by_max_ttl_year::integer THEN | |
119 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
120 | + CONTINUE; | |
97 | 121 | ELSE |
98 | - IF partition_day IS NOT NULL THEN | |
99 | - IF SPLIT_PART(partition, '_', 5)::integer < partition_day::integer THEN | |
100 | - partition_to_delete := partition; | |
122 | + IF partition_year < partition_by_max_ttl_year::integer THEN | |
123 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
124 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
125 | + deleted := deleted + 1; | |
126 | + ELSE | |
127 | + partition_month := SPLIT_PART(partition, '_', 4)::integer; | |
128 | + IF partition_year = partition_by_max_ttl_year::integer THEN | |
129 | + IF partition_month >= partition_by_max_ttl_month::integer THEN | |
130 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
131 | + CONTINUE; | |
132 | + ELSE | |
133 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
134 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
135 | + deleted := deleted + 1; | |
136 | + END IF; | |
101 | 137 | END IF; |
102 | 138 | END IF; |
103 | 139 | END IF; |
140 | + END LOOP; | |
141 | + END IF; | |
142 | + ELSE | |
143 | + IF partition_type = 'DAYS' THEN | |
144 | + IF partition_by_max_ttl_month IS NULL THEN | |
145 | + RAISE NOTICE 'Failed to remove days partitions by max ttl date due to partition_by_max_ttl_month is null!'; | |
146 | + ELSE | |
147 | + IF partition_by_max_ttl_day IS NULL THEN | |
148 | + RAISE NOTICE 'Failed to remove days partitions by max ttl date due to partition_by_max_ttl_day is null!'; | |
149 | + ELSE | |
150 | + FOR partition IN SELECT tablename | |
151 | + FROM pg_tables | |
152 | + WHERE schemaname = 'public' | |
153 | + AND tablename like 'ts_kv_' || '%' | |
154 | + AND tablename != 'ts_kv_latest' | |
155 | + AND tablename != 'ts_kv_dictionary' | |
156 | + AND tablename != 'ts_kv_indefinite' | |
157 | + AND tablename != partition_by_max_ttl_date | |
158 | + LOOP | |
159 | + partition_year := SPLIT_PART(partition, '_', 3)::integer; | |
160 | + IF partition_year > partition_by_max_ttl_year::integer THEN | |
161 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
162 | + CONTINUE; | |
163 | + ELSE | |
164 | + IF partition_year < partition_by_max_ttl_year::integer THEN | |
165 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
166 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
167 | + deleted := deleted + 1; | |
168 | + ELSE | |
169 | + partition_month := SPLIT_PART(partition, '_', 4)::integer; | |
170 | + IF partition_month > partition_by_max_ttl_month::integer THEN | |
171 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
172 | + CONTINUE; | |
173 | + ELSE | |
174 | + IF partition_month < partition_by_max_ttl_month::integer THEN | |
175 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
176 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
177 | + deleted := deleted + 1; | |
178 | + ELSE | |
179 | + partition_day := SPLIT_PART(partition, '_', 5)::integer; | |
180 | + IF partition_day >= partition_by_max_ttl_day::integer THEN | |
181 | + RAISE NOTICE 'Skip iteration! Partition: % is valid!', partition; | |
182 | + CONTINUE; | |
183 | + ELSE | |
184 | + IF partition_day < partition_by_max_ttl_day::integer THEN | |
185 | + RAISE NOTICE 'Partition to delete by max ttl: %', partition; | |
186 | + EXECUTE format('DROP TABLE IF EXISTS %I', partition); | |
187 | + deleted := deleted + 1; | |
188 | + END IF; | |
189 | + END IF; | |
190 | + END IF; | |
191 | + END IF; | |
192 | + END IF; | |
193 | + END IF; | |
194 | + END LOOP; | |
104 | 195 | END IF; |
105 | 196 | END IF; |
106 | 197 | END IF; |
107 | - IF partition_to_delete IS NOT NULL THEN | |
108 | - RAISE NOTICE 'Partition to delete by max ttl: %', partition_to_delete; | |
109 | - EXECUTE format('DROP TABLE IF EXISTS %I', partition_to_delete); | |
110 | - partition_to_delete := NULL; | |
111 | - deleted := deleted + 1; | |
112 | - END IF; | |
113 | 198 | END IF; |
114 | - END LOOP; | |
199 | + END IF; | |
200 | + END IF; | |
115 | 201 | END IF; |
116 | 202 | END IF; |
117 | 203 | END |
... | ... | @@ -127,8 +213,6 @@ BEGIN |
127 | 213 | partition := 'ts_kv_' || to_char(date, 'yyyy') || '_' || to_char(date, 'MM'); |
128 | 214 | WHEN partition_type = 'YEARS' THEN |
129 | 215 | partition := 'ts_kv_' || to_char(date, 'yyyy'); |
130 | - WHEN partition_type = 'INDEFINITE' THEN | |
131 | - partition := NULL; | |
132 | 216 | ELSE |
133 | 217 | partition := NULL; |
134 | 218 | END CASE; | ... | ... |